Concatenate Multiple Rows with same Unique Identifier

kparadise

Board Regular
Joined
Aug 13, 2015
Messages
186
Hello,

Have a question for excel. I have a sheet with a large list of records. Each record has an ID, but is not unique due to multiple attributes which need to be accounted for, for each ID. Because these records are split, what I am trying to do is build another column at the end of my spreadsheet which will combine all the data from each unique ID into one cell. I will try to show below. Please notice, the combination of A2:B3 are duplicates, I wanted to include this in the example because I want to make sure if there are duplicates, I want to remove those from the results. I would put carriage returns in the results area.

A
B
C
1
ID
Type
Results
2
A-123
Cat-big
Cat-big
Cat-small
Dog-big
Dog-small
Dog-tiny
3
A-123
Cat-big
Cat-big
Cat-small
Dog-big
Dog-small
Dog-tiny

4
A-123
Cat-small
Cat-big
Cat-small
Dog-big
Dog-small
Dog-tiny

5
A-123
Dog-big
Cat-big
Cat-small
Dog-big
Dog-small
Dog-tiny

6
B-123
Dog-small
Dog-small
Dog-tiny

7
B-123
Dog-tiny
Dog-small
Dog-tiny

8
A-987
Cat-tiny
Cat-tiny
9
A-777
Cat-large
Cat-large
10
A-555
Bull-large
Bull-large
Bull-skinny
11
A-555
Bull-skinny
Bull-large
Bull-skinny


<tbody>
</tbody>
 

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
Do you want to get rid of the duplicate IDs once you have concatenated the values in col B?
 
Upvote 0
If you do want to delete the duplicates, how about
Code:
Sub kparadise()
   Dim Cl As Range, Rng As Range
   Dim Dic As Object
   
   Set Dic = CreateObject("scripting.dictionary")
   For Each Cl In Range("A2", Range("A" & Rows.Count).End(xlUp))
      If Not Dic.Exists(Cl.Value) Then
         Dic.Add Cl.Value, Array(Cl.Offset(, 1), CreateObject("scripting.dictionary"))
         Dic(Cl.Value)(1)(Cl.Offset(, 1).Value) = Empty
      ElseIf Not Dic(Cl.Value)(1).Exists(Cl.Offset(, 1).Value) Then
         Dic(Cl.Value)(0).Value = Dic(Cl.Value)(0).Value & vbLf & Cl.Offset(, 1).Value
         Dic(Cl.Value)(1)(Cl.Offset(, 1).Value) = Empty
         If Rng Is Nothing Then Set Rng = Cl Else Set Rng = Union(Rng, Cl)
      Else
         If Rng Is Nothing Then Set Rng = Cl Else Set Rng = Union(Rng, Cl)
      End If
   Next Cl
   If Not Rng Is Nothing Then Rng.EntireRow.Delete
End Sub
 
Upvote 0
or with PowerQuery

IDType
A-123Cat-big
A-123Cat-big
A-123Cat-small
A-123Dog-big
B-123Dog-small
B-123Dog-tiny
A-987Cat-tiny
A-777Cat-large
A-555Bull-large
A-555Bull-skinny
IDResult
A-123Cat-big
Cat-small
Dog-big
B-123Dog-small
Dog-tiny
A-987Cat-tiny
A-777Cat-large
A-555Bull-large
Bull-skinny

Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Grp = Table.Group(Source, {"ID"}, {{"Count", each _, type table}}),
    Lst = Table.AddColumn(Grp, "Result", each List.Distinct(Table.Column([Count],"Type"))),
    Ext = Table.TransformColumns(Lst, {"Result", each Text.Combine(List.Transform(_, Text.From), "#(lf)"), type text})
in
    Ext[/SIZE]
 
Upvote 0
for Excel 2010/2013 this is free add-in
for Excel 2016 and above this is Get&Transform (PowerQuery) which is built-in
 
Upvote 0
A
B
C
1
IDTypeResults
2
A-123Cat-bigCat-big
Cat-small
Dog-big
Dog-small
Dog-tiny
3
A-123Cat-bigCat-big
Cat-small
Dog-big
Dog-small
Dog-tiny
4
A-123Cat-smallCat-big
Cat-small
Dog-big
Dog-small
Dog-tiny
5
A-123Dog-bigCat-big
Cat-small
Dog-big
Dog-small
Dog-tiny
6
B-123Dog-smallDog-small
Dog-tiny
7
B-123Dog-tinyDog-small
Dog-tiny
8
A-987Cat-tinyCat-tiny
9
A-777Cat-largeCat-large
10A-555Bull-largeBull-large
Bull-skinny
11
A-555Bull-skinnyBull-large
Bull-skinny

<tbody>
</tbody>
Is your example result correct for the first four rows? I ask because you picked up the two Types for B-123 and concatenated them along with those from A-123. Originally I guessed that only the 123 mattered from the ID, but you did not do the same thing for the B-123 entries, so I am confused as to what IDs are used... unless, of course, you accidentally included the B-123 Types when you did not mean to.
 
Upvote 0
Is your example result correct for the first four rows? I ask because you picked up the two Types for B-123 and concatenated them along with those from A-123. Originally I guessed that only the 123 mattered from the ID, but you did not do the same thing for the B-123 entries, so I am confused as to what IDs are used... unless, of course, you accidentally included the B-123 Types when you did not mean to.

You are correct, I apologize. I did not mean to include those. Dog-small and Dog-tiny are not supposed to be in there.

I DO NOT HAVE ACCESS TO POWERQUERY, FYI.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,213,482
Messages
6,113,915
Members
448,532
Latest member
9Kimo3

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top