Automating and looping a Web Query

abesimpson

Active Member
Joined
May 3, 2003
Messages
435
My spreadsheet is linked to a stock data web page using the little documented .iqy function. I have set cell A1 to the web page ticker symbol, so that whenever this cell value is changed the data in the spreadsheet is automatically updated.

My problem is in several parts:
1. Read TickerSymbol.csv file which is comprised of just ticker symbols,
2. Insert (TickerSymbol.csv) symbol 1 into cell A1,
3. Save the results to a file c:\XXX\Symbol1.csv,
4. Insert (TickerSymbol.csv) symbol 2,
5. repeat, repeat

Any and all help would be greatly appreciated.


abe
 
In order to import data into Access I need to restructure the date from the web table format into some thing better imported into a database.

I have added the following formula just prior to the csv save.
Code:
'Table 1
Sheets("sheet1").Range("AA1").Value = Sheets("sheet1").Range("A2").Value
Sheets("sheet1").Range("AA2").Value = Sheets("sheet1").Range("B2").Value
Sheets("sheet1").Range("AB1").Value = Sheets("sheet1").Range("A3").Value
Sheets("sheet1").Range("AB2").Value = Sheets("sheet1").Range("B3").Value
Sheets("sheet1").Range("AC1").Value = Sheets("sheet1").Range("A4").Value
Sheets("sheet1").Range("AC2").Value = Sheets("sheet1").Range("B4").Value
Sheets("sheet1").Range("AD1").Value = Sheets("sheet1").Range("A5").Value
Sheets("sheet1").Range("AD2").Value = Sheets("sheet1").Range("B5").Value
Sheets("sheet1").Range("AE1").Value = Sheets("sheet1").Range("A6").Value
Sheets("sheet1").Range("AE2").Value = Sheets("sheet1").Range("B6").Value
Sheets("sheet1").Range("AF1").Value = Sheets("sheet1").Range("A7").Value
Sheets("sheet1").Range("AF2").Value = Sheets("sheet1").Range("B7").Value
Sheets("sheet1").Range("AG1").Value = Sheets("sheet1").Range("A8").Value
Sheets("sheet1").Range("AG2").Value = Sheets("sheet1").Range("B8").Value
Sheets("sheet1").Range("AH1").Value = Sheets("sheet1").Range("A9").Value
Sheets("sheet1").Range("AH2").Value = Sheets("sheet1").Range("B9").Value

Depending on the table being saved this can add a lot of code to what is so far an elegant solution.


Is there a better way (what a silly question)?

Regards

a
 
Upvote 0

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
You want to transpose rows and columns, so Copy the source cells and then Edit - Paste Special with the Transpose option. Doing this operation with the Macro recorder and then refining the code to remove unnecessary Selects produces:
Code:
Sub test()
    With Sheets("Sheet1")
        .Range("A2:B9").Copy
        .Range("AA1").PasteSpecial Paste:=xlPasteAll, Operation:=xlNone, SkipBlanks:=False, Transpose:=True
    End With
    Application.CutCopyMode = False
End Sub
If the end cell (B9 in the above example) varies, use code previously posted to find the last populated row and construct the source range string.
 
Upvote 0
John

I have settled on using the .IQY option as I found that in some cases I only want/need to import one or 2 tables from a web page and this is the easiest way to tune this parameter. This being said I find that even when importing "AllTables" from a web page the number of rows imported in a single pass can vary as the number of blank lines or advertisements between tables can sometimes vary (also found that cell formatting sometime needs to be adjusted prior to export). My solution is to modify the tables to created a more or less standard data for each web page array prior to transposing from vertical to horizontal.

I keep getting errors using your code on a second pass of running it (could it be due to the fact that I am using the IQY file?). My code is as follows:

IQY file:
Code:
WEB
1
http://finance.yahoo.com/q?s=["quote symbol","Enter cell containing quote symbol, e.g. =B1"]&=

Selection=AllTables
PreFormattedTextToColumns=True
ConsecutiveDelimitersAsOne=True
SingleBlockTextImport=False
DisableDateRecognition=False
DisableRedirections=False

Modified Code:
Code:
'Delete Blank Rows 
Columns("B:B").Select
Selection.SpecialCells(xlCellTypeBlanks).Select
Selection.EntireRow.Delete
                
'Delete Previous Transpose Range
Columns("C:DF").Select
Selection.Delete Shift:=xlToLeft
                
'"Fix" Cell Formatting
Sheets("sheet1").Range("B:B").NumberFormat = "General"
                
