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

To celebrate FabCon Vienna, we are offering 50% off select exams. Ends October 3rd. Request your discount now.

Reply
anshpalash
Helper II
Helper II

Data Preparation

Hi all,

 

I have a dataset in format:

 

1Start: 9/23nullnullDuration: 6nullnullEnd: 9/24null
2Start: 9/24nullnullDuration: 4nullEnd: 9/25nullnull
3Start: 9/27nullnullnullDuration: 8nullnullEnd: 9/27

 

I want to convert it to format: 

 

1Start: 9/23Duration: 6End: 9/24
2Start: 9/24Duration: 4End: 9/25
3Start: 9/27Duration: 8End: 9/27

 

Positions of start, duration, end keeps changing. Can somebody please help me how to achieve the above table dynamically?

I would really appreciate your help. Thanks!

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @anshpalash ,

 

Here is the whole M syntax, please check:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUQouSSwqsVKw1DcyBvLySnNyEJRLaVFiSWZ+npWCGYaca14KWJcJTChWJ1rJCMVAEzwGmmCaZIqmHGSgMYqB5hgGYphrgdOh5kqxsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [A = _t, B = _t, C = _t, D = _t, E = _t, F = _t, G = _t, H = _t, L = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"A", Int64.Type}, {"B", type text}, {"C", type text}, {"D", type text}, {"E", type text}, {"F", type text}, {"G", type text}, {"H", type text}, {"L", type text}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"A"}, "Attribute", "Value"),
    #"Filtered Rows" = Table.SelectRows(#"Unpivoted Other Columns", each ([Value] <> "null")),
    #"Added Custom" = Table.AddColumn(#"Filtered Rows", "Custom", each Text.Split([Value],":"){0}),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Attribute"}),
    #"Pivoted Column" = Table.Pivot(#"Removed Columns", List.Distinct(#"Removed Columns"[Custom]), "Custom", "Value")
in
    #"Pivoted Column"

Eyelyn9_0-1633328067482.png

 

Best Regards,
Eyelyn Qin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

2 REPLIES 2
Anonymous
Not applicable

Hi @anshpalash ,

 

Here is the whole M syntax, please check:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUQouSSwqsVKw1DcyBvLySnNyEJRLaVFiSWZ+npWCGYaca14KWJcJTChWJ1rJCMVAEzwGmmCaZIqmHGSgMYqB5hgGYphrgdOh5kqxsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [A = _t, B = _t, C = _t, D = _t, E = _t, F = _t, G = _t, H = _t, L = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"A", Int64.Type}, {"B", type text}, {"C", type text}, {"D", type text}, {"E", type text}, {"F", type text}, {"G", type text}, {"H", type text}, {"L", type text}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"A"}, "Attribute", "Value"),
    #"Filtered Rows" = Table.SelectRows(#"Unpivoted Other Columns", each ([Value] <> "null")),
    #"Added Custom" = Table.AddColumn(#"Filtered Rows", "Custom", each Text.Split([Value],":"){0}),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Attribute"}),
    #"Pivoted Column" = Table.Pivot(#"Removed Columns", List.Distinct(#"Removed Columns"[Custom]), "Custom", "Value")
in
    #"Pivoted Column"

Eyelyn9_0-1633328067482.png

 

Best Regards,
Eyelyn Qin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Anonymous
Not applicable

I would use Table.ToRows to make each of your rows a list. Then use each List.RemoveNulls to make a custom column with the non null values from each row.  Then you can use e Table.FromRows to change it right back into a table.

 

--Nate 

Helpful resources

Announcements
September Power BI Update Carousel

Power BI Monthly Update - September 2025

Check out the September 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 Kudoed Authors