XL97: Returning Data with DAO to a Custom Worksheet Function

Last reviewed: February 27, 1998
Article ID: Q167179
The information in this article applies to:
  • Microsoft Excel 97 for Windows

SUMMARY

Microsoft Excel allows you to 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 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 folder.

Microsoft provides examples of Visual Basic for Applications procedures 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. The Visual Basic procedures in this article are provided 'as is' and Microsoft does not guarantee that they can be used in all situations. While Microsoft support engineers can help explain the functionality of a particular macro, they will not modify these examples to provide added functionality, nor will they help you construct macros to meet your specific needs. If you have limited programming experience, you may want to consult one of the Microsoft Solution Providers. Solution Providers offer a wide range of fee-based services, including creating custom macros. For more information about Microsoft Solution Providers, call Microsoft Customer Information Service at (800) 426-9400.

To use the example macro, do the following:

  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.5 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.
              MyPath = "c:\program files\microsoft office\office"
       
              ' 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("Customer")
       
              ' 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()" (without the quotation marks), 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 using Data Access Objects, click the Office Assistant, type "DAO" (without quotation marks), 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 Microsoft Excel Help is not installed on your computer, please see the following article in the Microsoft Knowledge Base:

   ARTICLE-ID: Q120802
   TITLE     : Office: How to Add/Remove a Single Office
               Program or Component


Additional query words: XL97
Keywords : kbcode kbprg kbhowto
Version : WINDOWS:97
Platform : WINDOWS
Issue type : kbhowto


THE INFORMATION PROVIDED IN THE MICROSOFT KNOWLEDGE BASE IS PROVIDED "AS IS" WITHOUT WARRANTY OF ANY KIND. MICROSOFT DISCLAIMS ALL WARRANTIES, EITHER EXPRESS OR IMPLIED, INCLUDING THE WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. IN NO EVENT SHALL MICROSOFT CORPORATION OR ITS SUPPLIERS BE LIABLE FOR ANY DAMAGES WHATSOEVER INCLUDING DIRECT, INDIRECT, INCIDENTAL, CONSEQUENTIAL, LOSS OF BUSINESS PROFITS OR SPECIAL DAMAGES, EVEN IF MICROSOFT CORPORATION OR ITS SUPPLIERS HAVE BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGES. SOME STATES DO NOT ALLOW THE EXCLUSION OR LIMITATION OF LIABILITY FOR CONSEQUENTIAL OR INCIDENTAL DAMAGES SO THE FOREGOING LIMITATION MAY NOT APPLY.

Last reviewed: February 27, 1998
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.