Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredGet Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Learn more
 
					
				
		
Hi
I would like to transform the FROM TABLE data TO TABLE one below using power query/ (transformation). Kindly help
Solved! Go to Solution.
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
into this
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
 
					
				
		
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
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
into this
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
 
					
				
				
			
		
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!
Check out the October 2025 Power BI update to learn about new features.
