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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
H_insight
Helper V
Helper V

Can this multi-level header be transformed by PQ dynamically?

Hi,

 

I have a spreadsheet (attached) that holds multi-level headers. I need to have the data transformed into a tabular format, so I can do some anaylsis.

 

H_insight_0-1652523812439.png

 

May thanls

 

 

1 ACCEPTED SOLUTION
Vijay_A_Verma
Super User
Super User

Below are the steps. Solution file uploaded to https://1drv.ms/x/s!Akd5y6ruJhvhuXVNE1rq8ooZx1rc?e=Mi2OhC 

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Filtered Rows" = Table.SelectRows(Source, each not Text.Contains(Text.From([Column1]),"Total")),
    #"Added Custom" = Table.AddColumn(#"Filtered Rows", "Region", each try if Text.Contains([Column1],"Region") then [Column1] else null otherwise null),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Department", each try if Text.Contains([Column1],"Department") then [Column1] else null otherwise null),
    #"Filled Down" = Table.FillDown(#"Added Custom1",{"Region", "Department"}),
    #"Removed Top Rows" = Table.Skip(#"Filled Down",2),
    #"Promoted Headers" = Table.PromoteHeaders(#"Removed Top Rows", [PromoteAllScalars=true]),
    #"Renamed Columns" = Table.RenameColumns(#"Promoted Headers",{{"Region 1", "Region"}, {"Department 1", "Department"}}),
    #"Reordered Columns" = Table.ReorderColumns(#"Renamed Columns",{"Region", "Department", "#", "Name", "id", "date", "value", "Notes"}),
    #"Filtered Rows1" = Table.SelectRows(#"Reordered Columns", each ([Name] <> null) and ([#"#"] <> "#")),
    #"Changed Type" = Table.TransformColumnTypes(#"Filtered Rows1",{{"Region", type text}, {"Department", type text}, {"#", Int64.Type}, {"Name", type text}, {"id", Int64.Type}, {"date", type datetime}, {"value", Int64.Type}, {"Notes", type text}})
in
    #"Changed Type"

 

View solution in original post

2 REPLIES 2
Vijay_A_Verma
Super User
Super User

Below are the steps. Solution file uploaded to https://1drv.ms/x/s!Akd5y6ruJhvhuXVNE1rq8ooZx1rc?e=Mi2OhC 

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Filtered Rows" = Table.SelectRows(Source, each not Text.Contains(Text.From([Column1]),"Total")),
    #"Added Custom" = Table.AddColumn(#"Filtered Rows", "Region", each try if Text.Contains([Column1],"Region") then [Column1] else null otherwise null),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Department", each try if Text.Contains([Column1],"Department") then [Column1] else null otherwise null),
    #"Filled Down" = Table.FillDown(#"Added Custom1",{"Region", "Department"}),
    #"Removed Top Rows" = Table.Skip(#"Filled Down",2),
    #"Promoted Headers" = Table.PromoteHeaders(#"Removed Top Rows", [PromoteAllScalars=true]),
    #"Renamed Columns" = Table.RenameColumns(#"Promoted Headers",{{"Region 1", "Region"}, {"Department 1", "Department"}}),
    #"Reordered Columns" = Table.ReorderColumns(#"Renamed Columns",{"Region", "Department", "#", "Name", "id", "date", "value", "Notes"}),
    #"Filtered Rows1" = Table.SelectRows(#"Reordered Columns", each ([Name] <> null) and ([#"#"] <> "#")),
    #"Changed Type" = Table.TransformColumnTypes(#"Filtered Rows1",{{"Region", type text}, {"Department", type text}, {"#", Int64.Type}, {"Name", type text}, {"id", Int64.Type}, {"date", type datetime}, {"value", Int64.Type}, {"Notes", type text}})
in
    #"Changed Type"

 

Thank you!

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors
Top Kudoed Authors