cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Anonymous
Not applicable

Split and rearrange resulting columns

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. 

ReasonQuery.PNG

 

And I want to get to something like this: 

ReasonQuery2.PNG

 

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 

1 ACCEPTED SOLUTION
dearwatson
Responsive Resident
Responsive Resident

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:

originaloriginalresultresult

"The commonality between science and art is in trying to see profoundly - to develop strategies of seeing and showing." - Edward Tufte

View solution in original post

2 REPLIES 2
dearwatson
Responsive Resident
Responsive Resident

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:

originaloriginalresultresult

"The commonality between science and art is in trying to see profoundly - to develop strategies of seeing and showing." - Edward Tufte
Anonymous
Not applicable

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

 

Helpful resources

Announcements
September Update

Check it Out!

Click here to learn more about the September 2022 updates!

Power BI Show episode 9

The Power BI Community Show

Watch the playback when Priya Sathy and Charles Webb discuss Datamarts! Kelly also shares Power BI Community updates.

Power BI Dev Camp Session 26

New Date - Check it Out!

Mark your calendars and join us on Thursday, October 6 at 11a PDT for a great session with Ted Pattison!

Top Solution Authors