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
Kev_Tord1
Frequent Visitor

Pivot/Transpose job on multiple columns in same report

Hi everyone,

Had asked this before but the post was messy thus lead to no help. Reposting here for more clarity.

I am currently dealing with a project involving Power Query and was hoping someone could share their light with me. 

I have tried many ways, read posts on this forum as well so I could reach the expected result but can't seem to find the best route to get there. Not quite sure existing solutions offered don't work. I suspect this is due to calculations not always offering the same results.

 

Context: The report lists options calculated for individuals. Not everyone is receiving the same option ("NUM_OPTION_OFFERED").

 

The attached might be self-explanatory but in short, I am trying to pivot a few columns in this report so that each calc ID will result into one single line that will list all options and their underlying data horizontally. 

Note:

Fields CALC_ID,RESULT_ID and ID will always be matching, the options and underlying data are the one resulting in several rows.

"OPTION_TYPE_DESC" will always match its "NUM_OPTION_OFFERED".

The formatting is just to ease the reading of my explanation.

Finally, while there is a way to run this in a matrix visual, I was have this performed in PQ. 

Thanks in advance for any help!

 

Link to Data Sample (Dummy data) used to illustrate the above:

Link (GSheet) 

PQ_Request 2.pngPQ_Request 3.png

 

 

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @Kev_Tord1 ,

Please refer to the following steps:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ldTBbsIwDAbgd+E6H5LYTuLjBJ22AwWhXiaE9v5vscQuNDBSNKn0D7R8MW7I+bzZ+g1stqd6/trV8+E4aYzDz/H9u4zs2L4N5YzkIUsZTOVVL3o3Dyg48KEMHMjmAgUOCgeFg8E1CrofxulnN3yUd1Juz03qJIEc5GYSZyU41VNX75edsnjA0JCUZlRyYMikNBuNSqPS2CucPcTQZJ3GJ87g8UXlT/h+5cReIMlfkjkRSGzrJoVJYerWnSD7JuskIYYMGJ/X7Q1nxVlx7uFlCeQlKp3Bpf+6/W54BO/b1WcXS4uI2qUXFY2KxpctJhTr5JVFEbshBkIg+0nZ6KR0Ujp1mywQuEmdBsvaoN7aINOz6ln1bHq6Fl7rAcYl7Djdc6pF00Q1UU1Mqz9zfxinz8QKhSb6Hs4rTP/tZbNwSmoUk29m/SBytG7eBos7PrhpjX0olRGctIM+G2Z23trmvW3e3PDKxvoVtm1hjn4H8hpJN1IfOoS0RJ+UNfK+p8XCJfpkWiPv+8ngZYkVsjz6yy8=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [CALC_ID = _t, RESULT_ID = _t, ID = _t, NUM_OPTION_OFFERED = _t, OPTION_TYPE_DESC = _t, PB_Amount = _t, P_Amount = _t, L_Code = _t, L_Amount = _t, OPT_TYPE = _t, SB_Flag = _t, PR_Amount = _t, Recalculation_Flag = _t, Max_Amount = _t, RED_PERCENTAGE = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"CALC_ID", type text}, {"RESULT_ID", type text}, {"ID", type text}, {"NUM_OPTION_OFFERED", type text}, {"OPTION_TYPE_DESC", type text}, {"PB_Amount", Int64.Type}, {"P_Amount", Int64.Type}, {"L_Code", type text}, {"L_Amount", Int64.Type}, {"OPT_TYPE", type text}, {"SB_Flag", type text}, {"PR_Amount", Int64.Type}, {"Recalculation_Flag", type text}, {"Max_Amount", Int64.Type}, {"RED_PERCENTAGE", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"CALC_ID", "RESULT_ID", "ID", "NUM_OPTION_OFFERED"}, {{"Data", each _}}),
    #"Sorted Rows" = Table.Sort(#"Grouped Rows",{{"NUM_OPTION_OFFERED", Order.Ascending}}),
    #"Pivoted Column" = Table.Pivot(#"Sorted Rows", List.Distinct(#"Sorted Rows"[NUM_OPTION_OFFERED]), "NUM_OPTION_OFFERED", "Data"),
    #"Expanded OPT1" = Table.ExpandTableColumn(#"Pivoted Column", "OPT1", {"NUM_OPTION_OFFERED", "OPTION_TYPE_DESC", "PB_Amount", "P_Amount", "L_Code", "L_Amount", "OPT_TYPE", "SB_Flag", "PR_Amount", "Recalculation_Flag", "Max_Amount", "RED_PERCENTAGE"}, {"OPT1.NUM_OPTION_OFFERED", "OPT1.OPTION_TYPE_DESC", "OPT1.PB_Amount", "OPT1.P_Amount", "OPT1.L_Code", "OPT1.L_Amount", "OPT1.OPT_TYPE", "OPT1.SB_Flag", "OPT1.PR_Amount", "OPT1.Recalculation_Flag", "OPT1.Max_Amount", "OPT1.RED_PERCENTAGE"})
