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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
bbbt123
Helper I
Helper I

data transformation in power query

Hi,  I need to transform data as per example below:

 

Table is:

+----+------+
| Id | Name |
+----+------+    
| 1  | aaa  |
| 1  | bbb  |
| 1  | ccc  |
| 1  | ddd  |
| 1  | eee  |
+----+------+

Required output:

+----+---------------------+
| Id |        abc          |
+----+---------------------+ 
|  1 | aaa,bbb,ccc,ddd,eee |
+----+---------------------+

How can I achieve this in power query?

 

Thank you in advance

1 ACCEPTED SOLUTION
edhans
Super User
Super User

  1. Group your data by the first column, and for the aggregation use the ALL ROWS aggregation and call it "AllRows"
  2. Add a custom column, call it Names, and use Table.Column([AllRows], "Name") as the formula.
  3. Expand the new Names column but as Values (not rows) and select the comma as your delimiter.
  4. Select the ID and Names column and remove other columns.

 

2020-01-14 08_43_14-Table1 - Power Query Editor.png

 

Full M query (my data came from an Excel table which explains the source)

 

 

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Id", Int64.Type}, {"Name", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Id"}, {{"AllRows", each _, type table [Id=number, Name=text]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Names", each Table.Column([AllRows], "Name")),
    #"Extracted Values" = Table.TransformColumns(#"Added Custom", {"Names", each Text.Combine(List.Transform(_, Text.From), ","), type text}),
    #"Removed Other Columns" = Table.SelectColumns(#"Extracted Values",{"Id", "Names"})
in
    #"Removed Other Columns"

 

workbook is here.

 



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

View solution in original post

3 REPLIES 3
Jimmy801
Community Champion
Community Champion

Hello @bbbt123 

 

didn't see that @edhans  did already answer. As i've put down already a solution, i will post it. It uses a little leaner way.

let
	Source = #table
	(
		{"ID","Name"},
		{
			{"1","aaa"},	{"1","bbb"},	{"1","ccc"},	{"1","ddd"},	{"1","eee"}
		}
	),
    Group = Table.Group(Source, {"ID"}, {{"Combine", each Text.Combine(_[Name], ", "), type text}})
in
	Group

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works. If this solution fits your need, copy and past a part of it and implement it in your query.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

edhans
Super User
Super User

  1. Group your data by the first column, and for the aggregation use the ALL ROWS aggregation and call it "AllRows"
  2. Add a custom column, call it Names, and use Table.Column([AllRows], "Name") as the formula.
  3. Expand the new Names column but as Values (not rows) and select the comma as your delimiter.
  4. Select the ID and Names column and remove other columns.

 

2020-01-14 08_43_14-Table1 - Power Query Editor.png

 

Full M query (my data came from an Excel table which explains the source)

 

 

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Id", Int64.Type}, {"Name", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Id"}, {{"AllRows", each _, type table [Id=number, Name=text]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Names", each Table.Column([AllRows], "Name")),
    #"Extracted Values" = Table.TransformColumns(#"Added Custom", {"Names", each Text.Combine(List.Transform(_, Text.From), ","), type text}),
    #"Removed Other Columns" = Table.SelectColumns(#"Extracted Values",{"Id", "Names"})
in
    #"Removed Other Columns"

 

workbook is here.

 



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

Thank you 😄 

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors
Top Kudoed Authors