XL: How to Use DAO to Append the Records in Two Tables

Last reviewed: February 26, 1997
Article ID: Q141686
7.00 97 WINDOWS kbusage kbhowto

The information in this article applies to:

  • Microsoft Excel for Windows 95, version 7.0
  • Microsoft Excel 97 for Windows

SUMMARY

In the versions of Microsoft Excel listed at the beginning of this article, you can use DAO (Data Access Objects) to manipulate data in external databases. This article provides a macro example that demonstrates how you can append the records from two different tables using DAO commands.

MORE INFORMATION

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.

WARNING: Your use or modification of the SQL statement provided in this article is at your own risk. Microsoft provides this SQL statement "as is" without warranty of any kind, either expressed or implied, including but not limited to the implied warranties of merchantability and/or fitness for a particular purpose. Microsoft does not support modifications of the SQL statement to suit specific customer requirements.

You can merge the results of two or more queries, tables, and SELECT statements in a single UNION operation. The following example demonstrates how you can use the UNION operation to append two tables:

Sub AppendTables()

Dim db As Database Dim Results As Recordset Dim i As Integer

   'Open the dBASE IV database
   Set db = OpenDatabase("c:\my documents", False, False, "dBASE IV;")

   'Create a recordset that is a union of the January table
   'and the February Table
   Set Results = _
      db.OpenRecordset("Select * from January" & _
        "UNION Select * from February")

   'Return the column headers to the first row of Sheet1
    For i = 0 To Results.Fields.Count - 1
      Sheets("Sheet1").Range("A1").Offset(, i) = Results.Fields(i).Name
    Next

   'Return the recordset results to Sheet1
   Sheets("Sheet1").Range("a2").CopyFromRecordset Results

   db.Close

End Sub

If the January and February tables used in the AppendTables macro appear as in the following tables

   January.DBF                         February.DBF
   ------------------------            ------------------------

   DATE      QTY     AMOUNT            DATE      QTY     AMOUNT
   1/3/95     1      66.99             2/6/95     6      44.91
   1/5/95     6      59.11             2/9/95     7      19.13
   1/8/95     4       2.80             2/10/95    2      20.56
   1/8/95     3      11.12             2/10/95    3      69.94
   1/9/95     2      49.71             2/11/95    8      71.67
   1/15/95    3      59.76             2/19/95    1      93.61
   1/23/95    7      93.32             2/24/95    4      57.76
   1/23/95    8      90.96             2/26/95    3      98.13

the results returned to Sheet1 using the macro are as follows

   DATE      QTY     AMOUNT
   1/3/95     1      66.99
   1/5/95     6      59.11
   1/8/95     4       2.80
   1/8/95     3      11.12
   1/9/95     2      49.71
   1/15/95    3      59.76
   1/23/95    7      93.32
   1/23/95    8      90.96
   2/6/95     6      44.91
   2/9/95     7      19.13
   2/10/95    2      20.56
   2/10/95    3      69.94
   2/11/95    8      71.67
   2/19/95    1      93.61
   2/24/95    4      57.76
   2/26/95    3      98.13

To use the Data Access Object commands in a Microsoft Excel Visual Basic for Applications macro, the DAO library must be referenced. To reference the DAO library use the following steps:

  1. Activate the module sheet containing the macro.

  2. On the Tools menu, click References.

  3. In Microsoft Excel 97, select the Microsoft DAO 3.5 Object Library check box or in Microsoft Excel version 7.0, select the Microsoft DAO 3.0 Object Library check box, and then click OK.

REFERENCES

For more information about DAO, click the Index tab in Microsoft Excel 97 Visual Basic Help, type the following text

   DAO, Overview

and then double-click the selected text to go to the "Data Access Objects Overview" topic.

For more information about Data Access Objects, click the Index tab in Microsoft Excel 7.0 Help, type the following text

   DAO, Overview

and then double-click the selected text to go to the "Data Access Objects Overview" topic.

For more information about the UNION sql operation, click the Index tab in Microsoft Excel Help, type the following text

   UNION Operation

and then double-click the selected text to go to the "UNION Operation (SQL)" topic.


KBCategory: kbusage kbhowto
KBSubcategory: xldao xlwin
Additional reference words: 7.00 8.00 97
Keywords : xldao xlwin kbhowto kbusage
Version : 7.00 97
Platform : WINDOWS


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 26, 1997
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.