You are currently offline, waiting for your internet to reconnect

How to Retrieve a Table from Access into Excel Using DAO

This article was previously published under Q146406
Retired KB Content Disclaimer
This article was written about products for which Microsoft no longer offers support. Therefore, this article is offered "as is" and will no longer be updated.
In the versions of Microsoft Excel listed above, you can use Data AccessObjects (DAO) in Visual Basic for Applications to retrieve a table fromMicrosoft Access.

To provide an example of how you can use DAO to retrieve a table fromMicrosoft Access, the macro described in this article uses the Northwinddatabase that shipped with both Microsoft Office Professional for Windows95, version 7.0, and Microsoft Office 97 Professional for Windows. If youselected the default options when you installed Microsoft OfficeProfessional for Windows 95, version 7.0, the database is located in:
If you selected the default options when you installed Microsoft Office97 Professional for Windows, the database is located in:
   \Program Files\Microsoft Office\Office\Samples\Northwind.mdb				
If the Northwind database is located in a different folder on yourcomputer, you will need to edit the code provided below before you runit.

To use DAO in your macro, you must reference the Microsoft DAO ObjectLibrary or you may receive the error "User-defined type not defined". Toreference this library in Microsoft Excel version 7.0, activate a modulesheet, click References on the Tools menu, and check the "Microsoft DAO3.0 Object Library" option. To reference this library in Microsoft Excelversion 97, click References on the Tools menu in the Visual Basic Editorand check the "Microsoft DAO 3.5 Object Library".
Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements. To retrieve a table from Microsoft Access, follow these steps:

  1. Establish a Database object.
  2. Establish a Recordset object.
  3. Retrieve the Headers (if desired).
  4. Retrieve the data from the table.
After the data is retrieved, you should close all the objects you openedby issuing .Close commands.

To retrieve a table from Microsoft Access programmatically, use thefollowing Visual Basic for Applications code:
Sub GetTable()'This sub will retrieve all the data in the "Customers" table in'Northwind   'Declare variables   Dim Db As Database   Dim Rs As Recordset   Dim Ws As Object   Dim i As Integer   Dim Path as String   'This line will define the Object "Ws" as Sheets("Sheet1")   'The purpose of this is to save typing Sheets("Sheet1")   'over and over again   Set Ws = Sheets("Sheet1")   'Set the Path to the database. This line is useful because   'if your database is in another location, you just need to change   'it here and the Path Variable will be used throughout the code   Path = "c:\msoffice\access\samples\northwind.mdb"   'This set of code will activate Sheet1 and clear any existing data   'After clearing the data it will select cell A1   Ws.Activate   Range("A1").Activate   Selection.CurrentRegion.Select   Selection.ClearContents   Range("A1").Select   'Set the Database, and RecordSet  This Table exists in the database   Set Db = Workspaces(0).OpenDatabase(Path, ReadOnly:=True)   'This will set the RecordSet to all records in the Customers table   Set Rs = Db.OpenRecordset("Customers")   'You could instead set the RecordSet to, for example, the records   'where the Country Code is "UK", without quotes. To do this, replace   'the line above: Set Rs = Db.OpenRecordset("Customers") with the   'following:   '   'Set Rs = _   'Db.OpenRecordset("SELECT * FROM Customers WHERE Country = 'UK';")   'This loop will collect the field names and place them in the first   'row starting at "A1"   For i = 0 To Rs.Fields.Count - 1      Ws.Cells(1, i + 1).Value = Rs.Fields(i).Name   Next I   'The next line simply formats the headers to bold font   Ws.Range(Ws.Cells(1, 1), Ws.Cells(1, Rs.Fields.Count)).Font.Bold=True   'The next line will get the data from the recordset and copy it   'into the Worksheet (Sheet1).   Ws.Range("A2").CopyFromRecordset Rs   'This next code set will just select the data region and   'auto-fit the columns   Sheets("Sheet1").Select   Range("A1").Select   Selection.CurrentRegion.Select   Selection.Columns.AutoFit   Range("A1").Select   Rs.Close   Db.CloseEnd Sub				
For more information about Data Access, click the Index tab in MicrosoftExcel Help, type the following text
data access in DAO
and then double-click the selected text to go to the "Accessing ExternalDatabases with DAO" topic.
OFF7 XL7 8.00 97 XL97 OFF97 XL

Article ID: 146406 - Last Review: 10/11/2006 02:27:16 - Revision: 2.3

  • Microsoft Excel 97 Standard Edition
  • Microsoft Excel 95 Standard Edition
  • kbdtacode kbhowto kbinterop kbprogramming KB146406