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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Anonymous
Not applicable

Power Query to shape excel to a single table

Hi,

 

I'm trying to use power query to extract data from an excel form. Here's an example of the source that I have:

 

MonthJanuary
CarsQty

Blue

1

Green

2

Yellow3
Red4
Trucks

Qty

Orange

1

Black

2

White

1

Silver

2

 

I'm trying to end up with the following:

ItemQty
Cars-Blue1
Cars-Green2
Cars-Yellow3
Cars-Red4
Trucks-Orange1
Truck-black2
Truck-white1
Truck-silver2

 

I'm able to do it for cars using the method outlined here but cannot seem to figure out how to add trucks into the single query. I'm also able to do it in 2 seperate queries and then append but would like to know how best to combine into a single query. If anyone can help that would be great or point me to any resources I'll be eternally grateful!

 

I've uploaded an excel of the sample dataset for your convenience [click to download]

 

Thanks!

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hey,

 

I was able to solve it using the code below.

 

 

let
    Source = Excel.CurrentWorkbook(){[Name="Data"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type any}}),
    #"Filtered Rows" = Table.SelectRows(#"Changed Type", each ([Column1] <> null and [Column1] <> "Month")),
    #"Added Custom" = Table.AddColumn(#"Filtered Rows", "Custom", each if [Column2] = null then [Column1] else null),
    #"Filled Down" = Table.FillDown(#"Added Custom",{"Custom"}),
    #"Filtered Rows1" = Table.SelectRows(#"Filled Down", each ([Column2] <> null)),
    #"Renamed Columns" = Table.RenameColumns(#"Filtered Rows1",{{"Custom", "Item"}, {"Column1", "Color"}, {"Column2", "Qty"}}),
    #"Reordered Columns" = Table.ReorderColumns(#"Renamed Columns",{"Color", "Item", "Qty"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Reordered Columns",{{"Qty", type number}, {"Item", type text}})
in
    #"Changed Type1"

 

 

The result I get from it is the following

 

Annotation 2019-11-22 180937.png

 

I hope it helps.

View solution in original post

2 REPLIES 2
Anonymous
Not applicable

Hey,

 

I was able to solve it using the code below.

 

 

let
    Source = Excel.CurrentWorkbook(){[Name="Data"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type any}}),
    #"Filtered Rows" = Table.SelectRows(#"Changed Type", each ([Column1] <> null and [Column1] <> "Month")),
    #"Added Custom" = Table.AddColumn(#"Filtered Rows", "Custom", each if [Column2] = null then [Column1] else null),
    #"Filled Down" = Table.FillDown(#"Added Custom",{"Custom"}),
    #"Filtered Rows1" = Table.SelectRows(#"Filled Down", each ([Column2] <> null)),
    #"Renamed Columns" = Table.RenameColumns(#"Filtered Rows1",{{"Custom", "Item"}, {"Column1", "Color"}, {"Column2", "Qty"}}),
    #"Reordered Columns" = Table.ReorderColumns(#"Renamed Columns",{"Color", "Item", "Qty"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Reordered Columns",{{"Qty", type number}, {"Item", type text}})
in
    #"Changed Type1"

 

 

The result I get from it is the following

 

Annotation 2019-11-22 180937.png

 

I hope it helps.

Anonymous
Not applicable

thank you @Anonymous !

 

After looking at your solution I can only facepalm at it's simplicity. Thank you!

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.