Combining data from multiple rows into one row

jodeyes

New Member
Joined
Nov 21, 2016
Messages
23
I am trying to combine data for users who have multiple rows into one single row. All other data is the same except for one column, so I want that one column to reflect all of the data in the first column for that user, separated by commas.

Current Sample
[TABLE="width: 868"]
<tbody>[TR]
[TD]Login_ID
[/TD]
[TD]Sys1_ID
[/TD]
[TD="align: center"]Emp_No
[/TD]
[TD]Market
[/TD]
[TD]Name_of_User
[/TD]
[TD]Store_ID
[/TD]
[TD]ProfileName
[/TD]
[TD]Job Title
[/TD]
[TD]Coordinator
[/TD]
[/TR]
[TR]
[TD]A123456
[/TD]
[TD="align: right"]12635004
[/TD]
[TD="align: center"]12635004
[/TD]
[TD]050
[/TD]
[TD]Barbara Jones
[/TD]
[TD]5001
[/TD]
[TD]ASSOC2
[/TD]
[TD]Retail Sales Associate
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]B123456
[/TD]
[TD="align: right"]12632959
[/TD]
[TD="align: center"]12632959
[/TD]
[TD]050
[/TD]
[TD]Elissa Donnabella
[/TD]
[TD]5004
[/TD]
[TD]ASSOC2
[/TD]
[TD]Retail Sales Associate
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]C123456
[/TD]
[TD="align: right"]12597915
[/TD]
[TD="align: center"]12597915
[/TD]
[TD]050
[/TD]
[TD]Marcia Brady
[/TD]
[TD]5003
[/TD]
[TD]ASSTMNGR
[/TD]
[TD]Retail Sales Leader
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]D123456
[/TD]
[TD="align: right"]12612768
[/TD]
[TD="align: center"]12612768
[/TD]
[TD]050
[/TD]
[TD]Brad Pitt
[/TD]
[TD]5001
[/TD]
[TD]ASSOC2
[/TD]
[TD]Retail Sales Associate
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]E123456
[/TD]
[TD="align: right"]11345
[/TD]
[TD="align: center"]12533788
[/TD]
[TD]050
[/TD]
[TD]Jennifer Aniston
[/TD]
[TD]5007
[/TD]
[TD]ASSTMNGR
[/TD]
[TD]Retail Sales Leader
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]F123456
[/TD]
[TD="align: right"]4389
[/TD]
[TD="align: center"]12531662
[/TD]
[TD]050
[/TD]
[TD]Bob Jones
[/TD]
[TD]5000
[/TD]
[TD]REGMNGR
[/TD]
[TD]Sr Analyst, Business Analysis
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]F123456
[/TD]
[TD="align: right"]4389
[/TD]
[TD="align: center"]12531662
[/TD]
[TD]050
[/TD]
[TD]Bob Jones
[/TD]
[TD]5001
[/TD]
[TD]REGMNGR
[/TD]
[TD]Sr Analyst, Business Analysis
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]F123456
[/TD]
[TD="align: right"]4389
[/TD]
[TD="align: center"]12531662
[/TD]
[TD]050
[/TD]
[TD]Bob Jones
[/TD]
[TD]5002
[/TD]
[TD]REGMNGR
[/TD]
[TD]Sr Analyst, Business Analysis
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]F123456
[/TD]
[TD="align: right"]4389
[/TD]
[TD="align: center"]12531662
[/TD]
[TD]050
[/TD]
[TD]Bob Jones
[/TD]
[TD]5003
[/TD]
[TD]REGMNGR
[/TD]
[TD]Sr Analyst, Business Analysis
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]F123456
[/TD]
[TD="align: right"]4389
[/TD]
[TD="align: center"]12531662
[/TD]
[TD]050
[/TD]
[TD]Bob Jones
[/TD]
[TD]5004
[/TD]
[TD]REGMNGR
[/TD]
[TD]Sr Analyst, Business Analysis
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]F123456
[/TD]
[TD="align: right"]4389
[/TD]
[TD="align: center"]12531662
[/TD]
[TD]050
[/TD]
[TD]Bob Jones
[/TD]
[TD]5005
[/TD]
[TD]REGMNGR
[/TD]
[TD]Sr Analyst, Business Analysis
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]F123456
[/TD]
[TD="align: right"]4389
[/TD]
[TD="align: center"]12531662
[/TD]
[TD]050
[/TD]
[TD]Bob Jones
[/TD]
[TD]5006
[/TD]
[TD]REGMNGR
[/TD]
[TD]Sr Analyst, Business Analysis
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]F123456
[/TD]
[TD="align: right"]4389
[/TD]
[TD="align: center"]12531662
[/TD]
[TD]050
[/TD]
[TD]Bob Jones
[/TD]
[TD]5007
[/TD]
[TD]REGMNGR
[/TD]
[TD]Sr Analyst, Business Analysis
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]G123456
[/TD]
[TD="align: right"]12645049
[/TD]
[TD="align: center"]12645049
[/TD]
[TD]050
[/TD]
[TD]Avery Shriber
[/TD]
[TD]5002
[/TD]
[TD]ASSOC2
[/TD]
[TD]Retail Sales Associate
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]H123456
[/TD]
[TD="align: right"]12216
[/TD]
[TD="align: right"]12533491
[/TD]
[TD]050
[/TD]
[TD]Louise Penny
[/TD]
[TD]5002
[/TD]
[TD]INVASSOC
[/TD]
[TD]Inventory Sales Associate
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]I123456
[/TD]
[TD="align: right"]12633078
[/TD]
[TD="align: right"]12633078
[/TD]
[TD]050
[/TD]
[TD]Karen Smith
[/TD]
[TD]5004
[/TD]
[TD]ASSOC2
[/TD]
[TD]Retail Sales Associate
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]I123456
[/TD]
[TD="align: right"]12633078
[/TD]
[TD="align: right"]12633078
[/TD]
[TD]050
[/TD]
[TD]Karen Smith
[/TD]
[TD]6006
[/TD]
[TD]ASSOC2
[/TD]
[TD]Retail Sales Associate
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]J123456
[/TD]
[TD="align: right"]11738
[/TD]
[TD="align: right"]12533406
[/TD]
[TD]050
[/TD]
[TD]Jose Rodriguez
[/TD]
[TD]5006
[/TD]
[TD]ASSTMNGR
[/TD]
[TD]Retail Sales Leader
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]K123456
[/TD]
[TD="align: right"]12637433
[/TD]
[TD="align: right"]12637433
[/TD]
[TD]050
[/TD]
[TD]Eleanor Page
[/TD]
[TD]5002
[/TD]
[TD]ASSOC2
[/TD]
[TD]Retail Sales Associate
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
</tbody>[/TABLE]