in
    #"Expanded OPT1"

 

vcgaomsft_0-1717469449231.png

 If I have misunderstood your question, please feel free to contact me.

 

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly --  How to provide sample data in the Power BI Forum -- China Power BI User Group

View solution in original post

1 REPLY 1
Anonymous
Not applicable

Hi @Kev_Tord1 ,

Please refer to the following steps:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ldTBbsIwDAbgd+E6H5LYTuLjBJ22AwWhXiaE9v5vscQuNDBSNKn0D7R8MW7I+bzZ+g1stqd6/trV8+E4aYzDz/H9u4zs2L4N5YzkIUsZTOVVL3o3Dyg48KEMHMjmAgUOCgeFg8E1CrofxulnN3yUd1Juz03qJIEc5GYSZyU41VNX75edsnjA0JCUZlRyYMikNBuNSqPS2CucPcTQZJ3GJ87g8UXlT/h+5cReIMlfkjkRSGzrJoVJYerWnSD7JuskIYYMGJ/X7Q1nxVlx7uFlCeQlKp3Bpf+6/W54BO/b1WcXS4uI2qUXFY2KxpctJhTr5JVFEbshBkIg+0nZ6KR0Ujp1mywQuEmdBsvaoN7aINOz6ln1bHq6Fl7rAcYl7Djdc6pF00Q1UU1Mqz9zfxinz8QKhSb6Hs4rTP/tZbNwSmoUk29m/SBytG7eBos7PrhpjX0olRGctIM+G2Z23trmvW3e3PDKxvoVtm1hjn4H8hpJN1IfOoS0RJ+UNfK+p8XCJfpkWiPv+8ngZYkVsjz6yy8=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [CALC_ID = _t, RESULT_ID = _t, ID = _t, NUM_OPTION_OFFERED = _t, OPTION_TYPE_DESC = _t, PB_Amount = _t, P_Amount = _t, L_Code = _t, L_Amount = _t, OPT_TYPE = _t, SB_Flag = _t, PR_Amount = _t, Recalculation_Flag = _t, Max_Amount = _t, RED_PERCENTAGE = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"CALC_ID", type text}, {"RESULT_ID", type text}, {"ID", type text}, {"NUM_OPTION_OFFERED", type text}, {"OPTION_TYPE_DESC", type text}, {"PB_Amount", Int64.Type}, {"P_Amount", Int64.Type}, {"L_Code", type text}, {"L_Amount", Int64.Type}, {"OPT_TYPE", type text}, {"SB_Flag", type text}, {"PR_Amount", Int64.Type}, {"Recalculation_Flag", type text}, {"Max_Amount", Int64.Type}, {"RED_PERCENTAGE", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"CALC_ID", "RESULT_ID", "ID", "NUM_OPTION_OFFERED"}, {{"Data", each _}}),
    #"Sorted Rows" = Table.Sort(#"Grouped Rows",{{"NUM_OPTION_OFFERED", Order.Ascending}}),
    #"Pivoted Column" = Table.Pivot(#"Sorted Rows", List.Distinct(#"Sorted Rows"[NUM_OPTION_OFFERED]), "NUM_OPTION_OFFERED", "Data"),
    #"Expanded OPT1" = Table.ExpandTableColumn(#"Pivoted Column", "OPT1", {"NUM_OPTION_OFFERED", "OPTION_TYPE_DESC", "PB_Amount", "P_Amount", "L_Code", "L_Amount", "OPT_TYPE", "SB_Flag", "PR_Amount", "Recalculation_Flag", "Max_Amount", "RED_PERCENTAGE"}, {"OPT1.NUM_OPTION_OFFERED", "OPT1.OPTION_TYPE_DESC", "OPT1.PB_Amount", "OPT1.P_Amount", "OPT1.L_Code", "OPT1.L_Amount", "OPT1.OPT_TYPE", "OPT1.SB_Flag", "OPT1.PR_Amount", "OPT1.Recalculation_Flag", "OPT1.Max_Amount", "OPT1.RED_PERCENTAGE"})
in
    #"Expanded OPT1"

 

vcgaomsft_0-1717469449231.png

 If I have misunderstood your question, please feel free to contact me.

 

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly --  How to provide sample data in the Power BI Forum -- China Power BI User Group

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!

November Power BI Update Carousel

Power BI Monthly Update - November 2025

Check out the November 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.