'"TAG" Export Range with TKR and Date
Sheets("sheet1").Range("C1").Value = "Ticker"
Sheets("sheet1").Range("C2").Value = Sheets("sheet1").Range("B1").Value
Sheets("sheet1").Range("D1").Value = "Date"
Sheets("sheet1").Range("D2").Value = Date
Sheets("sheet1").Range("D2").NumberFormat = "mm\/dd\/yy"

'Transpose Data
Range("E2").Select
ActiveCell.FormulaR1C1 = "=TRANSPOSE(RC[-3]:R[23]C[-3])"
Selection.AutoFill Destination:=Range("E2:AB2"), Type:=xlFillDefault
Range("E2:AB2").Select
Selection.FormulaArray = "=TRANSPOSE(RC[-3]:R[23]C[-3])"

'Save the data returned
Save_Stock_Data saveToFolder, symbol, Range("C2:AB2") '<<< Modify To Suit Web Query; Save-to Data Range

My code is clearly not the best; it looks clumsy and so I imagine there are way better ways to write this. I would like to be able to the export range to a "Sheet2" but so far have failed to do so. I also noticed that you wrote your lasted code like this:
With Sheets("Sheet1")
.Range("A2:B9").Copy
.Range("AA1").PasteSpecial Paste:=xlPasteAl

When I try to remove the repetitive Sheets("sheet1").... as you did, my code crashes.

As before, Thanks (and please be gentle with your comments).

a
 
Upvote 0
I would like to be able to the export range to a "Sheet2" but so far have failed to do so. I also noticed that you wrote your lasted code like this:
With Sheets("Sheet1")
.Range("A2:B9").Copy
.Range("AA1").PasteSpecial Paste:=xlPasteAl

When I try to remove the repetitive Sheets("sheet1").... as you did, my code crashes.
Try this:
Code:
Sub test2()
    Sheets("Sheet1").Range("A2:B9").Copy
    Sheets("Sheet2").Range("AA1").PasteSpecial Paste:=xlPasteAll, Operation:=xlNone, SkipBlanks:=False, Transpose:=True
    Application.CutCopyMode = False
End Sub
 
Upvote 0
John,

I feel like the South-end of a horse facing North (again). Everything was working perfectly until Sunday. On Monday the routine started to fail on "If Err.Number = 0 Then". I have backtracked back to your untouched code with the same results.

What could have happened?


a
 
Upvote 0
Are you running 2 or more instances of the workbook/macro concurrently? If so, that could cause a failure for the reasons I have already said.

Are you running the .iqy file version or the URL connection version?

I don't understand why it should fail on "If Err.Number = 0 Then" as there is nothing in that statement which could cause an error.

The code uses On Error to handle error 1004 ('This Web query returned no data') which occurs when a delisted symbol is retrieved, e.g. AQR-U. The trouble with using On Error is that it overrides Excel's own error handling which displays an error message when an error occurs, and therefore hides the actual error. If the answer to the first question above is '"No", then you need to find the true cause of this latest failure. To do this, remove all the delisted symbols from your TickerSymbols file, comment out the On Error Resume Next statement and run the code. This assumes that a delisted symbol is not causing the failure.
 
Upvote 0
1. Only one spreadsheet is running.
2. I'm running the IQY version of your code (as I find this is the more flexible way to define what I am importing from any web page).
3. I do (and did) have firefox installed on the machine, but IE is set as the default browser.

I am flummoxed.
I am down to running your clean code without any of the junk transpose code that I wrote. In any run I get 1 or 2 tickers saved to the data folder before the program crashes.

This is very humbling.

a

Code:
'Uses a dynamic web query, using either an .iqy file or a URL connection string, to retrieve stock data from
'Yahoo Finance (http://finance.yahoo.com).
'The stock quote symbols are read from a file containing one symbol per line.
'For each symbol, the stock data is retrieved using the dynamic web query and then saved in a file called .csv.

'The dynamic web query is contained in the file YahooFinanceQuote.iqy, which contains:
'   WEB
'   1
'   http://finance.yahoo.com/q?s=["quote symbol","Enter cell containing quote symbol, e.g. =B1"]&=

 
Option Explicit
 
'Name of the dynamic web query
Const cQueryName = "YahooFinanceQuote"

'File containing symbols to be retrieved, one per line.
'Const cSymbolsFilename = "Yahoo Finance TickerSymbols.csv"
Const cSymbolsFilename = "TickerSymbols.csv"

'Folder containing the symbols file
Const cSymbolsFolder = "Z:\WebSpider\"