What I'm trying to achieve
[TABLE="width: 995"]
<tbody>[TR]
[TD]Login_ID
[/TD]
[TD]Sys1_ID
[/TD]
[TD]Emp_No
[/TD]
[TD]Market
[/TD]
[TD]Name_of_User
[/TD]
[TD]Store_ID
[/TD]
[TD]ProfileName
[/TD]
[TD]Job Title
[/TD]
[TD]Coordinator
[/TD]
[/TR]
[TR]
[TD]A123456
[/TD]
[TD="align: center"]12635004
[/TD]
[TD]12635004
[/TD]
[TD]050
[/TD]
[TD]Barbara Jones
[/TD]
[TD]5001
[/TD]
[TD]ASSOC2
[/TD]
[TD]Retail Sales Associate
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]B123456
[/TD]
[TD="align: center"]12632959
[/TD]
[TD]12632959
[/TD]
[TD]050
[/TD]
[TD]Elissa Donnabella
[/TD]
[TD]5004
[/TD]
[TD]ASSOC2
[/TD]
[TD]Retail Sales Associate
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]C123456
[/TD]
[TD="align: center"]12597915
[/TD]
[TD]12597915
[/TD]
[TD]050
[/TD]
[TD]Marcia Brady
[/TD]
[TD]5003
[/TD]
[TD]ASSTMNGR
[/TD]
[TD]Retail Sales Leader
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]D123456
[/TD]
[TD="align: center"]12612768
[/TD]
[TD]12612768
[/TD]
[TD]050
[/TD]
[TD]Brad Pitt
[/TD]
[TD]5001
[/TD]
[TD]ASSOC2
[/TD]
[TD]Retail Sales Associate
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]E123456
[/TD]
[TD="align: center"]11345
[/TD]
[TD]12533788
[/TD]
[TD]050
[/TD]
[TD]Jennifer Aniston
[/TD]
[TD]5007
[/TD]
[TD]ASSTMNGR
[/TD]
[TD]Retail Sales Leader
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]F123456
[/TD]
[TD="align: center"]4389
[/TD]
[TD]12531662
[/TD]
[TD]050
[/TD]
[TD]Bob Jones
[/TD]
[TD]5000, 5001, 5002, 5003, 5004, 5005, 5006, 5007
[/TD]
[TD]REGMNGR
[/TD]
[TD]Sr Analyst, Business Analysis
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]G123456
[/TD]
[TD="align: center"]12645049
[/TD]
[TD]12645049
[/TD]
[TD]050
[/TD]
[TD]Avery Shriber
[/TD]
[TD]5002
[/TD]
[TD]ASSOC2
[/TD]
[TD]Retail Sales Associate
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]H123456
[/TD]
[TD="align: center"]12216
[/TD]
[TD]12533491
[/TD]
[TD]050
[/TD]
[TD]Louise Penny
[/TD]
[TD]5002
[/TD]
[TD]INVASSOC
[/TD]
[TD]Inventory Sales Associate
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]I123456
[/TD]
[TD="align: center"]12633078
[/TD]
[TD]12633078
[/TD]
[TD]050
[/TD]
[TD]Karen Smith
[/TD]
[TD]5004, 6006
[/TD]
[TD]ASSOC2
[/TD]
[TD]Retail Sales Associate
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]J123456
[/TD]
[TD="align: center"]11738
[/TD]
[TD]12533406
[/TD]
[TD]050
[/TD]
[TD]Jose Rodriguez
[/TD]
[TD]5006
[/TD]
[TD]ASSTMNGR
[/TD]
[TD]Retail Sales Leader
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
[TR]
[TD]K123456
[/TD]
[TD="align: center"]12637433
[/TD]
[TD]12637433
[/TD]
[TD]050
[/TD]
[TD]Eleanor Page
[/TD]
[TD]5002
[/TD]
[TD]ASSOC2
[/TD]
[TD]Retail Sales Associate
[/TD]
[TD]Mary Smith
[/TD]
[/TR]
</tbody>[/TABLE]

