Exporting From Excel To Access

RunTime91

Active Member
Joined
Aug 30, 2012
Messages
276
Office Version
  1. 365
Greetings...

Simple? Apparently not...

Setup:

I receive each day a payroll extract in CSV format, I have written code to clean it up and once cleaned I would like to export it into an Access database.

NOTE: I do not want to import from Excel into Access... I want to export from Excel into Access (this difference seems to confuse just about, well, everybody)

Needless to say my internet searches thus far have all provided the same thing...instructions for importing rather than exporting.

So, perhaps you cannot export from excel into access but I'll believe it when this community says so.

I do have BI installed (Query& Pivot) so what says you Mr. Excel

Can this be done?...with VBA or even SQL of course

Thank you much...
 

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.
Good morning.

You can run the following VBA code from Excel, which will export the active sheet into an Access database. It assumes that your data starts at cell A1, with headers in the first row and data starting in the second row.

An example of the data in your worksheet is like this:

Code:
Sheet1:

   |   A     |   B     |   C
--------------------------------
1  | Column1 | Column2 | Column3
2  | A6708   | B7417   | C9096
3  | A1937   | B9109   | C5108
4  | A5050   | B2868   | C1284
5  | A4301   | B1178   | C6502
6  | A4065   | B5158   | C2689
7  | A6578   | B8605   | C1564
8  | A8291   | B1858   | C2219
9  | A7058   | B9088   | C2895
10 | A2486   | B7877   | C1131
11 | A6035   | B2445   | C8008
12 | A5619   | B1768   | C1224
13 | A4823   | B2607   | C5485
14 | A9154   | B4174   | C3444
15 | A1393   | B1962   | C2876
16 | A8660   | B3687   | C6515
17 | A6158   | B4753   | C5552


And here's the code to export to Access:

Code:
Public Sub ExportToDatabase()
  Const dbOpenDynaset = 2
  Const dbText = 10
  Dim objAccessApp As Object
  Dim objRecordset As Object
  Dim vntFilename As Variant
  Dim objDatabase As Object
  Dim objTable As Object
  Dim objField As Object
  Dim intCols As Integer
  Dim lngRows As Long
  Dim i As Integer
  Dim j As Long
  
  On Error GoTo ErrHandler

' Check a worksheet is active
  If Not TypeOf ActiveSheet Is Worksheet Then
    MsgBox "Activate a worksheet first.", vbExclamation
    GoTo ExitProc
  End If
  
  lngRows = Cells(Rows.Count, 1).End(xlUp).Row
  intCols = Cells(1, Columns.Count).End(xlToLeft).Column
  
GetFilename: ' Request filename from user
  vntFilename = Application.GetSaveAsFilename(ActiveSheet.Name, _
                                             "Microsoft Access (*.accdb), *.accdb", , _
                                             "Export to Database")
  If VarType(vntFilename) = vbBoolean Then GoTo ExitProc
  If Dir(vntFilename) <> vbNullString Then
    Select Case MsgBox("Overwrite existing file?", vbQuestion + vbYesNoCancel + vbDefaultButton2)
      Case vbYes: Kill vntFilename
      Case vbNo: GoTo GetFilename
      Case vbCancel: GoTo ExitProc
    End Select
  End If
  
' Create the database
  Set objAccessApp = CreateObject("Access.Application")
  objAccessApp.NewCurrentDatabase vntFilename
  Set objDatabase = objAccessApp.CurrentDb()
  
' Create the table
  Set objTable = objDatabase.CreateTableDef(ActiveSheet.Name)
  For i = 1 To intCols
    Set objField = objTable.CreateField(Cells(1, i).Value, dbText)
    objTable.Fields.Append objField
  Next i
  objDatabase.TableDefs.Append objTable
  
' Add records from sheet
  Set objRecordset = objTable.OpenRecordset(dbOpenDynaset)
  For j = 2 To lngRows
    objRecordset.AddNew
    For i = 1 To intCols
      objRecordset.Fields(Cells(1, i).Value).Value = Cells(j, i).Value
    Next i
    objRecordset.Update
  Next j
  objRecordset.Close
  objDatabase.Close

' Open table and give control to user
  objAccessApp.DoCmd.OpenTable ActiveSheet.Name
  objAccessApp.UserControl = True

ExitProc:
  On Error Resume Next
  objRecordset.Close
  objDatabase.Close
  Set objRecordset = Nothing
  Set objAccessApp = Nothing
  Set objDatabase = Nothing
  Set objTable = Nothing
  Set objField = Nothing
  Exit Sub
  
ErrHandler:
  MsgBox Err.Description, vbExclamation
  Resume ExitProc
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,632
Messages
6,120,649
Members
448,975
Latest member
sweeberry

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top