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.
 

John_w

MrExcel MVP
Joined
Oct 15, 2007
Messages
5,996
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
 

Forum statistics

Threads
1,081,703
Messages
5,360,747
Members
400,595
Latest member
T_Dubs

Some videos you may like

This Week's Hot Topics

  • VBA (Userform)
    Hi All, I just would like to know why my code isn't working. Here is my VBA code: [CODE=vba]Private Sub OKButton_Click() Dim i As Integer...
  • List box that changes fill color
    Hello, I have gone through so many pages trying to figure this out. I have a 2020 calendar that depending on the day needs to have a certain...
  • Remove duplicates and retain one. Cross-linked cases
    Hi all I ran out of google keywords to use and still couldn't find a reference how to achieve the results of a single count. It would be great if...
  • VBA Copy and Paste With Duplicates
    Hello All, I'm in need of some input. My VBA skills are sub-par at best. I've assembled this code from basic research and it works but is...
  • Macro
    is it possible for a macro to run if the active cell value is different to the value above it
  • IF DATE and TIME
    I currently use this to check if date has passed but i also need to set a time on it too. Is it possible? [CODE=vba]=IF(B:B>TODAY(),"Not...
Top