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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
huynq
Frequent Visitor

Convert columns to rows with dynamic columns

I've tried to find the solution for this but didn't work so I post this message for your help.

I have this data:

 

 1/11/21/3
A112
B023
C11null (ignore null or default to be 0 is fine)
 2/12/2null
A11null

 

What I'm looking for

A1/11
A1/21
A1/32
B1/10
B1/22
B1/33
C1/11
C1/21
A2/11
A2/21

 

😍I know that the data looks stupid becauseI have to deal with legacy from decade ago.

I would like to say thanks in advance. 

1 ACCEPTED SOLUTION
Jimmy801
Community Champion
Community Champion

Hallo @huynq 

 

you have to first split der your data into tables, promote headers, combine your tables and then do unpivotother

Here the complete solution

let
	Source = #table
	(
		{"Column1","Column2","Column3","Column4"},
		{
			{"","1/1","1/2","1/3"},	{"A","1","1","2"},	{"B","0","2","3"},	{"C","1","1",""},	{"","2/1","2/2",""},	{"A","1","1",""}
		}
	),
    AddIndex = Table.AddIndexColumn(Source, "Index", 0, 1),
    AddDevideTable = Table.AddColumn(AddIndex, "Devide Table", each if [Column1]="" then [Index] else null),
    FillDownDevideTable = Table.FillDown(AddDevideTable,{"Devide Table"}),
    GroupTables = Table.Group(FillDownDevideTable, {"Devide Table"}, {{"AllRows", each _, type table [Column1=text, Column2=text, Column3=text, Column4=text, Index=number, Devide Table=number]}}),
	MaintainTable = Table.TransformColumns
	(
		GroupTables,
		{
			{
				"AllRows",
				(tableint) =>
				let 
					DeleteIndexDevideTable = Table.RemoveColumns(tableint, {"Index", "Devide Table"}),
					Promote = Table.PromoteHeaders(DeleteIndexDevideTable)
				in 
					Promote
			}
		}
	),
	Combine = Table.Combine
	(
		MaintainTable[AllRows]
	),
    UnpivotOther = Table.UnpivotOtherColumns(Combine, {""}, "Attribute", "Value"),
    FilterNonEmptyValue = Table.SelectRows(UnpivotOther, each ([Value] <> ""))
in
    FilterNonEmptyValue

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works. If this solution fits your need, copy and past a part of it and implement it in your query

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

5 REPLIES 5
Hitesh-Dsouza
Regular Visitor

Try using "Unpivot Other Columns" under "Transform" options in Power BI.

Jimmy801
Community Champion
Community Champion

Hallo @huynq 

 

you have to first split der your data into tables, promote headers, combine your tables and then do unpivotother

Here the complete solution

let
	Source = #table
	(
		{"Column1","Column2","Column3","Column4"},
		{
			{"","1/1","1/2","1/3"},	{"A","1","1","2"},	{"B","0","2","3"},	{"C","1","1",""},	{"","2/1","2/2",""},	{"A","1","1",""}
		}
	),
    AddIndex = Table.AddIndexColumn(Source, "Index", 0, 1),
    AddDevideTable = Table.AddColumn(AddIndex, "Devide Table", each if [Column1]="" then [Index] else null),
    FillDownDevideTable = Table.FillDown(AddDevideTable,{"Devide Table"}),
    GroupTables = Table.Group(FillDownDevideTable, {"Devide Table"}, {{"AllRows", each _, type table [Column1=text, Column2=text, Column3=text, Column4=text, Index=number, Devide Table=number]}}),
	MaintainTable = Table.TransformColumns
	(
		GroupTables,
		{
			{
				"AllRows",
				(tableint) =>
				let 
					DeleteIndexDevideTable = Table.RemoveColumns(tableint, {"Index", "Devide Table"}),
					Promote = Table.PromoteHeaders(DeleteIndexDevideTable)
				in 
					Promote
			}
		}
	),
	Combine = Table.Combine
	(
		MaintainTable[AllRows]
	),
    UnpivotOther = Table.UnpivotOtherColumns(Combine, {""}, "Attribute", "Value"),
    FilterNonEmptyValue = Table.SelectRows(UnpivotOther, each ([Value] <> ""))
in
    FilterNonEmptyValue

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works. If this solution fits your need, copy and past a part of it and implement it in your query

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

That's amazing solution @Jimmy801  . Thank you very much.

By the way, how can you create that kind of amazing moves? Can you share us some experiences?

Jimmy801
Community Champion
Community Champion

Hello @huynq 

 

you are welcome. Thanks for the feedback... I appreciate that

Is all learning by doing 🙂

Difficult to pass experience. You have to really understand every function and how you can combine them.

 

Jimmy

Anonymous
Not applicable

I believe the function you are looking for is "Unpivot Other Columns".  You'll find it in the ribbon under "Transform"

 

Go into your query editor, select only the first column (that contains A, B, C etc). Select unpivot other columns and you should be good to go.

 

Capture.PNG

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors
Top Kudoed Authors