Introduction.
We can Import data from external data sources; from another Access database, dBase, FoxPro, Excel, and so on. We can Export data from Access into these Applications as well.
Following is a list of topics I have published earlier; either on importing, exporting, or working with external data sources from Microsoft Access:
- Exporting/Importing Data in Text format
- GetRows() Function and Exporting Data
- Import Objects with VB Code
- Adding Data Directly into External databases
- Link External Tables with VBA
- Linking with IBM AS400 Tables
Today, we will explore how to add a range of Excel cell data directly into Access Table, by running the VBA Code from within Excel.
The Algorithm of the program is as given below:
Create an Access Application Object and open it.
Open the target database within the Access Application.
Keep the Access Application window hidden.
Open the target table from the Database.
Take the count of Rows from one of the Excel data columns.
Open a repeating loop to write the excel data one row at a time, from the second row onwards.
Repeat the writing action till all the rows are transferred to the Access Table.
Close the table, and database, and quit the MS-Access Application.
The Excel VBA Code is Run by clicking a Command Button on the Excel Sheet. A sample image of the Excel Sheet with data and Command Button is given below:
Target Access Table Structure image is given below:
The Excel VBA Code
Sub Button1_Click() Dim objAcc As Object Dim recSet As Object Dim DataRow As Long, EndRow As Long On Error GoTo Button1_Click_Err 'Create Access Application Object Set objAcc = CreateObject("Access.Application") 'Open Database in Microsoft Access window objAcc.OpenCurrentDatabase "F:\mdbs\Database4XL.accdb", True 'Keep Access application window hidden objAcc.Visible = False 'Open Access Table to add records from Excel Set recSet = objAcc.CurrentDb.OpenRecordset("Table1") 'Take actual row counts of data for transfer EndRow = Sheet1.Range("A" & Rows.Count).End(xlUp).Row With recSet For DataRow = 2 To EndRow .AddNew ![Desc] = Sheet1.Range("A" & DataRow).Value ![Qrtr1] = Sheet1.Cells.Range("B" & DataRow).Value ![Qrtr2] = Sheet1.Cells.Range("C" & DataRow).Value ![Qrtr3] = Sheet1.Cells.Range("D" & DataRow).Value ![Qrtr4] = Sheet1.Cells.Range("E" & DataRow).Value .Update Next End With recSet.Close objAcc.Quit Set objAcc = Nothing Button1_Click_Exit: Exit Sub Button1_Click_Err: MsgBox Err & " : " & Err.Description, , "Button1_Click()" Resume Button1_Click_Exit End Sub
Courtesy:
The non-functional raw VBA Code presented by a User at www.mrexcel.com/forum/microsoft-access, was modified by me to make it functional and was originally submitted there.The first field of the table is an ID field with the data type AutoNumber. The ID field value is automatically generated when data is inserted into the other fields.
- Roundup Function of Excel in MS-Access
- Proper Function of Excel in Microsoft Access
- Appending Data from Excel to Access
- Writing Excel Data Directly into Access
- Printing MS-Access Report from Excel
- Copy Paste Data From Excel to Access2007
- Microsoft Excel Power in MS-Access
- Rounding Function MROUND of Excel
- MS-Access Live Data in Excel
- Access Live Data in Excel- 2
- Opening Excel Database Directly
- Create Excel Word File from Access
No comments:
Post a Comment
Comments subject to moderation before publishing.