Notifications
Clear all
Power Query
3
Posts
2
Users
0
Reactions
171
Views
Topic starter
Good afternoon,
I am new to Power Query and am running into some difficulty creating a Dynamic Column Name. I have a function which works well when the table headers are the same but I am now looking to use it to extract income statement data and it is not working for all URL's. The issue is that the header changes depending on the date of the reporting period (e.g. 2019-06-30 or 2019-03-31).
The function, titled "fGetResults" is below:
let GetResults=(URL) =>
let
Source = Web.Page(Web.Contents(URL)),
Data0 = Source{0}[Data],
#"Changed Type" = Table.TransformColumnTypes(Data0,{{"In Millions ofCanadian Dollars #(lf) (except for per share items)", type text}, {"2019 #(lf) 2019-06-30 #(lf) #(lf) #(lf) Period Length #(lf) 3 Months", type text}}),
#"Promoted Headers" = Table.PromoteHeaders(#"Changed Type", [PromoteAllScalars=true]),
DynamicNameHeader= Table.ColumnNames(#"Promoted Headers"){1},
#"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers",{{"In Millions ofCanadian Dollars#(cr)#(lf)#(lf) (except for per share items)", type text}, {Table.ColumnNames(#"Promoted Headers"){1}, type text}}),
#"Renamed Columns" = Table.RenameColumns(#"Changed Type1",{{"In Millions ofCanadian Dollars#(cr)#(lf)#(lf) (except for per share items)", "Query Item"}, {Table.ColumnNames(#"Promoted Headers"){1}, "Query Result"}})
in
#"Renamed Columns"
Source = Web.Page(Web.Contents(URL)),
Data0 = Source{0}[Data],
#"Changed Type" = Table.TransformColumnTypes(Data0,{{"In Millions ofCanadian Dollars #(lf) (except for per share items)", type text}, {"2019 #(lf) 2019-06-30 #(lf) #(lf) #(lf) Period Length #(lf) 3 Months", type text}}),
#"Promoted Headers" = Table.PromoteHeaders(#"Changed Type", [PromoteAllScalars=true]),
DynamicNameHeader= Table.ColumnNames(#"Promoted Headers"){1},
#"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers",{{"In Millions ofCanadian Dollars#(cr)#(lf)#(lf) (except for per share items)", type text}, {Table.ColumnNames(#"Promoted Headers"){1}, type text}}),
#"Renamed Columns" = Table.RenameColumns(#"Changed Type1",{{"In Millions ofCanadian Dollars#(cr)#(lf)#(lf) (except for per share items)", "Query Item"}, {Table.ColumnNames(#"Promoted Headers"){1}, "Query Result"}})
in
#"Renamed Columns"
in GetResults
After that, I just run a query from a table of URL's. I still get an error when the header name isn't the line with "2019-06-30" in it. I tried to fix this by creating the dynamic name header line, but it didn't work.
For reference, here are two URL's that I'm testing against. The first one works, the second one doesn't.
Any help would be much appreciated!
Thanks,
Geoffrey
Posted : 02/08/2019 11:21 am
Hi Geoffrey,
Try this version:
let GetResults=(URL) =>
let
Source = Web.Page(Web.Contents(URL)),
#"Removed Other Columns" = Table.SelectColumns(Source,{"Data"}),
Data = #"Removed Other Columns"{0}[Data],
#"Demoted Headers" = Table.DemoteHeaders(Data),
#"Removed Top Rows" = Table.Skip(#"Demoted Headers",1),
NewNames={#"Removed Top Rows"[Column1]{0},#"Removed Top Rows"[Column2]{0}},
#"Renamed Columns" = Table.RenameColumns(#"Removed Top Rows",List.Zip({Table.ColumnNames( #"Removed Top Rows"),NewNames}))
in
#"Renamed Columns"
in GetResults
let
Source = Web.Page(Web.Contents(URL)),
#"Removed Other Columns" = Table.SelectColumns(Source,{"Data"}),
Data = #"Removed Other Columns"{0}[Data],
#"Demoted Headers" = Table.DemoteHeaders(Data),
#"Removed Top Rows" = Table.Skip(#"Demoted Headers",1),
NewNames={#"Removed Top Rows"[Column1]{0},#"Removed Top Rows"[Column2]{0}},
#"Renamed Columns" = Table.RenameColumns(#"Removed Top Rows",List.Zip({Table.ColumnNames( #"Removed Top Rows"),NewNames}))
in
#"Renamed Columns"
in GetResults
Posted : 05/08/2019 1:13 am
Topic starter
Catalin,
Thank you so much! Your solution worked perfectly, I can't tell you how much time this saved me. Thanks again!
Geoffrey
Posted : 05/08/2019 6:30 pm