Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register 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 🙂
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
56 | |
55 | |
54 | |
37 | |
29 |
User | Count |
---|---|
77 | |
62 | |
45 | |
40 | |
40 |