Microsoft KB Archive/147779

From BetaArchive Wiki
Knowledge Base


How to Retrieve Records into Specific Columns Using DAO

Article ID: 147779

Article Last Modified on 10/11/2006



APPLIES TO

  • Microsoft Excel 97 Standard Edition
  • Microsoft Excel 95 Standard Edition



This article was previously published under Q147779

SUMMARY

In earlier versions of Microsoft Excel, you can use SQLBIND to specify where the results of a query are placed. However, if you use Data Access Objects (DAO), and you use the CopyFromRecordset method, data is always returned to a contiguous section of the worksheet. SQLBIND is not available with DAO; therefore, you must use alternate method of placing data in specified columns when you use DAO. This article demonstrates how to do this.

MORE INFORMATION

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. In order to specify into which columns the results of a data retrieval are inserted, it is necessary to loop through the recordset, specifying into which cells to place the data in each iteration of the loop.

The following subroutine will retrieve the Customers table in the Northwind database. The subroutine will then place the CustomerID field in Column A, the CompanyName field in Column C, and the ContactName field in Column E of Sheet1. The data is placed in the worksheet starting on the second row so that field headers can be placed in the first row.

NOTE: This subroutine is designed to run using the Northwind database that is included with both Microsoft Office 97 for Windows, Professional Edition and Microsoft Office version 7.0, Professional Edition.

In Microsoft Office 97 for Windows, Professional Edition, the default location for the Northwind database is:

   C:\Program Files\Microsoft Office\Office\Samples\Northwind.mdb
                

In Microsoft Office version 7.0, Professional Edition, the default location for the Northwind database is:

   C:\MSOffice\Access\Samples\Northwind.mdb
                

If you installed the Northwind database in a different location, modify the OpenDatabase statement in the following subroutine. Change the line to point to the location of the Northwind database.

   Sub Test()
       Dim DB As Database, RS As Recordset
       Dim StartCell As Range

       ' Open the Northwind database.
       Set DB = OpenDatabase("c:\msoffice\access\samples\northwind.mdb")

       ' Open the Customers table as a recordset.
       Set RS = DB.OpenRecordset("Customers")

       ' Set StartCell as the first cell of the return range.
       Set StartCell = Worksheets(1).Range("A2")

       ' Move to the first row of the recordset.
       RS.MoveFirst

       For x = 0 To RS.RecordCount - 1
           With StartCell
               ' Place CustomerName field in column A.
               .Offset(x, 0).Value = RS.Fields("CustomerID").Value

               ' Place CompanyName field in column C.
               .Offset(x, 2).Value = RS.Fields("CompanyName").Value

               ' Place ContactName field in column E.
               .Offset(x, 4).Value = RS.Fields("ContactName").Value
           End With

           ' Move to the next record.
           RS.MoveNext
       Next

       ' Close the Recordset object.
       RS.Close

       ' Close the Database object.
       DB.Close
   End Sub
                

NOTE: If an error appears when you run this subroutine, make sure that you referenced the DAO Object Library. To reference the library in Microsoft Excel 97, click References on the Tools menu in the Visual Basic Editor, and select "Microsoft DAO 3.5 Object Library." To reference the library in Microsoft Excel version 7.0, activate the module sheet, click References on the Tools menu, and select "Microsoft DAO 3.0 Object Library."

REFERENCES

For more information about Data Access Objects in Microsoft Excel 97, from the Visual Basic Editor, click the Office Assistant, type DAO, click Search, and then click to view "Data Access Objects Overview."

NOTE: If the Assistant is hidden, click the Office Assistant button on the Standard toolbar. If the Assistant is not able to answer your query, please see the following article in the Microsoft Knowledge Base:

176476 OFF: Office Assistant Not Answering Visual Basic Questions


For more information about data access objects in Microsoft Excel 7.0, click the Index tab in Microsoft Excel Help and type:

DAO



Additional query words: 8.00 97 XL

Keywords: kbdtacode kbhowto kbprogramming KB147779