XL97: How to Programmatically Perform a Web Query

Last reviewed: February 27, 1998
Article ID: Q162080
The information in this article applies to:
  • Microsoft Excel 97 for Windows

SUMMARY

A Web query is a new feature in Microsoft Excel 97 that allows you to retrieve data stored on an intranet, the Internet, or the World Wide Web. A Web query can use static parameters, dynamic parameters, or a combination of both. Queries with static parameters send a query without any input; queries with dynamic parameters prompt you for input. Regardless of the type of parameters in the query, the requested information is pulled from an Internet or an intranet site, and the results are placed in a worksheet.

Using a Hypertext Markup Language (HTML) form, you can use two methods to send parameters to the server: GET and POST. Use GET when you are sending small amounts of information and POST when you are sending larger amounts of information. The GET method appends the parameters to the Uniform Resource Locator (URL). The POST method sends the parameters as a separate line of text in the query file.

This article provides example macros that run Web queries that use both the GET and the POST methods.

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.

Programmatically 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 module. To do this, use the following steps:

  1. Save and close any open workbooks, and then create a new workbook.

  2. Start the Visual Basic Editor (press ALT+F11).

  3. 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, use the following steps:

  1. 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
    
    

  2. Switch to Sheet1 in the workbook.

  3. 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, use the following steps:

  1. 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, are prompted for the parameter values.

    1. In the Enter Parameter Value dialog box, type up to twenty valid stock symbols that are separated by a space; for example, type "msft" (without the quotation marks).

    2. 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, "Detailed Stock Quote by PC Quote, Inc.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, use the following steps:

    1. Switch to the Visual Basic Editor and type the following macro in the module sheet:

            Sub Finder_Get_Query()
         
                IQYFile = "c:\Program Files\Microsoft Office\Queries\" & _
                    "Detailed Stock Quote by PC Quote, Inc.iqy"
         
                With ActiveSheet.QueryTables.Add(Connection:= _
                    "FINDER;" & IQYFile, Destination:=Range("A1"))
         
                    .BackgroundQuery = True
                    .TablesOnlyFromHTML = True
                    .Refresh BackgroundQuery:=False
                    .SaveData = True
                End With
            End Sub
      
      

    2. Switch to Sheet3 in the workbook and run the Finder_Get_Query macro.

    Because this example uses a dynamic parameter, you are prompted for the parameter value.

    1. In the Enter Parameter Value dialog box, type a valid stock symbol.

    2. Click OK.

    A detailed stock quote is returned to Sheet3 for the stock symbol you entered in Step 3.

    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, "Multiple Stock Quotes by PC Quote, Inc.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, use the following steps:

    1. Switch to the Visual Basic Editor and type the following macro in the module sheet:

            Sub Finder_Post_Query()
         
                IQYFile = "c:\program files\microsoft office\queries\" & _
                    "Multiple Stock Quotes by PC Quote, Inc.iqy"
         
                With ActiveSheet.QueryTables.Add(Connection:= _
                    "FINDER;" & IQYFile, 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 Sheet4 in the workbook and run the Finder_Post_Query macro.

    Because this example uses dynamic parameters, you are prompted for the parameter values.

    1. In the Enter Parameter Value dialog box, type up to twenty valid stock symbols that are separated by a space; for example, type "msft" (without the quotation marks).

    2. Click OK.

    The stock quotes for the stock symbols you entered are returned to a table in Sheet4.

    For additional information, please see the following article in the Microsoft Knowledge Base:

       ARTICLE-ID: Q157482
       TITLE     : XL97: How to Create Web Query (.iqy) Files
    
    

    REFERENCES

    For more information about Web queries, click the Index tab in Microsoft Excel Help, type the following text

       web, queries
    
    
    and then double-click the selected text to go to the "Create a Web query" topic.

    For more information about the Add Method, click the Office Assistant, type "querytable", click Search, and then click to view "Add Method (QueryTables Collection)".

    NOTE: If the Assistant is hidden, click the Office Assistant button on the Standard toolbar. If <Product> Help is not installed on your computer, please see the following article in the Microsoft Knowledge Base:

       ARTICLE-ID: Q120802
       TITLE     : Office: How to Add/Remove a Single Office
                   Program or Component
    

  • Additional query words: 97 XL97
    Keywords : kbcode kbprg kbualink97 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: February 27, 1998
    © 1998 Microsoft Corporation. All rights reserved. Terms of Use.