Join us for an expert-led overview of the tools and concepts you'll need to pass exam PL-300. The first session starts on June 11th. See you there!
Get registeredPower BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.
I have a table where my data is split by an ID, just like the example below.
ID | Var1 | Var2 | Var3 |
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.
ID | Var1 | Var2 | Var3 |
1 | A, B, C | A, B, C | A, B, C |
2 | D, E | D, E | D, 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!
Solved! Go to Solution.
@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
@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
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!