Geoffrey Learmonth
New Member
Members
Forum Posts: 2
Member Since:
August 2, 2019
August 2, 2019
Offline
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
Catalin Bombea
Iasi, Romania
Member
Dashboards
Power Query
Power Pivot
Xtreme Pivot Tables
Excel for Decision Making
Excel for Finance
Excel Analysis Toolpak
Power BI
Excel
Word
Outlook
Excel Expert
Excel Customer Service
PowerPoint
Power Query
Power Pivot
Xtreme Pivot Tables
Excel for Decision Making
Excel for Finance
Excel Analysis Toolpak
Power BI
Excel
Word
Outlook
Excel Expert
Excel Customer Service
PowerPoint
Forum Posts: 1939
Member Since:
November 8, 2013
November 8, 2013
Offline
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
Answers Post
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Saliha Mohamed
Guest(s) 8
Currently Browsing this Page:
1 Guest(s)
1 Guest(s)
Top Posters:
Catalin Bombea: 1939
SunnyKow: 1432
Anders Sehlstedt: 930
Purfleet: 415
Hans Hallebeek: 355
Frans Visser: 349
David_Ng: 312
lea cohen: 248
Jessica Stewart: 219
A.Maurizio: 216
Newest Members:
HMDIGPzunsnLJt lObJcycvbDLCmIq
Stephen Brown
John Kang'ara
iDeYYtyNRPTss icXlxLtkCZaWuY
Elizabeth Kinsey
Shaun Del Toro
Clive Webb
Forum Stats:
Groups: 3
Forums: 25
Topics: 7095
Posts: 31110
Member Stats:
Guest Posters: 49
Members: 34532
Moderators: 2
Admins: 3
Administrators: Mynda Treacy, Philip Treacy, Jessica
Moderators: Velouria, Riny van Eekelen
© Simple:Press —