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

The Power BI Data Visualization World Championships is back! It's time to submit your entry. Live now!

Reply
Anonymous
Not applicable

Pivot Table with conditional fields

Hi,

I would like to unpivot the summary table below

Table1

NameID-PrimaryID-SecondaryScore 1 (primary)Score 2 (primary)Score 3 (secondary)Type 1 (first)Type 2 (second)

A

100 11 a 
B 201  1b 
C102202111ba

 

to look like this

Table2

Name

IDScore 1 (primary)Score 2 (primary)Score 3 (secondary)Type

A

10011 a
B200  1b
C10211 a
C202  1b

 

So each row of data has ID as the unique key and should only contain info specific to primary or secondary.

Primary should associate to IDs starting with "1" and "a" type, secondary with "2" and "b".

 

 

I know I can do

Table2 =
FILTER(
UNION(
SELECTCOLUMNS(Table1,"Name",[Name],"ID",[ID-Primary]),
SELECTCOLUMNS(Table1,"Name",[Name],"ID",[ID-Secondary])
),
[ID]<>"")
 
to unpivot IDs for each name, but is there a way to set conditionals for updating the score values and unpivoting the type values to match their respective ID?
 
Thanks
1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @Anonymous,

You can try to use the following power query codes to achieve your requirement:

1.png

Full query:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTI0MACSIAYUA1EiiIrViVZygvCNDKASUCVJMHlnsAFGYCVGSGbAFCUqxcYCAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, #"ID-Primary" = _t, #"ID-Secondary" = _t, #"Score 1 (primary)" = _t, #"Score 2 (primary)" = _t, #"Score 3 (secondary)" = _t, #"Type 1 (first)" = _t, #"Type 2 (second)" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"ID-Primary", Int64.Type}, {"ID-Secondary", Int64.Type}, {"Score 1 (primary)", Int64.Type}, {"Score 2 (primary)", Int64.Type}, {"Score 3 (secondary)", Int64.Type}, {"Type 1 (first)", type text}, {"Type 2 (second)", type text}}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Name", "Score 1 (primary)", "Score 2 (primary)", "Score 3 (secondary)", "Type 1 (first)", "Type 2 (second)"}, "Attribute", "Value"),
    #"Replaced Value" = Table.ReplaceValue(#"Unpivoted Columns",each [#"Type 1 (first)"] ,each if [Name]="C" and [Attribute]="ID-Primary" then [#"Type 2 (second)"] else [#"Type 1 (first)"],Replacer.ReplaceText,{"Type 1 (first)"}),
    #"Removed Columns" = Table.RemoveColumns(#"Replaced Value",{"Type 2 (second)", "Attribute"}),
    #"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Type 1 (first)", "Type"}, {"Value", "ID"}})
in
    #"Renamed Columns"

 

Regards,
Xiaoxin Sheng

View solution in original post

2 REPLIES 2
Anonymous
Not applicable

Hi @Anonymous,

You can try to use the following power query codes to achieve your requirement:

1.png

Full query:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTI0MACSIAYUA1EiiIrViVZygvCNDKASUCVJMHlnsAFGYCVGSGbAFCUqxcYCAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, #"ID-Primary" = _t, #"ID-Secondary" = _t, #"Score 1 (primary)" = _t, #"Score 2 (primary)" = _t, #"Score 3 (secondary)" = _t, #"Type 1 (first)" = _t, #"Type 2 (second)" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"ID-Primary", Int64.Type}, {"ID-Secondary", Int64.Type}, {"Score 1 (primary)", Int64.Type}, {"Score 2 (primary)", Int64.Type}, {"Score 3 (secondary)", Int64.Type}, {"Type 1 (first)", type text}, {"Type 2 (second)", type text}}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Name", "Score 1 (primary)", "Score 2 (primary)", "Score 3 (secondary)", "Type 1 (first)", "Type 2 (second)"}, "Attribute", "Value"),
    #"Replaced Value" = Table.ReplaceValue(#"Unpivoted Columns",each [#"Type 1 (first)"] ,each if [Name]="C" and [Attribute]="ID-Primary" then [#"Type 2 (second)"] else [#"Type 1 (first)"],Replacer.ReplaceText,{"Type 1 (first)"}),
    #"Removed Columns" = Table.RemoveColumns(#"Replaced Value",{"Type 2 (second)", "Attribute"}),
    #"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Type 1 (first)", "Type"}, {"Value", "ID"}})
in
    #"Renamed Columns"

 

Regards,
Xiaoxin Sheng

amitchandak
Super User
Super User

@Anonymous , My advice would be unpivoted these tables in the power query. Correct column name and values and then Append in power query

 

https://radacad.com/pivot-and-unpivot-with-power-bi
Append : https://radacad.com/append-vs-merge-in-power-bi-and-power-query

Share with Power BI Enthusiasts: Full Power BI Video (20 Hours) YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube

Helpful resources

Announcements
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.