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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. 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
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

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

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.

Top Solution Authors
Top Kudoed Authors