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 Microsoft Advisory Services. For more information, visit these Microsoft Web sites:
Microsoft Certified Partners -
https://partner.microsoft.com/global/30000104Microsoft Advisory Services -
http://support.microsoft.com/gp/advisoryserviceFor more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:
http://support.microsoft.com/default.aspx?scid=fh;EN-US;CNTACTMSProgrammatically Running a Web Query
In order to programmatically run a Web query, you must use the
Add method of the
QueryTables collection. When you use the
Add method, it returns a
QueryTable object that represents the new query table. The syntax for the
Add method is as follows:
<expression>.Add(Connection, Destination, Sql)
where <expression> is required and returns a
QueryTable object. The
Connection argument is also required and is the data source for the query table. In the context of Web queries, you can use one of two types of Connection strings: URL or FINDER. When you specify the URL type, you use the complete URL to the server on which you are performing the query (you can copy the third line from any Web query [.iqy] file and use it as the URL). When you specify the FINDER type, you use the complete path to an existing Web query (.iqy) file.
Creating a Visual Basic Module
Before you use the examples in this article, you must create a Visual Basic module.
- Save and close any open workbooks, and then create a new workbook.
- Start the Visual Basic Editor (press ALT+F11).
- On the Insert menu, click Module.
URL Examples
Static Web Query (GET Method)
The following example uses static parameters; you are not prompted for the
values to send to the server. To create this macro, follow these
steps:
- In the module, type the following code:
Sub URL_Get_Query()
With ActiveSheet.QueryTables.Add(Connection:= _
"URL;http://webservices.pcquote.com/cgi-" & _
"bin/excelget.exe?TICKER=msft", _
Destination:=Range("a1"))
.BackgroundQuery = True
.TablesOnlyFromHTML = True
.Refresh BackgroundQuery:=False
.SaveData = True
End With
End Sub
- Switch to Sheet1 in the workbook.
- Run the URL_Get_Query macro.
A detailed stock quote for MSFT is returned to Sheet1.
Dynamic Web Query (POST Method)
The following example uses dynamic parameters; you are prompted for the
values to send to the server. This example uses the
POST method because the parameters are contained in the query. To create the macro, follow these
steps:
- Switch to the Visual Basic Editor and type the following macro in the
module sheet:
Sub URL_Post_Query()
With ActiveSheet.QueryTables.Add(Connection:= _
"URL;http://webservices.pcquote.com/cgi-bin/excel.exe", _
Destination:=Range("a1"))
.PostText = _
"QUOTE0=[""QUOTE0"",""Enter up to 20 symbols separated " & _
"by spaces.""]"
.BackgroundQuery = True
.TablesOnlyFromHTML = True
.Refresh BackgroundQuery:=False
.SaveData = True
End With
End Sub
- Switch to Sheet2 in the workbook and run the URL_Post_Query macro.
Because this example uses dynamic parameters, you are prompted for the
parameter values.
- In the Enter Parameter Value dialog box, type up to twenty valid stock symbols, each separated by a space. For example, type msft.
- Click OK.
The stock quotes for the stock symbols you entered are returned to a
table in Sheet2.
FINDER Examples
Dynamic Query (GET Method)
With the FINDER type of connection, specify the full path to an existing Web query (.iqy) file. This example uses the
GET method because the Web query file, Microsoft Investor Currency Rates.iqy, uses the
GET method. That is, the parameters and the URL of the server are on the third line in the file. To create the macro, follow these
steps:
- Switch to the Visual Basic Editor and type the following macro in the
module sheet:
Sub Finder_Get_Query()
' Edit path to .iqy file, if necessary.
IQYFile = "C:\Program Files\Microsoft Office\Office\Queries\" & _
"Microsoft Investor Currency Rates.iqy"
With ActiveSheet.QueryTables.Add(Connection:= _
"FINDER;" & IQYFile, Destination:=Range("A1"))
.BackgroundQuery = True
.TablesOnlyFromHTML = True
.Refresh BackgroundQuery:=False
.SaveData = True
End With
End Sub
- Switch to Sheet3 in the workbook and run the Finder_Get_Query macro.
A list of currency rates is returned to Sheet3.
Dynamic Query (POST Method)
With the FINDER type of connection, specify the full path to an existing
Web query (.iqy) file. This example uses the
POST method because the Web query file, Microsoft Investor Stock Quotes.iqy, uses the
POST method. That is, the parameters are on the fourth line, and the URL of the server is on the third line in the file. To create the macro, follow these
steps:
- Switch to the Visual Basic Editor and type the following macro in the
module sheet:
Sub Finder_Post_Query()
' Edit path to .iqy file, if necessary.
IQYFile = "C:\Program Files\Microsoft Office\Office\Queries\" & _
"Microsoft Investor Stock Quotes.iqy"
With ActiveSheet.QueryTables.Add(Connection:= _
"FINDER;" & IQYFile, Destination:=Range("A1"))
.BackgroundQuery = True
.TablesOnlyFromHTML = True
.Refresh BackgroundQuery:=False
.SaveData = True
End With
End Sub
- Switch to Sheet4 in the workbook and run the Finder_Post_Query macro.
Because this example uses dynamic parameters, you are prompted for the
parameter values.
- In the Enter Parameter Value dialog box, type up to twenty valid stock symbols, each separated by a space. For example, type
msft.
- Click OK.
The stock quotes for the stock symbols you entered are returned to a
table in Sheet4.