Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
Good Morning,
I have an issue where I need some help. I have a list of data where I have a unique ID number for each customer. On that customer i have multiple rows of who is assigned to the account. I need to merge the multilple rows (2-5 each) into the same row using the Customer ID for reference and in theory the rest of the data to tack on at the end of the line where the previous row left off that it was merged to.
For this example each Account ID has 2 team members associated.
I would like to to read exactly how line 1 is shown but then add the information from line 2 as the Account Id matches and add the remainder of the row to the tail end (Cell E1-G1)
Solved! Go to Solution.
Hi @AtticusZak - to achieve your outcome you need to understand the advanced feature of Table.Group. Please consider the following Advanced Group By Tricks in Power Query - YouTube. Chandeep gives good explanation. Using this approach, you will have a table with the following:
Within the Nested Table in each row, you will find the two Rows with the employee details that you want to split in Column groups. To these tables though we want to add an Table.AddIndexColumn.
We can now expand the table columns to add Employer, Job, Email, Phone and Index back to Customer.
We can now use the Unpivot and Pivot features in Power Query to transition the Columns to Rows then to separate Columns. Transpose, pivot or unpivot in Power Query? - YouTube
Here is the code I created:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcspPKlbSUfLKTwWSvolF2aklmXnpQLYjEBsqxeoglCTmAcngxJxUEM8JiI3A0kGJyRmpOcVQ7UDKvwDEcQZiYwwFeSmVSIa4ALGJUmwsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Customer = _t, Employee = _t, Job = _t, Email = _t, Phone = _t]),
#"Grouped Rows" = Table.Group(Source, {"Customer"}, {{"Table", each Table.AddIndexColumn(_ , "Index" , 1, 1) }}),
#"Expanded Table" = Table.ExpandTableColumn(#"Grouped Rows", "Table", {"Employee", "Job", "Email", "Phone", "Index"}, {"Employee", "Job", "Email", "Phone", "Index"}),
#"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Expanded Table", {"Customer", "Index"}, "Attribute", "Value"),
#"Merged Columns" = Table.CombineColumns(Table.TransformColumnTypes(#"Unpivoted Columns", {{"Index", type text}}, "en-GB"),{"Attribute", "Index"},Combiner.CombineTextByDelimiter(" ", QuoteStyle.None),"Merged"),
#"Pivoted Column" = Table.Pivot(#"Merged Columns", List.Distinct(#"Merged Columns"[Merged]), "Merged", "Value"),
#"Changed Type" = Table.TransformColumnTypes(#"Pivoted Column",{{"Employee 1", type text}, {"Job 1", type text}, {"Email 1", type text}, {"Phone 1", type text}, {"Employee 2", type text}, {"Job 2", type text}, {"Email 2", type text}, {"Phone 2", type text}})
in
#"Changed Type"
Hello Daryl.
Im looking to do something like this shown below but on a much larger scale.
Turned into
Customer being the place holder and all other rows for the same company merged/added onto the Customer line
Hi @AtticusZak - to achieve your outcome you need to understand the advanced feature of Table.Group. Please consider the following Advanced Group By Tricks in Power Query - YouTube. Chandeep gives good explanation. Using this approach, you will have a table with the following:
Within the Nested Table in each row, you will find the two Rows with the employee details that you want to split in Column groups. To these tables though we want to add an Table.AddIndexColumn.
We can now expand the table columns to add Employer, Job, Email, Phone and Index back to Customer.
We can now use the Unpivot and Pivot features in Power Query to transition the Columns to Rows then to separate Columns. Transpose, pivot or unpivot in Power Query? - YouTube
Here is the code I created:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcspPKlbSUfLKTwWSvolF2aklmXnpQLYjEBsqxeoglCTmAcngxJxUEM8JiI3A0kGJyRmpOcVQ7UDKvwDEcQZiYwwFeSmVSIa4ALGJUmwsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Customer = _t, Employee = _t, Job = _t, Email = _t, Phone = _t]),
#"Grouped Rows" = Table.Group(Source, {"Customer"}, {{"Table", each Table.AddIndexColumn(_ , "Index" , 1, 1) }}),
#"Expanded Table" = Table.ExpandTableColumn(#"Grouped Rows", "Table", {"Employee", "Job", "Email", "Phone", "Index"}, {"Employee", "Job", "Email", "Phone", "Index"}),
#"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Expanded Table", {"Customer", "Index"}, "Attribute", "Value"),
#"Merged Columns" = Table.CombineColumns(Table.TransformColumnTypes(#"Unpivoted Columns", {{"Index", type text}}, "en-GB"),{"Attribute", "Index"},Combiner.CombineTextByDelimiter(" ", QuoteStyle.None),"Merged"),
#"Pivoted Column" = Table.Pivot(#"Merged Columns", List.Distinct(#"Merged Columns"[Merged]), "Merged", "Value"),
#"Changed Type" = Table.TransformColumnTypes(#"Pivoted Column",{{"Employee 1", type text}, {"Job 1", type text}, {"Email 1", type text}, {"Phone 1", type text}, {"Employee 2", type text}, {"Job 2", type text}, {"Email 2", type text}, {"Phone 2", type text}})
in
#"Changed Type"
Hi @AtticusZak - a couple of suggestion that might help the community help you.
(1) Could you add some sample data using the "Add Data" feature in Power BI?
(2) Could you show an example of what you think the end result might look like using Excel?
Many Thanks
Daryl
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
If you love stickers, then you will definitely want to check out our Community Sticker Challenge!