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

Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.

Reply
qsong
Helper II
Helper II

Unpivoting data with multiple rows

Hello PBI user:

 

I have the following structure of data, 

 SCENARIOACFC2FC3PLACFC2FC3PL
COLUMN1COLUMN2

MO

MOMOMOYTDYTDYTDYTD
ax00000000
by00000000
cz00000000
 
 
 

I want to unpivot them into three columns

COLUMN1COLUMN2SCENARIOMOYTD
axAC00
byAC00
czAC00
ax

FC2

00
byFC200
czFC200
axFC300
byFC300
czFC300
axPL00
byPL00
czPL00

 

I am just showing the portion of the data, so it is impossible to do some kind of transpose, because of PBI column limitation. I am wondering if there is a good way to make data transformation.

 

Thank you.

 

Best, Qianru 

1 ACCEPTED SOLUTION
v-lili6-msft
Community Support
Community Support

hi @qsong 

You could try these steps as below:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WUtJRCnZ29XMM8vQHMh2dgYSbsxGYNAaSAT44RGN1opWc/X1Cff0MgQIQFkiBrz8mERnigoUEmZAIZFcAsQFeDFKZBGRVEqUyGciqIqwyFgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t, Column5 = _t, Column6 = _t, Column7 = _t, Column8 = _t, Column9 = _t, Column10 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type text}, {"Column3", type text}, {"Column4", type text}, {"Column5", type text}, {"Column6", type text}, {"Column7", type text}, {"Column8", type text}, {"Column9", type text}, {"Column10", type text}}),
    #"Transposed Table" = Table.Transpose(#"Changed Type"),
    #"Filtered Rows" = Table.SelectRows(#"Transposed Table", each ([Column1] <> "")),
    #"Promoted Headers" = Table.PromoteHeaders(#"Filtered Rows", [PromoteAllScalars=true]),
    #"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers",{{"SCENARIO", type text}, {"COLUMN2", type text}, {"x", Int64.Type}, {"y", Int64.Type}, {"z", Int64.Type}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type1", {"SCENARIO", "COLUMN2"}, "Attribute", "Value"),
    #"Pivoted Column" = Table.Pivot(#"Unpivoted Other Columns", List.Distinct(#"Unpivoted Other Columns"[COLUMN2]), "COLUMN2", "Value"),
    #"Renamed Columns" = Table.RenameColumns(#"Pivoted Column",{{"Attribute", "COLUMN2"}}),
    #"Added Conditional Column" = Table.AddColumn(#"Renamed Columns", "COLUMN1", each if [COLUMN2] = "x" then "a" else if [COLUMN2] = "y" then "b" else "c"),
    #"Reordered Columns" = Table.ReorderColumns(#"Added Conditional Column",{"COLUMN1", "COLUMN2", "SCENARIO", "MO", "YTD"})
in
    #"Reordered Columns"

Result:

11.JPG

and here is sample pbix file, please try it.

 

Regards,

Lin

Community Support Team _ Lin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

5 REPLIES 5
v-lili6-msft
Community Support
Community Support

hi @qsong 

You could try these steps as below:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WUtJRCnZ29XMM8vQHMh2dgYSbsxGYNAaSAT44RGN1opWc/X1Cff0MgQIQFkiBrz8mERnigoUEmZAIZFcAsQFeDFKZBGRVEqUyGciqIqwyFgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t, Column5 = _t, Column6 = _t, Column7 = _t, Column8 = _t, Column9 = _t, Column10 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type text}, {"Column3", type text}, {"Column4", type text}, {"Column5", type text}, {"Column6", type text}, {"Column7", type text}, {"Column8", type text}, {"Column9", type text}, {"Column10", type text}}),
    #"Transposed Table" = Table.Transpose(#"Changed Type"),
    #"Filtered Rows" = Table.SelectRows(#"Transposed Table", each ([Column1] <> "")),
    #"Promoted Headers" = Table.PromoteHeaders(#"Filtered Rows", [PromoteAllScalars=true]),
    #"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers",{{"SCENARIO", type text}, {"COLUMN2", type text}, {"x", Int64.Type}, {"y", Int64.Type}, {"z", Int64.Type}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type1", {"SCENARIO", "COLUMN2"}, "Attribute", "Value"),
    #"Pivoted Column" = Table.Pivot(#"Unpivoted Other Columns", List.Distinct(#"Unpivoted Other Columns"[COLUMN2]), "COLUMN2", "Value"),
    #"Renamed Columns" = Table.RenameColumns(#"Pivoted Column",{{"Attribute", "COLUMN2"}}),
    #"Added Conditional Column" = Table.AddColumn(#"Renamed Columns", "COLUMN1", each if [COLUMN2] = "x" then "a" else if [COLUMN2] = "y" then "b" else "c"),
    #"Reordered Columns" = Table.ReorderColumns(#"Added Conditional Column",{"COLUMN1", "COLUMN2", "SCENARIO", "MO", "YTD"})
in
    #"Reordered Columns"

Result:

11.JPG

and here is sample pbix file, please try it.

 

Regards,

Lin

Community Support Team _ Lin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

I see you have to transpose the orginal table, as I told you that my dataset is longer, more than MAX #columns in PowerBi.  So it is not feasible for my case. 

 

Thank you. 

Ashish_Mathur
Super User
Super User

Hi,

You may refer to my solution here - Rearrange a multi heading dataset into a single heading one which is Pivot ready.

Hope this helps.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Hi Ashish

 

Thank you for your suggestion. Currently, I am building an automized report, and I have to do data cleaning and transformation in PowerBi, so do you have a way to deal with it?

 

Best, Qianru

Hi,

I do not understand.  Doesn't my soluion at the link shared earlier answer your question?


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Helpful resources

Announcements
FabCon Global Hackathon Carousel

FabCon Global Hackathon

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

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.