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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
KasperJ90
Helper III
Helper III

Multiple columns shown in pivot with only one value

Hi,

I have a table looking like below showing a vendor and certificates (SA8000 etc.) for that vendor in independent columns:

Vendor SA8000  Økotex  BSCI  Amount 
1  Økotex  100
2 SA8000  Økotex  200
3 SA8000   BSCI 300

 

How can I consolidate to show amount pr. vendor in each category like below? 

Vendor SA8000  Økotex  BSCI 
101000
2200200 
3300 300
1 ACCEPTED SOLUTION
Vijay_A_Verma
Super User
Super User

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUQKiwzOy80tSKyAcQwMDpVidaCUjIDvY0cIAyEVTYQRVYYysAoicgp09gZQxSDoWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Vendor = _t, SA8000 = _t, Økotex = _t, BSCI = _t, Amount = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Vendor", Int64.Type}, {"SA8000", type text}, {"Økotex", type text}, {"BSCI", type text}, {"Amount", Int64.Type}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Amount", "Vendor"}, "Attribute", "Value"),
    Custom1 = Table.ReplaceValue(#"Unpivoted Other Columns",each [Amount],each if [Value]="" then 0 else [Amount],Replacer.ReplaceValue,{"Amount"}),
    #"Removed Columns" = Table.RemoveColumns(Custom1,{"Value"}),
    #"Pivoted Column" = Table.Pivot(#"Removed Columns", List.Distinct(#"Removed Columns"[Attribute]), "Attribute", "Amount")
in
    #"Pivoted Column"

 

View solution in original post

2 REPLIES 2
Vijay_A_Verma
Super User
Super User

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUQKiwzOy80tSKyAcQwMDpVidaCUjIDvY0cIAyEVTYQRVYYysAoicgp09gZQxSDoWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Vendor = _t, SA8000 = _t, Økotex = _t, BSCI = _t, Amount = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Vendor", Int64.Type}, {"SA8000", type text}, {"Økotex", type text}, {"BSCI", type text}, {"Amount", Int64.Type}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Amount", "Vendor"}, "Attribute", "Value"),
    Custom1 = Table.ReplaceValue(#"Unpivoted Other Columns",each [Amount],each if [Value]="" then 0 else [Amount],Replacer.ReplaceValue,{"Amount"}),
    #"Removed Columns" = Table.RemoveColumns(Custom1,{"Value"}),
    #"Pivoted Column" = Table.Pivot(#"Removed Columns", List.Distinct(#"Removed Columns"[Attribute]), "Attribute", "Amount")
in
    #"Pivoted Column"

 

HotChilli
Super User
Super User

Unpivot the 3 middle columns.

Remove the Attribute column.

Filter out blank values from Value column.

Pivot the Value column, with Amount in Values (and Do Not Aggregate in Advanced section)

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors
Top Kudoed Authors