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

Power BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.

Reply
Anonymous
Not applicable

Group by and Concatenate Rows for Multiple Columns with Power Query

I have a table where my data is split by an ID, just like the example below.

IDVar1Var2Var3
1   

A

A   A   
1   B   B   B   
1   C   C   C   
2   D   D   D   
2   E   E   E   

What I need to get is a table grouped by ID, concatenating each column.

IDVar1Var2Var3
1A, B, C   A, B, C   A, B, C   
2D, ED, ED, E

I'm able to concatenate 1 column using Power Query. Is it possible to do the same for multiple columns? How can I do that?

Thank you!

1 ACCEPTED SOLUTION
AntrikshSharma
Super User
Super User

@Anonymous You can use this:

let
    Source = Table.FromRows (
        Json.Document (
            Binary.Decompress (
                Binary.FromText (
                    "i45WMlTSUXKE41gdiIgTHMNEnOEYJGIEZLnAMUzEFY5jYwE=",
                    BinaryEncoding.Base64
                ),
                Compression.Deflate
            )
        ),
        let
            _t = ( ( type nullable text ) meta [ Serialized.Text = true ] )
        in
            type table [ ID = _t, Var1 = _t, Var2 = _t, Var3 = _t ]
    ),
    ChangedType = Table.TransformColumnTypes (
        Source,
        {
            { "ID", Int64.Type },
            { "Var1", type text },
            { "Var2", type text },
            { "Var3", type text }
        }
    ),
    Group = Table.Group (
        ChangedType,
        { "ID" },
        {
            {
                "Transformation",
                ( CurrentGroup ) =>
                    let
                        DataCols    = Table.RemoveColumns ( CurrentGroup, "ID" ),
                        ColumnNames = Table.ColumnNames ( DataCols ),
                        ColumnsList = Table.ToColumns ( DataCols ),
                        Combine     = List.Transform ( ColumnsList, each Text.Combine ( _, ", " ) ),
                        Result      = Table.FromRows ( { Combine }, ColumnNames )
                    in
                        Result,
                type table [
                    ID = nullable number,
                    Var1 = nullable text,
                    Var2 = nullable text,
                    Var3 = nullable text
                ]
            }
        }
    ),
    ExpandedTransformation = Table.ExpandTableColumn (
        Group,
        "Transformation",
        { "Var1", "Var2", "Var3" },
        { "Var1", "Var2", "Var3" }
    )
in
    ExpandedTransformation

View solution in original post

3 REPLIES 3
AntrikshSharma
Super User
Super User

@Anonymous You can use this:

let
    Source = Table.FromRows (
        Json.Document (
            Binary.Decompress (
                Binary.FromText (
                    "i45WMlTSUXKE41gdiIgTHMNEnOEYJGIEZLnAMUzEFY5jYwE=",
                    BinaryEncoding.Base64
                ),
                Compression.Deflate
            )
        ),
        let
            _t = ( ( type nullable text ) meta [ Serialized.Text = true ] )
        in
            type table [ ID = _t, Var1 = _t, Var2 = _t, Var3 = _t ]
    ),
    ChangedType = Table.TransformColumnTypes (
        Source,
        {
            { "ID", Int64.Type },
            { "Var1", type text },
            { "Var2", type text },
            { "Var3", type text }
        }
    ),
    Group = Table.Group (
        ChangedType,
        { "ID" },
        {
            {
                "Transformation",
                ( CurrentGroup ) =>
                    let
                        DataCols    = Table.RemoveColumns ( CurrentGroup, "ID" ),
                        ColumnNames = Table.ColumnNames ( DataCols ),
                        ColumnsList = Table.ToColumns ( DataCols ),
                        Combine     = List.Transform ( ColumnsList, each Text.Combine ( _, ", " ) ),
                        Result      = Table.FromRows ( { Combine }, ColumnNames )
                    in
                        Result,
                type table [
                    ID = nullable number,
                    Var1 = nullable text,
                    Var2 = nullable text,
                    Var3 = nullable text
                ]
            }
        }
    ),
    ExpandedTransformation = Table.ExpandTableColumn (
        Group,
        "Transformation",
        { "Var1", "Var2", "Var3" },
        { "Var1", "Var2", "Var3" }
    )
in
    ExpandedTransformation
HotChilli
Super User
Super User

I suppose you have a good reason for doing this but the format of the first table looks absolutely fine.  You could then do the 2nd table in DAX

---

However, if you want to go ahead in Power Query:

Group By the ID with 3 aggregations (Choose Min on each column name - it doesn't really matter because you are going to edit the code after this).

Use Text.Combine() with a comma to replace the aggregations in the line of code that was produced by the 'group by' i.e. put the text.combine instead of List.Min and edit the code to get rid of any syntax errors

This exactly solved my current problem, thank you for this!

Helpful resources

Announcements
June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

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

June 2025 community update carousel

Fabric Community Update - June 2025

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

Top Solution Authors