WORKAROUND
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 the Microsoft fee-based
consulting line at (800) 936-5200. For more information about Microsoft Certified
Partners, please visit the following Microsoft Web site:
For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:
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