How do I pass a string variable to the web.contents argument of Power Query (Get & Transform)?

QuinnE

New Member
Joined
Apr 13, 2023
Messages
5
Office Version
  1. 2016
Platform
  1. Windows
Hello,

I am using Get & Transform in a VBA routine to get the contents of a webpage that I want to later parse. The content is bills from our state legislature and how the legislators voted. Each Bill has its own page, so I want to build the string according to the bill number and use the string variable to get the contents. Below is the code I am trying to use. The first section is the code, where you can see the string variable is not resolving. The second part is when I recorded a macro using the same exact string, which works fine. I'm not real good at determining the format for strings, so if you could guide me, that would be great.
VBA Code:
Sub GetBillInfoFromWeb()
'
' Macro3 Macro
'

'
Dim BillNum As String
Dim WebAddress As String
[COLOR=rgb(250, 197, 28)]WebAddress[/COLOR] = "https://legislature.idaho.gov/sessioninfo/2023/legislation/"
Dim RowNum As Integer
Dim ColNum As Integer
Dim scratch As String

RowNum = 4
Sheets("LegislatureVotes").Select
BillNum = "Start"

Do Until BillNum = ""
BillNum = Cells(RowNum, 1).Value2
WebAddress = WebAddress & BillNum & "/"

    Sheets("Scratchpad").Select
    ActiveWorkbook.Queries.Add Name:="Table 0", Formula:= _
        "let" & Chr(13) & "" & Chr(10) & "    Source = Web.Page(Web.Contents([COLOR=rgb(250, 197, 28)]webaddress[/COLOR]))," & Chr(13) & "" & Chr(10) & "    Data0 = Source{0}[Data]," & Chr(13) & "" & Chr(10) & "    #""Changed Type"" = Table.TransformColumnTypes(Data0,{{""Column1"", type text}, {""Column2"", type date}, {""Column3"", type text}, {""Column4"", type text}})" & Chr(13) & "" & Chr(10) & "in" & Chr(13) & "" & Chr(10) & "    #""Changed Type"""
    With ActiveSheet.ListObjects.Add(SourceType:=0, Source:= _
        "OLEDB;Provider=Microsoft.Mashup.OleDb.1;Data Source=$Workbook$;Location=""Table 0"";Extended Properties=""""" _
        , Destination:=Range("$A$1")).QueryTable
        .CommandType = xlCmdSql
        .CommandText = Array("SELECT * FROM [Table 0]")
        .RowNumbers = False
        .FillAdjacentFormulas = False
        .PreserveFormatting = True
        .RefreshOnFileOpen = False
        .BackgroundQuery = True
        .RefreshStyle = xlInsertDeleteCells
        .SavePassword = False
        .SaveData = True
        .AdjustColumnWidth = True
        .RefreshPeriod = 0
        .PreserveColumnInfo = True
        .ListObject.DisplayName = "Table_0"
        .Refresh BackgroundQuery:=False
    End With
    Selection.ListObject.QueryTable.Refresh BackgroundQuery:=False
    Loop
End Sub

VBA Code:
Sub Macro6()
'
' Macro6 Macro
'

'
    ActiveWorkbook.Queries.Add Name:="Table 0", Formula:= _
        "let" & Chr(13) & "" & Chr(10) & "    Source = Web.Page(Web.Contents([COLOR=rgb(250, 197, 28)]""https://legislature.idaho.gov/sessioninfo/2023/legislation/H0001/""[/COLOR]))," & Chr(13) & "" & Chr(10) & "    Data0 = Source{0}[Data]," & Chr(13) & "" & Chr(10) & "    #""Changed Type"" = Table.TransformColumnTypes(Data0,{{""Column1"", type text}, {""Column2"", type date}, {""Column3"", type text}, {""Column4"", type text}})" & Chr(13) & "" & Chr(10) & "in" & Chr(13) & "" & Chr(10) & "    #""Changed Type"""
    With ActiveSheet.ListObjects.Add(SourceType:=0, Source:= _
        "OLEDB;Provider=Microsoft.Mashup.OleDb.1;Data Source=$Workbook$;Location=""Table 0"";Extended Properties=""""" _
        , Destination:=Range("$A$1")).QueryTable
        .CommandType = xlCmdSql
        .CommandText = Array("SELECT * FROM [Table 0]")
        .RowNumbers = False
        .FillAdjacentFormulas = False
        .PreserveFormatting = True
        .RefreshOnFileOpen = False
        .BackgroundQuery = True
        .RefreshStyle = xlInsertDeleteCells
        .SavePassword = False
        .SaveData = True
        .AdjustColumnWidth = True
        .RefreshPeriod = 0
        .PreserveColumnInfo = True
        .ListObject.DisplayName = "Table_0"
        .Refresh BackgroundQuery:=False
    End With
    Selection.ListObject.QueryTable.Refresh BackgroundQuery:=False
End Sub
 

Excel Facts

Can a formula spear through sheets?
Use =SUM(January:December!E7) to sum E7 on all of the sheets from January through December
Referring to this line in Macro6 (without the colour tags):
VBA Code:
    ActiveWorkbook.Queries.Add Name:="Table 0", Formula:= _
        "let" & Chr(13) & "" & Chr(10) & "    Source = Web.Page(Web.Contents(""https://legislature.idaho.gov/sessioninfo/2023/legislation/H0001/""))," & Chr(13) & "" & Chr(10) & "    Data0 = Source{0}[Data]," & Chr(13) & "" & Chr(10) & "    #""Changed Type"" = Table.TransformColumnTypes(Data0,{{""Column1"", type text}, {""Column2"", type date}, {""Column3"", type text}, {""Column4"", type text}})" & Chr(13) & "" & Chr(10) & "in" & Chr(13) & "" & Chr(10) & "    #""Changed Type"""
Note how the URL is embedded in a string and surrounded by two pairs of double quotes. Each pair of embedded double quotes resolves to one double quote in the final string, to give:

Power Query:
    Source = Web.Page(Web.Contents("https://legislature.idaho.gov/sessioninfo/2023/legislation/H0001/")),

Therefore you want:
VBA Code:
    ActiveWorkbook.Queries.Add Name:="Table 0", Formula:= _
        "let" & Chr(13) & "" & Chr(10) & "    Source = Web.Page(Web.Contents(""" & webaddress & """))," & Chr(13) & "" & Chr(10) & "    Data0 = Source{0}[Data]," & Chr(13) & "" & Chr(10) & "    #""Changed Type"" = Table.TransformColumnTypes(Data0,{{""Column1"", type text}, {""Column2"", type date}, {""Column3"", type text}, {""Column4"", type text}})" & Chr(13) & "" & Chr(10) & "in" & Chr(13) & "" & Chr(10) & "    #""Changed Type"""
Explanation: in " Source = Web.Page(Web.Contents(""" & WebAddress & """)),"

" Source = Web.Page(Web.Contents(""" is a string with an embedded double quote at the end

and """))," is a string with an embedded double quote at the start and we concatenate WebAddress between the two strings.
 
Upvote 0
I ended up building the entire formula string like this and it seems to be working.
VBA Code:
QFormula = "let" & Chr(13) & "" & Chr(10) & "    Source = Web.Page(Web.Contents(""" & WebAddress & """))," & Chr(13) & "" & Chr(10) & "Data0 = Source{0}[Data]," & Chr(13) & "" & Chr(10) & "    #""Changed Type"" = Table.TransformColumnTypes(Data0,{{""Column1"", type text}, {""Column2"", type date}, {""Column3"", type text}, {""Column4"", type text}})" & Chr(13) & "" & Chr(10) & "in" & Chr(13) & "" & Chr(10) & "    #""Changed Type"""

    Sheets("Scratchpad").Select
    ActiveWorkbook.Queries.Add Name:="Table 0", Formula:=QFormula
 
Upvote 0
Hello. Let's see if the following proposal works for you:
Sample_1.xlsm
\________________________/​

VBA Code:
Sub Macro_9()
Dim iRow&, Url$
iRow = ActiveCell.Row
If Cells(iRow, "B") = "" Or iRow = 1 Then Exit Sub
Url = Cells(iRow, "B"): If Not IsNumeric(Right(Url, 1)) Then Url = Left(Url, Len(Url) - 1)
Url = "https://legislature.idaho.gov/sessioninfo/2023/legislation/" & Url
ThisWorkbook.FollowHyperlink Url
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,098
Messages
6,170,099
Members
452,301
Latest member
QualityAssurance

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