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

Score big with last-minute savings on the final tickets to FabCon Vienna. Secure your discount

Reply
eggyweggs
Frequent Visitor

Tranpose rows to columns

I have a table which shows actions taken by a user ordered by the time executed:

 

DateIDStepsAction
14/04/2022112232Step 1register
14/04/2022112232Step 2register confirmation
14/04/2022112232Step 3first login
14/04/2022112232Step 4login
14/04/2022112233Step 1register
14/04/2022112233Step 2register confirmation
14/04/2022112233Step 3first login
14/04/2022112233Step 4login
14/04/2022112233Step 5login fail

 

I want to tranpose the 2 last columns 'Steps' and 'Action' so that it looks like this:

 

DateIDStep 1Step 2Step 3Step 4Step 5
14/04/2022112232registerregister confirmationfirst loginloginregister
14/04/2022112233registerregister confirmationfirst loginloginlogin fail

 

I've tried tranposing and grouping but I can't quite get it right, any help would be appreciated.

 

Thanks

1 ACCEPTED SOLUTION
Vijay_A_Verma
Super User
Super User

Select column named Steps - Transform tab - Pivot column

In values, choose Action

under Advanced options, choose Don't Aggregate

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("nc/BCoMwDMbxVyk9Cy5JB/oc2016EKkScHa0eX8WD4XtUnW3r/AL/DsM1rXgWrwh2sYCINI+HhLeBnSksHCWkKxvahS/qJniNnN6jcJxO7gjHWqzmDUufKSdjoqj8+H0ZzhdCqer4ffizDzyWnBXcNf3P398hixQVftbVKH1/gM=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, ID = _t, Steps = _t, Action = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}, {"ID", Int64.Type}, {"Steps", type text}, {"Action", type text}}),
    #"Pivoted Column" = Table.Pivot(#"Changed Type", List.Distinct(#"Changed Type"[Steps]), "Steps", "Action")
in
    #"Pivoted Column"

 

View solution in original post

2 REPLIES 2
Vijay_A_Verma
Super User
Super User

Select column named Steps - Transform tab - Pivot column

In values, choose Action

under Advanced options, choose Don't Aggregate

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("nc/BCoMwDMbxVyk9Cy5JB/oc2016EKkScHa0eX8WD4XtUnW3r/AL/DsM1rXgWrwh2sYCINI+HhLeBnSksHCWkKxvahS/qJniNnN6jcJxO7gjHWqzmDUufKSdjoqj8+H0ZzhdCqer4ffizDzyWnBXcNf3P398hixQVftbVKH1/gM=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, ID = _t, Steps = _t, Action = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}, {"ID", Int64.Type}, {"Steps", type text}, {"Action", type text}}),
    #"Pivoted Column" = Table.Pivot(#"Changed Type", List.Distinct(#"Changed Type"[Steps]), "Steps", "Action")
in
    #"Pivoted Column"

 

Thank you, that worked!

Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

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

August 2025 community update carousel

Fabric Community Update - August 2025

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

Top Solution Authors