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
Anonymous
Not applicable

Table Transformation using power query

Hi


I would like to transform the FROM TABLE data TO TABLE one below using power query/ (transformation). Kindly help


Capture.PNG

1 ACCEPTED SOLUTION
Jimmy801
Community Champion
Community Champion

Hello @Anonymous 

 

this can be achieved by Table.Transpose and splitting columns and pivoting. But what you didn't tell is what happens if your FROM TABLE has two or more rows instead of 1.

Here the solution usinig your data

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjRQ0lEyAhHGIMLEQCk2FgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ABC_MONTH = _t, ABC_YEAR = _t, XYZ_MONTH = _t, XYZ_YEAR = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ABC_MONTH", Int64.Type}, {"ABC_YEAR", Int64.Type}, {"XYZ_MONTH", Int64.Type}, {"XYZ_YEAR", Int64.Type}}),
    Transpose = Table.FromColumns({Table.ColumnNames(#"Changed Type")} & Table.ToColumns(Table.Transpose(#"Changed Type"))),
    #"Split Column by Delimiter" = Table.SplitColumn(Transpose, "Column1", Splitter.SplitTextByEachDelimiter({"_"}, QuoteStyle.Csv, false), {"Column1.1", "Column1.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Column1.1", type text}, {"Column1.2", type text}}),
    #"Pivoted Column" = Table.Pivot(#"Changed Type1", List.Distinct(#"Changed Type1"[Column1.2]), "Column1.2", "Column2", List.Sum),
    #"Renamed Columns" = Table.RenameColumns(#"Pivoted Column",{{"Column1.1", "Name"}})
in
    #"Renamed Columns"

transforms this

Jimmy801_0-1615544824654.png

into this

Jimmy801_1-1615544833975.png

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

 

View solution in original post

3 REPLIES 3
Anonymous
Not applicable

Thanks for your Solution. It works perfectly.  My table will have only one row containing sum of  values...

 

One query is when i do Transformation-> transpose, then only Values are listed in a column . column names column  is lost why ? 

Hello @Anonymous 

 

good question... we would need to ask the devoloper 🙂

this is the reason why I used Table.ToColumns and Table.FromColumns to add the column names again

 

BR

 

Jimmy

Jimmy801
Community Champion
Community Champion

Hello @Anonymous 

 

this can be achieved by Table.Transpose and splitting columns and pivoting. But what you didn't tell is what happens if your FROM TABLE has two or more rows instead of 1.

Here the solution usinig your data

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjRQ0lEyAhHGIMLEQCk2FgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ABC_MONTH = _t, ABC_YEAR = _t, XYZ_MONTH = _t, XYZ_YEAR = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ABC_MONTH", Int64.Type}, {"ABC_YEAR", Int64.Type}, {"XYZ_MONTH", Int64.Type}, {"XYZ_YEAR", Int64.Type}}),
    Transpose = Table.FromColumns({Table.ColumnNames(#"Changed Type")} & Table.ToColumns(Table.Transpose(#"Changed Type"))),
    #"Split Column by Delimiter" = Table.SplitColumn(Transpose, "Column1", Splitter.SplitTextByEachDelimiter({"_"}, QuoteStyle.Csv, false), {"Column1.1", "Column1.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Column1.1", type text}, {"Column1.2", type text}}),
    #"Pivoted Column" = Table.Pivot(#"Changed Type1", List.Distinct(#"Changed Type1"[Column1.2]), "Column1.2", "Column2", List.Sum),
    #"Renamed Columns" = Table.RenameColumns(#"Pivoted Column",{{"Column1.1", "Name"}})
in
    #"Renamed Columns"

transforms this

Jimmy801_0-1615544824654.png

into this

Jimmy801_1-1615544833975.png

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

 

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.