Explore and share Fabric Notebooks to boost Power BI insights in the new community notebooks gallery.
Check it out now!Microsoft is giving away 50,000 FREE Microsoft Certification exam vouchers. Get Fabric certified for FREE! Learn more
Hi guys,
I have a data set like this one and I'd like to split the column containing reasons based on the "," delimitor and then rearrange the resulting columns so that "reasonx" event will always appear only under the columnx.
And I want to get to something like this:
I load and split the columns in my query but after that I don't know how to propery sort the columns as above
Thank you,
Mihnea
Solved! Go to Solution.
Hi Mikyi_ro
basically, you need to unpivot the reason column then duplicate it and re-pivot it. I did it with the following query:
let Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("fY8xDsIwDEXv4jkDqVso12CNOjhx7A0GS5wfJwSkqojlW85//nZSAiKCAHFyIWNrza2SPe4xvCuOGk+whQQ5Z0dwdpGnGH/5aXDzni+lNH7k04+BtXPMzUF0URbTwx1Lx2qt7ixnl30adltE/GW9uGSVfAj5HHfttGpbE1uW/P339gI=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Data = _t, Data.1 = _t, Data.2 = _t, ReasonMerged = _t]), #"Changed Type" = Table.TransformColumnTypes(Source,{{"Data", type text}, {"ReasonMerged", type text}}), #"Renamed Columns" = Table.RenameColumns(#"Changed Type",{{"ReasonMerged", "Reason"}}), #"Split Column by Delimiter" = Table.SplitColumn(#"Renamed Columns", "Reason", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Reason.1", "Reason.2", "Reason.3"}), #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Data.1", type text}, {"Data.2", type text}, {"Reason.1", type text}, {"Reason.2", type text}, {"Reason.3", type text}}), #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type1", {"Data", "Data.1", "Data.2"}, "Attribute", "Value"), #"Removed Columns" = Table.RemoveColumns(#"Unpivoted Other Columns",{"Attribute"}), #"Duplicated Column" = Table.DuplicateColumn(#"Removed Columns", "Value", "Value - Copy"), #"Pivoted Column" = Table.Pivot(#"Duplicated Column", List.Distinct(#"Duplicated Column"[#"Value - Copy"]), "Value - Copy", "Value", List.Max) in #"Pivoted Column"
Original Data:
original
result
Hi Mikyi_ro
basically, you need to unpivot the reason column then duplicate it and re-pivot it. I did it with the following query:
let Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("fY8xDsIwDEXv4jkDqVso12CNOjhx7A0GS5wfJwSkqojlW85//nZSAiKCAHFyIWNrza2SPe4xvCuOGk+whQQ5Z0dwdpGnGH/5aXDzni+lNH7k04+BtXPMzUF0URbTwx1Lx2qt7ixnl30adltE/GW9uGSVfAj5HHfttGpbE1uW/P339gI=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Data = _t, Data.1 = _t, Data.2 = _t, ReasonMerged = _t]), #"Changed Type" = Table.TransformColumnTypes(Source,{{"Data", type text}, {"ReasonMerged", type text}}), #"Renamed Columns" = Table.RenameColumns(#"Changed Type",{{"ReasonMerged", "Reason"}}), #"Split Column by Delimiter" = Table.SplitColumn(#"Renamed Columns", "Reason", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Reason.1", "Reason.2", "Reason.3"}), #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Data.1", type text}, {"Data.2", type text}, {"Reason.1", type text}, {"Reason.2", type text}, {"Reason.3", type text}}), #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type1", {"Data", "Data.1", "Data.2"}, "Attribute", "Value"), #"Removed Columns" = Table.RemoveColumns(#"Unpivoted Other Columns",{"Attribute"}), #"Duplicated Column" = Table.DuplicateColumn(#"Removed Columns", "Value", "Value - Copy"), #"Pivoted Column" = Table.Pivot(#"Duplicated Column", List.Distinct(#"Duplicated Column"[#"Value - Copy"]), "Value - Copy", "Value", List.Max) in #"Pivoted Column"
Original Data:
original
result
Thank you very much!
It's what I needed .
My Table.Pivot statement had List.Count at the end, I changed it to .Max as in yours, but assume it's the same in this case.
Thanks again