XL2000: Returning Data with Data Access Objects (DAO) to a Custom Worksheet Function

Article translations Article translations
Article ID: 213710 - View products that this article applies to.
This article was previously published under Q213710
This article has been archived. It is offered "as is" and will no longer be updated.
Expand all | Collapse all

Summary

With Microsoft Excel, you can create custom functions using Visual Basic for Applications. You can also use Data Access Objects (DAO) to programmatically return information from an external database. This article includes sample macro code that uses DAO to return an array of data to a custom worksheet function.

More information

The following sample macro assumes you have installed the Data Access Objects component of Microsoft Office and the Northwind database files (Customer.dbf, Employee.dbf, and Orders.dbf) on your computer.

NOTE: By default, the Northwind database files are installed in the Program Files\Microsoft Office\Office\1033 folder.

Microsoft provides programming examples for illustration only, without warranty either expressed or implied, including, but not limited to, the implied warranties of merchantability and/or fitness for a particular purpose. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft support professionals 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 needs.
If you have limited programming experience, you may want to contact a Microsoft Certified Partner or Microsoft Advisory Services. For more information, visit these Microsoft Web sites:

Microsoft Certified Partners - https://partner.microsoft.com/global/30000104

Microsoft Advisory Services - http://support.microsoft.com/gp/advisoryservice

For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:http://support.microsoft.com/default.aspx?scid=fh;EN-US;CNTACTMS To use the example macro, follow these steps:
  1. Close all open workbooks, and then create a new workbook.
  2. Start the Visual Basic Editor (press ALT+F11), and then click Module on the Insert menu.
  3. On the Tools menu, click References.
  4. In the References dialog box, click Microsoft DAO 3.6 Object Library, and then click OK.
  5. Enter the following code in the module:
    Function DAO_Array() As Variant
    
        Dim db As Database
        Dim rs As Recordset
        Dim varrecords As Variant
        Dim MyPath As String
    
        ' This is the path to the Northwind database .dbf files.
        ' If the .dbf files are elsewhere, modify this line accordingly.
        MyPath = "c:\program files\microsoft office\office\1033"
         
        ' Open the Northwind database.
        Set db = OpenDatabase(MyPath, False, False, "dBase 5.0;")
    
        ' Select all records in the Customer.dbf table.
        Set rs = db.OpenRecordset("Customers")
    
        ' Move the pointer to the last record of the retrieved data.
        rs.MoveLast
    
        ' Count the number of records that are returned.
        x = rs.RecordCount
    
        ' Move the record pointer to the first record. This is required
        ' to return the number of records specified by the RecordCount
        ' property. If this is not done, the record pointer remains on
        ' the last record and only the last record is returned.
        rs.MoveFirst
    
        ' Return the records to a Variant variable containing the array.
        varrecords = rs.GetRows(x)
    
        ' Transpose the data so it is orientated correctly.
        DAO_Array = Application.Transpose(varrecords)
    
        rs.Close
        db.Close
    
    End Function
    					
  6. Switch to Microsoft Excel (press ALT+F11).
  7. On Sheet1, select the range A1:D4.
  8. Type =DAO_Array(), and then press CTRL+SHIFT+ENTER.
This step enters the formula as an array formula. The data from the Customer table is entered in the range you select.

NOTE: If the function returns more data than the range of cells can contain, the data is cut off; that is, the range does not expand to hold the returned data. If the range of cells is too large, cells that do not contain any data display the #N/A error value.

References

For more information about Data Access Objects, click Microsoft Excel Help on the Help menu, type what you need to retrieve external data in the Office Assistant or the Answer Wizard, and then click Search to view the topic.
Note This is a "FAST PUBLISH" article created directly from within the Microsoft support organization. The information contained herein is provided as-is in response to emerging issues. As a result of the speed in making it available, the materials may include typographical errors and may be revised at any time without notice. See Terms of Use for other considerations.

Properties

Article ID: 213710 - Last Review: October 25, 2013 - Revision: 1.0
Applies to
  • Microsoft Excel 2000 Standard Edition
Keywords: 
kbnosurvey kbarchive kbdtacode kbhowto kbprogramming KB213710

Contact us for more help

Contact us for more help
Connect with Answer Desk for expert help.
Get more support from smallbusiness.support.microsoft.com