Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
Anonymous
Not applicable

Power Query Promote Headers Dynamically

Hi Team,

I have a dataset whose sample is below:

amitkumar93_0-1647588434767.png


Now i want to Promote the headers of first two rows from first row and Promote the headers of rest rows from 2nd row.

I have almost 100 rows like this in the original dataset so its difficult to update manually.

Please Advise.

Thanks
Amit

1 ACCEPTED SOLUTION

Solution file upoaded to - https://1drv.ms/x/s!Akd5y6ruJhvhuSx85gpq2K8FOskP?e=eBqPq8 

You can incorporate following M codes

For case 1

 

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Transposed Table" = Table.Transpose(Source),
    #"Merged Columns" = Table.CombineColumns(#"Transposed Table",{"Column1", "Column2"},Combiner.CombineTextByDelimiter("", QuoteStyle.None),"Merged"),
    #"Transposed Table1" = Table.Transpose(#"Merged Columns"),
    #"Promoted Headers" = Table.PromoteHeaders(#"Transposed Table1", [PromoteAllScalars=true])
in
    #"Promoted Headers"

 

For Case 2

let
    Source = Excel.CurrentWorkbook(){[Name="Table2"]}[Content],
    #"Demoted Headers" = Table.DemoteHeaders(Source),
    #"Transposed Table" = Table.Transpose(#"Demoted Headers"),
    #"Added Custom" = Table.AddColumn(#"Transposed Table", "Custom", each (if Text.Contains([Column1],"Column") or Text.Contains([Column1],"_") then "" else [Column1])&(if [Column2]=null then "" else [Column2])),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Column1", "Column2"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Columns",{List.Last(Table.ColumnNames(#"Removed Columns"))}&List.RemoveLastN(Table.ColumnNames(#"Removed Columns"),1) ),
    #"Transposed Table1" = Table.Transpose(#"Reordered Columns"),
    #"Promoted Headers" = Table.PromoteHeaders(#"Transposed Table1", [PromoteAllScalars=true])
in
    #"Promoted Headers"

 

View solution in original post

3 REPLIES 3
Anonymous
Not applicable

@Vijay_A_Verma You are a Lifesaver!, Thank you very much.. 

Anonymous
Not applicable

I have one more situation where i already have header for the first 2 rows and rest of rows has the header in the first row.

amitkumar93_0-1647588892823.png

Please advise for this one as well.

Thanks

Solution file upoaded to - https://1drv.ms/x/s!Akd5y6ruJhvhuSx85gpq2K8FOskP?e=eBqPq8 

You can incorporate following M codes

For case 1

 

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Transposed Table" = Table.Transpose(Source),
    #"Merged Columns" = Table.CombineColumns(#"Transposed Table",{"Column1", "Column2"},Combiner.CombineTextByDelimiter("", QuoteStyle.None),"Merged"),
    #"Transposed Table1" = Table.Transpose(#"Merged Columns"),
    #"Promoted Headers" = Table.PromoteHeaders(#"Transposed Table1", [PromoteAllScalars=true])
in
    #"Promoted Headers"

 

For Case 2

let
    Source = Excel.CurrentWorkbook(){[Name="Table2"]}[Content],
    #"Demoted Headers" = Table.DemoteHeaders(Source),
    #"Transposed Table" = Table.Transpose(#"Demoted Headers"),
    #"Added Custom" = Table.AddColumn(#"Transposed Table", "Custom", each (if Text.Contains([Column1],"Column") or Text.Contains([Column1],"_") then "" else [Column1])&(if [Column2]=null then "" else [Column2])),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Column1", "Column2"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Columns",{List.Last(Table.ColumnNames(#"Removed Columns"))}&List.RemoveLastN(Table.ColumnNames(#"Removed Columns"),1) ),
    #"Transposed Table1" = Table.Transpose(#"Reordered Columns"),
    #"Promoted Headers" = Table.PromoteHeaders(#"Transposed Table1", [PromoteAllScalars=true])
in
    #"Promoted Headers"

 

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

Find out what's new and trending in the Fabric Community.

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

Check out the November 2024 Power BI update to learn about new features.