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

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

Reply
s15
Helper III
Helper III

Pivot multiple columns

 

Hi guys,

 

I have a dataset like below

 

population.PNG

 

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.

 

transpore.PNG

1 ACCEPTED SOLUTION
v-sihou-msft
Microsoft Employee
Microsoft Employee

@s15

 

Please follow steps below:

 

1. Unpivot all years columns.

 

123.PNG

 

2. Then rename the Attribute column into Year.

 

234.PNG

 

3. Pivot Country column.

 

345.PNG

 

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,

 

View solution in original post

3 REPLIES 3
v-sihou-msft
Microsoft Employee
Microsoft Employee

@s15

 

Please follow steps below:

 

1. Unpivot all years columns.

 

123.PNG

 

2. Then rename the Attribute column into Year.

 

234.PNG

 

3. Pivot Country column.

 

345.PNG

 

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 🙂

Thank you @v-sihou-msft That works perfectly!

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

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