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

The Power BI Data Visualization World Championships is back! It's time to submit your entry. Live now!

Reply
Anonymous
Not applicable

Return a Split Column After Transformation

Hi folks, 

 

Is there an efficient way to return a previously split column (by row) back to a comma-separated list in a single cell after performing transformations on it? I have a table like the following, which I split by delimiter into rows so I could perform Left Outer Joins via the Merge Query utility in order to identify the users by another table:

 

Initial Table:

JobIDOther Users
111UserID1, UserID2
222UserID3, UserID5, UserID6

 

Resulting Table After Splitting "Other Users" Column And Performing Outer Joing with Other Table to ID users:

Job IDOther UsersUser Names
111UserID1Steve
111UserID2Sally
222UserID3Juan
222UserID5Eric
222UserID6Tran

 

Desired Result (for the purposes of the report, it needs to return to this format):

Job IDUser Names
111Steve, Sally
222Juan, Eric, Tran

 

I am not sure how to get that final result so any insights would be appreciated. Thanks!

1 ACCEPTED SOLUTION
Greg_Deckler
Community Champion
Community Champion

@Anonymous Do a Group By step like this:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQ0VNJRCi1OLfJ0AbGCS1LLUpVidVBljEAyiTk5lWAZIyMjuIwxkOVVmpiHIWEKZLkWZSZjSJgBWSFFIB2xAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Job ID" = _t, #"Other Users" = _t, #"User Names" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Job ID", Int64.Type}, {"Other Users", type text}, {"User Names", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Job ID"}, {{"User Names", each Text.Combine([User Names], ", "), type nullable text}})
in
    #"Grouped Rows"

 



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

1 REPLY 1
Greg_Deckler
Community Champion
Community Champion

@Anonymous Do a Group By step like this:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQ0VNJRCi1OLfJ0AbGCS1LLUpVidVBljEAyiTk5lWAZIyMjuIwxkOVVmpiHIWEKZLkWZSZjSJgBWSFFIB2xAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Job ID" = _t, #"Other Users" = _t, #"User Names" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Job ID", Int64.Type}, {"Other Users", type text}, {"User Names", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Job ID"}, {{"User Names", each Text.Combine([User Names], ", "), type nullable text}})
in
    #"Grouped Rows"

 



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! It's time to submit your entry.

January Power BI Update Carousel

Power BI Monthly Update - January 2026

Check out the January 2026 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.