XL97: Background Queries Suspended While Macro Executes

Last reviewed: March 13, 1998
Article ID: Q157090
The information in this article applies to:
  • Microsoft Excel 97 for Windows

SYMPTOMS

When you use the Refreshing property as a condition for a loop in a Visual Basic for Applications macro while a query is refreshing in the background, the macro runs indefinitely and may appear to stop responding (hang).

CAUSE

Background queries do not run while macro code is running. When you programmatically update a pivot table or a query table, such that the query is performed in the background, updating is suspended until the macro ends. After the macro ends and control is returned to Microsoft Excel, the background query continues.

WORKAROUND

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 work around this behavior, use either of the following methods.

Method 1: Modify the macro such that the query does not update in the

          background. To do this, set the BackgroundQuery argument for the
          Refresh method to False.

          NOTE: In the following example, the BackgroundQuery argument for
          the Refresh method is set to False. When this argument is set to
          False, control is returned to the next line in the procedure only
          after the update is completed.

          Dim qTbl As QueryTable

          Sub CreateQueryTable()

             'Create a new query table.
             Set qTbl = ActiveSheet.QueryTables.Add("ODBC;dsn=Northwind", _
             ActiveSheet.Range("A1"), Sql:="Select * from Customers")

             'Refresh the query table.
             qTbl.Refresh BackgroundQuery:=False

            'Display the number of rows returned to the query table.
            MsgBox qTbl.ResultRange.Rows.Count & " Rows Returned"

          End Sub

Method 2: Use the OnTime method to check the Refreshing property of the
          query table at specific intervals of time.  The OnTime method
          schedules a procedure to run at a specified time. While it waits
          to execute the scheduled procedure, Microsoft Excel continues to
          update the query in the background.

          NOTE: In the following example, the OnTime method checks the
          Refreshing property of the background query.

          Dim qTbl As QueryTable

          Sub CreateQueryTable()

             'Create a new query table.
             Set qTbl = ActiveSheet.QueryTables.Add("ODBC;dsn=Northwind", _
                ActiveSheet.Range("A1"), Sql:="Select * from Customers")

             'Refresh the query table in the background.
             qTbl.Refresh BackgroundQuery:=True

             'Run the procedure to loop until the query is refreshed.
             CheckQueryRefreshState

          End Sub

          Sub CheckQueryRefreshState()

             If qTbl.Refreshing Then
                'If the query is still refreshing, call the
                'CheckQueryRefreshState again in one second.
                Application.OnTime Now() + TimeValue("00:00:01"), _
                "CheckQueryRefreshState"
             Else
                'Display the number of rows returned to the query table
                'after the query table is refreshed.
                MsgBox qTbl.ResultRange.Rows.Count & " Rows Returned"
             End If

          End Sub

MORE INFORMATION

In the following macro example, the macro runs indefinitely because the Refreshing property is the condition for a Do While...Loop, and a query is updating in the background.

Dim qTbl As QueryTable

Sub CreateQueryTable()

    'Create a new query table.
    Set qTbl = ActiveSheet.QueryTables.Add("ODBC;dsn=Northwind", _
         ActiveSheet.Range("A1"), Sql:="Select * from Customers")

    'Refresh the query table in the background.
    qTbl.Refresh BackgroundQuery:=True

    'Loop and wait until the query is refreshed.
    Do While qTbl.Refreshing
        DoEvents
    Loop

    'Display the number of rows returned to the query table.
    MsgBox qTbl.ResultRange.Rows.Count & " Rows Returned"

End Sub


Additional query words: XL97
Keywords : kbcode kbprg kbtool xlquery xlvbahowto xlvbainfo
Version : WINDOWS: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: March 13, 1998
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.