'Folder in which to create the symbol.csv files.  This folder must exist
Const cSaveToFolder = "Z:\WebSpider\Yahoo Financial\Data\"

'The .iqy file.  This file should be in the same folder as the workbook.  Not used if URL web query is called.
Const cIqyFilename = "IQYImport.iqy"

'Yahoo Finance URL with the query field (s=) but not the field value
'Const cURL = "http://finance.yahoo.com/q?s="

'Cell containing the query field (s=) field value (Excel dynamic parameter)
Const cParameterCell = "B1"

'Cell where retrieved data begins
Const cDataStartCell = "A2"

'Delete temporary internet files every n symbols
Const cDeleteTemporaryFilesEvery = 20

'For debugging
Const cDEBUG = True

Public Sub Retrieve_All_Symbols()

    Dim symbolsFile As String
    Dim iqyFile As String
    Dim saveToFolder As String
    Dim fileNum As Integer
    Dim symbol As String
    Dim queryName As String
    Dim dataEndRow As Integer
    Dim s As Integer
    Dim numSymbols As Long

    symbolsFile = cSymbolsFolder & cSymbolsFilename
    'Or if the symbols file is in the same folder as the workbook
    'symbolsFile = ActiveWorkbook.Path & "\" & cSymbolsFilename

    iqyFile = ActiveWorkbook.Path & "\" & cIqyFilename

    saveToFolder = cSaveToFolder
        'Or to save the symbol.csv files in the same folder as the workbook
    'saveToFolder = ActiveWorkbook.Path & "\"

    'Get web query (if it has been created manually) and create it if it doesn't exist
    queryName = Get_Web_Query_Name
    If queryName = "" Then
        'queryName = Create_Dynamic_Query_From_URL(cQueryName, cURL, cParameterCell, cDataStartCell)
        queryName = Create_Dynamic_Query_From_Iqy_File(cQueryName, iqyFile, cParameterCell, cDataStartCell)
    End If

    numSymbols = 0
    fileNum = FreeFile
    Open symbolsFile For Input As #fileNum
    While Not EOF(fileNum)

        DoEvents

        Line Input #fileNum, symbol
        numSymbols = numSymbols + 1

        If cDEBUG Then Debug.Print numSymbols & " " & symbol

        'Put this quote symbol in the cell associated with the web query.
        'The web query doesn't automatically refresh, despite the RefreshOnChange property being set.  Therefore the
        'explicit Refresh below is required to retrieve the data for the symbol

        ActiveSheet.Range(cParameterCell).Value = symbol

        'Delisted ticker symbols such as AQR-U cause the web query to
        'return "Run-time error 1004, This web query returned no data ..."
        'because the quote page (e.g. http://finance.yahoo.com/q?s=AQR-U&=) contains no tables

        On Error Resume Next
        ActiveSheet.QueryTables(queryName).Refresh BackgroundQuery:=False

        If Err.Number = 0 Then

            'No error occurred
            On Error GoTo 0
            If cDEBUG Then Debug.Print "Retrieved OK"

            'Find the last row of data in column A
            dataEndRow = ActiveSheet.Cells(ActiveSheet.Rows.Count, "A").End(xlUp).Row

            'Save the data returned
            Save_Stock_Data saveToFolder, symbol, Range("A2:B" & dataEndRow)

        ElseIf Err.Number = 1004 Then

            'The expected error "This web query returned no data ..." occurred - ignore it
            On Error GoTo 0
            If cDEBUG Then Debug.Print "Web query returned no data"

        Else

            'An unexpected error occurred - tell the user
            On Error GoTo 0
            If cDEBUG Then Debug.Print "Error " & Err.Number & " " & Err.Description

            MsgBox "Error number " & Err.Number & vbNewLine & Err.Description, , "Run-time error"

        End If

        DoEvents

        'Every n symbols delete Yahoo Finance files from IE temporary internet files cache
        'Without this, after a while any web query, even a manual one, returns
        '   "Run-time error 1004  The file could not be accessed ...",
        'which is trapped by the error handler above.
        'It seems that this error is related to IE's temporary internet files -
        'see http://www.vbforums.com/showthread.php?t=453684 for other people with the same problem with Yahoo Finance quotes.
        'The solution is to periodically delete the temporary files that IE creates for
        'http://finance.yahoo.com/q?s=XXX

        If numSymbols Mod cDeleteTemporaryFilesEvery = 0 Then
            Delete_Yahoo_IE_Temporary_Files
            DoEvents
        End If

    Wend

    Close #fileNum

End Sub


