Power Query to Concatenate Rows Based on Condition

legalhustler

Well-known Member
Joined
Jun 5, 2014
Messages
1,062
Hi,

I have column with Names, (unique) ID, and Address. The problem is some addresses have their street address in one row and the row below it is their city, state and zip. I would like to have their street address, city, state, and zip in concatenated in on line based on their ID. For example:


Name...….....ID...……...Address

Joe Smith....123...……..25 Apple Dr.

Joe Smith.....123...…...New York City, NY, 00972

Sue Brown....445...…...90 Bayview St. Miami, FL 32423

Tim Rice...….565...…..55 Pachino St.

Tim Rice...…..565...….Rockville, MD 64310



ExpectedResult:

Joe Smith...….123......25 Apple Dr. New York City, NY, 00972
Sue Brown....445...…...90 Bayview St. Miami, FL 32423
Tim Rice...….565...…..55 Pachino St. Rockville, MD 64310


How can I transform my data to show like this?
 
Last edited:

sandy666

Well-known Member
Joined
Oct 24, 2015
Messages
3,219
Use Group with All Rows then List.Distinct and Extract with Space delimiter

NameIDAddressNameIDAddress
Joe Smith
123​
25 Apple DrJoe Smith12325 Apple Dr New York City, NY, 00972
Joe Smith
123​
New York City, NY, 00972Sue Brown44590 Bayview St. Miami, FL 32423
Sue Brown
445​
90 Bayview St. Miami, FL 32423Tim Rice56555 Pachino St Rockville, MD 64310
Tim Rice
565​
55 Pachino St
Tim Rice
565​
Rockville, MD 64310
 
Last edited:

legalhustler

Well-known Member
Joined
Jun 5, 2014
Messages
1,062
So I did Group By on the ID field > All Rows, but I don't know how to apply the List.Distinct? Should I expand the new column once I did Group By? Where do I use List.Distinct? In a Custom Column?
 

peter789

Board Regular
Joined
Nov 20, 2016
Messages
109
AS an alternative approach use Text.Combine:
Code:
let
    Source = Excel.CurrentWorkbook(){[Name="InputTable"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"ID", Int64.Type}, {"Address", type text}}),
    Result=Table.Group(#"Changed Type", {"Name", "ID"}, {{"Count", each Text.Combine([Address],", "), type text}})
in
    Result
Peter
 
Last edited:

sandy666

Well-known Member
Joined
Oct 24, 2015
Messages
3,219
After Group you should see Table column, then use
for ID: ID = Table.AddColumn(Group, "ID", each List.Distinct(Table.Column([Count],"ID"))),
and : ExtractID = Table.TransformColumns(ID, {"ID", each Text.Combine(List.Transform(_, Text.From)), type text}),

the same for Address
 

peter789

Board Regular
Joined
Nov 20, 2016
Messages
109
Sorry Sandy666
for crossing my post with yours. I hope I haven't confused the issue.

Peter
 

sandy666

Well-known Member
Joined
Oct 24, 2015
Messages
3,219
no prob...
 

legalhustler

Well-known Member
Joined
Jun 5, 2014
Messages
1,062
AS an alternative approach use Text.Combine:
Code:
let
    Source = Excel.CurrentWorkbook(){[Name="InputTable"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"ID", Int64.Type}, {"Address", type text}}),
    Result=Table.Group(#"Changed Type", {"Name", "ID"}, {{"Count", each Text.Combine([Address],", "), type text}})
in
    Result
Peter
Thank you both. I used your method as it was easy for me to understand and change the M code. Small issue, some address lines show like this in a cell:

123 Moonlight St.
Columbus, OH 57423

How can I move/display it in one line for the cell/field? Do I need to substitute hard space/line feed with regular space?
 
Last edited:

peter789

Board Regular
Joined
Nov 20, 2016
Messages
109
Not sure what NVM means but I'm glad it worked and also you understood what the code was doing and helps you on your Power Query learning adventure!

Peter
 

Forum statistics

Threads
1,077,795
Messages
5,336,377
Members
399,078
Latest member
johnk94

Some videos you may like

This Week's Hot Topics

Top