• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member
  • Login

Dynamic Column Name with Dynamic Function|Power Query|Excel Forum|My Online Training Hub

You are here: Home / Dynamic Column Name with Dynamic Function|Power Query|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search|Last Search Results
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumPower QueryDynamic Column Name with Dynamic Fu…
sp_PrintTopic sp_TopicIcon
Dynamic Column Name with Dynamic Function
Avatar
Geoffrey Learmonth

New Member
Members
Level 0
Forum Posts: 2
Member Since:
August 2, 2019
sp_UserOfflineSmall Offline
1
August 2, 2019 - 1:21 am
sp_Permalink sp_Print

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"
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.
 
https://www.reuters.com/finance/stocks/income-statement/ACOx.TO?stmtType=INC&perType=INT
https://www.reuters.com/finance/stocks/income-statement/ARX.TO?stmtType=INC&perType=INT
 
Any help would be much appreciated! 
 
Thanks,
Geoffrey
sp_AnswersTopicSeeAnswer See Answer
Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1845
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
2
August 4, 2019 - 3:13 pm
sp_Permalink sp_Print sp_EditHistory

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
sp_AnswersTopicAnswer
Answers Post
Avatar
Geoffrey Learmonth

New Member
Members
Level 0
Forum Posts: 2
Member Since:
August 2, 2019
sp_UserOfflineSmall Offline
3
August 5, 2019 - 8:30 am
sp_Permalink sp_Print

Catalin,

 

Thank you so much! Your solution worked perfectly, I can't tell you how much time this saved me. Thanks again!

 

Geoffrey

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Mynda Treacy
Guest(s) 10
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 880
Purfleet: 414
Frans Visser: 346
David_Ng: 306
lea cohen: 237
Jessica Stewart: 219
A.Maurizio: 213
Aye Mu: 201
Hans Hallebeek: 186
Newest Members:
Kate Dyka
Kwaje Alfred Mogga
thong nguyen
Appiagyei Kofi Frimpong
Hilary Burchfield
Richie Wright
Adel Kock
Barbara Murray
Doug Milne
Siobhan Stringer
Forum Stats:
Groups: 3
Forums: 24
Topics: 6546
Posts: 28658

 

Member Stats:
Guest Posters: 49
Members: 32832
Moderators: 2
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel Office Scripts
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook

Sign up to our newsletter and join over 400,000
others who learn Excel and Power BI with us.

 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate
  • Sponsor Our Newsletter

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.