Private Sub Save_Stock_Data(folder As String, symbol As String, dataRange As Range)

    'Save the stock data for the symbol in the file .csv
    Dim dataOutputFile As String
    Dim fileNum As Integer
    Dim csvLine As String
    Dim previousRow As Integer
    Dim cell As Range
    
    dataOutputFile = folder & symbol & ".csv"
    
    fileNum = FreeFile
    Open dataOutputFile For Output As #fileNum
    
    csvLine = ""
    previousRow = dataRange.Row
    For Each cell In dataRange
        If cell.Row = previousRow Then
            csvLine = csvLine & cell.Value & ","
        Else
            Print #fileNum, Left(csvLine, Len(csvLine) - 1)
            csvLine = cell.Value & ","
            previousRow = cell.Row
        End If
    Next
    Print #fileNum, Left(csvLine, Len(csvLine) - 1)
    
    Close #fileNum
    
End Sub


Private Function Create_Dynamic_Query_From_URL(queryName As String, URL As String, parameterCell As String, _
        destinationCell As String) As String

    Dim qt As QueryTable
    Dim URLquery As String
       
    'Code in this function was generated by the Macro Recorder as a result of
    'Data - Import External Data - Import Data - browse to .iqy file.
    'and then modified to include the quote symbol parameter in the connection string - see http://www.jkp-ads.com/Articles/WebQuery.asp
    'Therefore the .iqy file is not needed and the Parameter Value dialogue box doesn't appear when the querytable is added.
                
    'This is the URL from the .iqy file
    'http://finance.yahoo.com/q?s=["quote symbol","Enter cell containing quote symbol, e.g. =B1"]&=
                
    URLquery = "[""quote symbol"",""Enter cell containing quote symbol, e.g. =B1""]&="
  
    Set qt = ActiveSheet.QueryTables.Add(Connection:="URL;" & URL & URLquery, Destination:=Range(destinationCell))
    
    With qt
        .Name = queryName
        .FieldNames = True
        .RowNumbers = False
        .FillAdjacentFormulas = False
        .PreserveFormatting = False
        .RefreshOnFileOpen = False
        .BackgroundQuery = False    'False because data requests must be synchronous. Was True when generated by Macro Recorder
        .RefreshStyle = xlOverwriteCells
        .SavePassword = False
        .SaveData = True
        .AdjustColumnWidth = True
        .RefreshPeriod = 0
        .WebSelectionType = xlAllTables
        .WebFormatting = xlWebFormattingAll
        .WebPreFormattedTextToColumns = False
        .WebConsecutiveDelimitersAsOne = True
        .WebSingleBlockTextImport = False
        .WebDisableDateRecognition = False
        .WebDisableRedirections = True
        With .Parameters(1)
            .SetParam xlRange, ActiveSheet.Range(parameterCell)
            .RefreshOnChange = True 'But doesn't trigger an automatic refresh when value of parameter cell changes
        End With
        '.Refresh BackgroundQuery:=False
    End With
    
    Create_Dynamic_Query_From_URL = qt.Name
    
End Function

Private Function Create_Dynamic_Query_From_Iqy_File(queryName As String, iqyFile As String, parameterCell As String, _
        destinationCell As String) As String

    Dim qt As QueryTable
    
    'Code in this function was generated by the Macro Recorder as a result of
    'Data - Import External Data - Import Data - browse to .iqy file
    'and then modified to suit this program
        
    Set qt = ActiveSheet.QueryTables.Add(Connection:="FINDER;" & iqyFile, Destination:=Range(destinationCell))
    
    With qt
        .Name = queryName
        .FieldNames = True
        .RowNumbers = False
        .FillAdjacentFormulas = False
        .PreserveFormatting = False
        .RefreshOnFileOpen = False
        .BackgroundQuery = False    'False because data requests must be synchronous. Was True when generated by Macro Recorder
        .RefreshStyle = xlOverwriteCells
        .SavePassword = False
        .SaveData = True
        .AdjustColumnWidth = True
        .RefreshPeriod = 0
        .WebSelectionType = xlAllTables
        .WebFormatting = xlWebFormattingAll
        .WebPreFormattedTextToColumns = False
        .WebConsecutiveDelimitersAsOne = True
        .WebSingleBlockTextImport = False
        .WebDisableDateRecognition = False
        .WebDisableRedirections = True
        
        'This With ... End With block sets the web query's parameter value to the specified cell.  Without this,
        'the 'Set Parameter Value' dialogue box appears
        
        'With .Parameters(1)
        '    .SetParam xlRange, ActiveSheet.Range(parameterCell)
        '    .RefreshOnChange = True
        'End With
        
        .Refresh BackgroundQuery:=False
    End With
    
    Create_Dynamic_Query_From_Iqy_File = qt.Name
    
