VBA getHTML as custom function - Avoid several HTML retrival

atpwtacha

New Member
Joined
Sep 26, 2017
Messages
5
Hi there. I am using this to retieve HTML from a webpage

Code:
Function GetHTML(url As String) As String    With CreateObject("MSXML2.XMLHTTP")
        .Open "GET", url, False
        .Send
        GetHTML = .ResponseText
    End With
    
End Function

I have created another custom function (fromthewebpage) to extract info from the HTML and put it into an 2d array.

Code:
Function fromthewebpage(month,user)
....
....
....
fromthewebpage= udarray(month,user)

When I need the info in the sheet I recall it with =fromthewebpage(x,y) in a cell.

But the size of the array is 13*4 and I need the whole array and each use of the fromthewebpage(x,y) function call GetHTML independently, resulting in 52 retrievals of the page. Are there ways to only call GetHTML once and reuse that info for each use of fromthewebpage.

I imagine either 1) calling GetHTML when opening the workbook and storing the info in a persistent array that I can reference when using fromthewebpage or 2) making fromthewebpage an array function. But I don´t know if that is possible and how to do it.
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
Try something like this (untested, obviously):
Code:
Function GetHTML(url As String) As String
    Static previousResponseText As String
    Static previousUrl As String
    If url <> previousUrl Then  
        With CreateObject("MSXML2.XMLHTTP")
            .Open "GET", url, False
            .Send
            previousResponseText = .ResponseText
            previousUrl = url
        End With
    End If
    GetHTML = previousResponseText
End Function
 
Upvote 0

Forum statistics

Threads
1,223,891
Messages
6,175,229
Members
452,621
Latest member
Laura_PinksBTHFT

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