XL7: Get External Returns Incorrect Data and/or Blank Rows

Last reviewed: February 5, 1998
Article ID: Q158835
The information in this article applies to:
  • Microsoft Excel for Windows 95, versions 7.0, 7.0a
  • Microsoft Windows 95

SYMPTOMS

When you use the Get External Data command on the Data menu to return data from an external data source, the data that is returned is not correct. Some fields or rows that should contain data are blank; or some fields or rows contain incorrect data.

CAUSE

This problem may occur when Microsoft Excel uses the Microsoft Query dynamic data exchange (DDE) Fetch command to return the data to the worksheet.

This problem occurs only under Windows 95. The problem does not occur when you use Microsoft Windows NT 3.51 or later.

STATUS

Microsoft has confirmed this to be a problem in the Microsoft products listed at the beginning of this article. The problem has been corrected in Microsoft Excel 97 for Windows.

MORE INFORMATION

For additional information on using DDE with Microsoft Query, please see the following articles in the Microsoft Knowledge Base:

   ARTICLE-ID: Q149581
   TITLE     : How to Retrieve Request Items Using DDERequest to MSQuery

   ARTICLE-ID: Q142357
   TITLE     : XL: Visual Basic Example Using BuildSQL

   ARTICLE-ID: Q105953
   TITLE     : MSQuery: Obtaining Login String from DDE Request to Query

You can use the following workarounds to avoid the problem described above.

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.

The following methods describe macros that you can use to successfully return external data to your worksheet.

 

Method 1: Using Data Access Objects (DAO)

 
You can use DAO in your macro to return the data to the worksheet. If you use this method, you must specify the path to the database, the Structured Query Language (SQL) statement for the query, and the destination cell for the data. The following macro example returns the data without any user interaction. To use this macro, use the following steps:
 

  • On the Insert menu, point to Macro and click Module.

  • In the Visual Basic module, type the following code:
          Sub GetDataUsingDAO()
     
              'Open the database.
              Set Db = opendatabase("c:\my documents\db1.mdb")
    
              'Create a recordset using a SQL statement.
              Set RS = Db.OpenRecordset("Select * from Table1")
    
              'Copy the field names starting at Sheet1!A1.
              For i = 1 To RS.Fields.Count
                  Range("Sheet1!A1").Offset(, i - 1) = RS(i - 1).Name
              Next
     
              'Copy the results starting at Sheet1!A2.
              Range("Sheet1!A2").CopyFromRecordset RS
    
              Db.Close
    
          End Sub
    
    

  • Click References on the Tools menu, select "Microsoft DAO 3.0 Object Library", and then click OK. The "Microsoft DAO 3.0 Object Library" check box should contain a check mark.
     
    

  • Click Macro on the Tools menu, click GetDataUsingDAO, and click Run to run the macro.

    Method 2: Using DDE with Microsoft Query

     
    
    You can use DDE with Microsoft Query to return the data to the worksheet. When you use this method, you interactively select the data source, select the database, and create the query. To use this macro, use the following steps:
     
    

  • On the Insert menu, point to Macro and click Module.

  • Type the following code in the module.
          Sub GetDataUsingDDE()
     
              Dim chan As Integer
              Dim r As Variant, c As Variant
              Dim StartCell As Range
              Dim RowsToRetrieve As String
              Dim i As Integer
     
              'Activate query - if it is not running, an error occurs and the
              'error handler StartQuery will start Query.
              On Error GoTo StartQuery
              AppActivate "Microsoft Query"
              On Error GoTo 0
    
              'Initiate a channel to query and return control to the user.
              chan = DDEInitiate("MSquery", "system")
              DDEExecute chan, _
                  "[UserControl('&Return Data To Microsoft Excel', 3, true)]"
    
              'Prompt the user for the cell to return the data to.
              Set StartCell = Application.InputBox( _
                  prompt:="Select the starting cell", Type:=8)
    
              'Obtain the number of rows and columns in the result.
              r = DDERequest(chan, "NumRows")
              c = DDERequest(chan, "NumCols")
    
              'Return the headers to the first row at the starting cell.
              DDEExecute chan, "[Fetch('Excel','" & StartCell.Worksheet.Name & _
                  "','" & StartCell.Resize(, c(1)).Address( _
                  ReferenceStyle:=xlR1C1) & "','R1:R1/Headers')]"
    
              'Return the data to the worksheet 100 rows at a time.
              For i = 1 To r(1) Step 100
                  RowsToRetrieve = "R" & i & ":R" & i + 100 - 1
                  DDEExecute chan, "[Fetch('Excel','" & StartCell.Worksheet.Name _
                      & "','" & StartCell.Offset(i).Resize(100, c(1)).Address( _
                      ReferenceStyle:=xlR1C1) & "','" & RowsToRetrieve & "')]"
                  DoEvents
              Next
    
              'Terminate the channel.
              DDETerminate chan
    
              Exit Sub
    
       StartQuery:
              Shell "c:\program files\common files\microsoft shared" & _
                  "\msquery\msqry32.exe", 2
              DoEvents
              Resume
       End Sub
    
    
    NOTE: This example uses the DDE Fetch command to return the data to the worksheet 100 rows at a time. To increase or decrease the number of rows that are returned, modify the Step argument in the following line:
     
       For i = 1 To r(1) Step 100
     
    

  • Click Macro on the Tools menu, click GetDataUsingDDE, and click Run to run the macro. Microsoft Query starts.
     
    

  • Create your query and then click "Return Data to Microsoft Excel" on the File menu.

  • When you are prompted, select a cell for the data and click OK.

    REFERENCES

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

       data access, using
    
    
    and then double-click the selected text to go to the "Using Data Access" topic.


  • Additional query words: garbage character gap missing XL7
    Keywords : kbtool xlquery xlvbainfo xldao
    Version : 7.00 7.00a
    Platform : WINDOWS
    Issue type : kbprb
    Solution Type : kbcode


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