March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
Register NowGet certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now
Hi guys,
I have a dataset like below
I'm finding the way to pivot years into a column named Years. And 5 countries shall be in 5 column headers.
If I use Transpose then I seem to lose all years.
Solved! Go to Solution.
Please follow steps below:
1. Unpivot all years columns.
2. Then rename the Attribute column into Year.
3. Pivot Country column.
See entire M query:
let Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCg1W0lEyBGITIDZXitWJVnJOzEtMSQRyjYDYFIgtwMJuRYl5yalArjEQmwGxpVJsLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Country = _t, #"1999" = _t, #"2000" = _t, #"2001" = _t]), #"Changed Type" = Table.TransformColumnTypes(Source,{{"Country", type text}, {"1999", Int64.Type}, {"2000", Int64.Type}, {"2001", Int64.Type}}), #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Country"}, "Attribute", "Value"), #"Renamed Columns" = Table.RenameColumns(#"Unpivoted Columns",{{"Attribute", "Year"}}), #"Pivoted Column" = Table.Pivot(#"Renamed Columns", List.Distinct(#"Renamed Columns"[Country]), "Country", "Value", List.Sum) in #"Pivoted Column"
Regards,
Please follow steps below:
1. Unpivot all years columns.
2. Then rename the Attribute column into Year.
3. Pivot Country column.
See entire M query:
let Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCg1W0lEyBGITIDZXitWJVnJOzEtMSQRyjYDYFIgtwMJuRYl5yalArjEQmwGxpVJsLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Country = _t, #"1999" = _t, #"2000" = _t, #"2001" = _t]), #"Changed Type" = Table.TransformColumnTypes(Source,{{"Country", type text}, {"1999", Int64.Type}, {"2000", Int64.Type}, {"2001", Int64.Type}}), #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Country"}, "Attribute", "Value"), #"Renamed Columns" = Table.RenameColumns(#"Unpivoted Columns",{{"Attribute", "Year"}}), #"Pivoted Column" = Table.Pivot(#"Renamed Columns", List.Distinct(#"Renamed Columns"[Country]), "Country", "Value", List.Sum) in #"Pivoted Column"
Regards,
Absolutely Great !!! you saved lot of working hours 🙂
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
Check out the November 2024 Power BI update to learn about new features.
User | Count |
---|---|
121 | |
99 | |
89 | |
72 | |
62 |
User | Count |
---|---|
140 | |
121 | |
106 | |
98 | |
94 |