End Function

Private Function Get_Web_Query_Name() As String
    
    Dim qt As QueryTable
    
    'Returns the name of the first web query on the active sheet, or "" if no queries exist
    If ActiveSheet.QueryTables.Count > 0 Then
        Get_Web_Query_Name = ActiveSheet.QueryTables(1).Name
    Else
        Get_Web_Query_Name = ""
    End If
    
End Function

Private Sub Delete_Yahoo_IE_Temporary_Files()

    'Delete Yahoo Finance files (filenames matching q[*.* and lookup*.*) from the IE cache
    Static TemporaryInternetFilesPath As String
    Static ComSpec As String
    Dim oWSH As Object
    Dim IECacheKey As String
    Dim ShellXResult As Long
    Dim DOScommand As String

    If TemporaryInternetFilesPath = "" Then
        IECacheKey = "HKEY_CURRENT_USER\Software\Microsoft\Windows\CurrentVersion\Explorer\Shell Folders\Cache"
        Set oWSH = CreateObject("WScript.Shell")
        TemporaryInternetFilesPath = oWSH.RegRead(IECacheKey) & "\Content.IE5\"
    End If
    
    If ComSpec = "" Then ComSpec = Environ$("ComSpec")
    
    'Run DEL commands asynchronously
    DOScommand = "DEL /Q /S " & Chr(34) & TemporaryInternetFilesPath & "q[*.*" & Chr(34)
    Shell ComSpec & " /c " & DOScommand, vbHide
    
    DOScommand = "DEL /Q /S " & Chr(34) & TemporaryInternetFilesPath & "lookup*.*" & Chr(34)
    Shell ComSpec & " /c " & DOScommand, vbHide
    
    'May need synchronous Shell function instead - http://vb-tec.de/xshell.htm
    'ShellXResult = ShellX(ComSpec & " /c " & DOScommand, vbHide)
 
End Sub

'=========== Debugging and Information routines ===========

Private Sub Show_All_Queries()
    Dim qt As QueryTable
    For Each qt In ActiveSheet.QueryTables
        Debug.Print qt.Name
    Next
End Sub

Private Sub Delete_Query(queryName As String)
    Dim qt As QueryTable
    For Each qt In ActiveSheet.QueryTables
        If qt.Name = queryName Then qt.Delete
    Next
End Sub

Sub Delete_All_Queries()
    Dim qt As QueryTable
    For Each qt In ActiveSheet.QueryTables
        Debug.Print "Deleted " & qt.Name
        qt.Delete
    Next
End Sub
 
Upvote 0
1. Only one spreadsheet is running.
2. I'm running the IQY version of your code (as I find this is the more flexible way to define what I am importing from any web page).
3. I do (and did) have firefox installed on the machine, but IE is set as the default browser.
1. Good, that removes one possible cause.
2. That's fine. I don't think it makes any difference as both methods retrieve data from the same web site.
3. I don't think Firefox would cause this problem as Excel web queries use IE.
I am flummoxed.
I am down to running your clean code without any of the junk transpose code that I wrote. In any run I get 1 or 2 tickers saved to the data folder before the program crashes.
I'm slightly stumped too. As I said, comment out the On Error Resume Next statement and see what error is displayed when the program crashes, although the error handling should display any error other than 1004 anyway.

It could be your IE temporary files folder. Open a command prompt in that folder, e.g. C:\Documents and Settings\John\Local Settings\Temporary Internet Files and enter the command 'DIR /S' to list all files and get the total file size. Then delete the temporary files within IE and run the program. The program deletes files matching q[*.* and lookup*.*, but maybe that is not enough.
 
Upvote 0
I don't know a stronger term than flummoxed, but if there one is I am it.

I've,
1.- Emptied the "Temporary Internet Files", and
2.- commented out " 'On Error Resume Next"

The Macro crashes with "Code Execution Has Been Interrupted", when I click debug "If Err.Number = 0 Then" is highlighted (though a few times out of many debug trapped this line: "ActiveSheet.QueryTables(queryName).Refresh BackgroundQuery:=False").

My major concern is that it's something I'm doing wrong and I just can't figure it out..

Thanks for your patience.

a
 
Upvote 0

Forum statistics

Threads
1,214,922
Messages
6,122,281
Members
449,075
Latest member
staticfluids

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top