Thank you!
 

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
Hi & welcome to MrExcel.
How about
Code:
Sub Amalgamatedata()
   Dim Cl As Range
   Dim Rng As Range
   
   With CreateObject("scripting.dictionary")
      For Each Cl In Range("E2", Range("E" & Rows.Count).End(xlUp))
         If Not .exists(Cl.Value) Then
            .Add Cl.Value, Cl.Offset(, 1)
         Else
            .Item(Cl.Value).Value = .Item(Cl.Value) & ", " & Cl.Offset(, 1).Value
            If Rng Is Nothing Then Set Rng = Cl Else Set Rng = Union(Rng, Cl)
         End If
      Next Cl
   End With
   If Not Rng Is Nothing Then Rng.EntireRow.Delete
End Sub
 
Upvote 0
Glad to help & thanks for the feedback
 
Upvote 0
Hi & welcome to MrExcel.
How about
Code:
Sub Amalgamatedata()
   Dim Cl As Range
   Dim Rng As Range
   
   With CreateObject("scripting.dictionary")
      For Each Cl In Range("E2", Range("E" & Rows.Count).End(xlUp))
         If Not .exists(Cl.Value) Then
            .Add Cl.Value, Cl.Offset(, 1)
         Else
            .Item(Cl.Value).Value = .Item(Cl.Value) & ", " & Cl.Offset(, 1).Value
            If Rng Is Nothing Then Set Rng = Cl Else Set Rng = Union(Rng, Cl)
         End If
      Next Cl
   End With
   If Not Rng Is Nothing Then Rng.EntireRow.Delete
End Sub

Its Amazing Vba code i first time try thanks.

Thanks
Navi_G:cool:
 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,240
Members
452,621
Latest member
Laura_PinksBTHFT

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