Consolidating columns of text based

Roonie847

New Member
Joined
Sep 6, 2019
Messages
4
I have a data set that looks like this:

Col1Col2
asam
bsam
csam
dsam
esam
fsam
gsam
abill
bbill
dbill
gbill
hbill
ddave
edave
fdave

<colgroup><col width="64" style="width:48pt" span="2"> </colgroup><tbody>
</tbody>

and I need to convert it to look like this:
NewCol1 NewCol2
a sam|bill
b sam|bill
c sam
d sam|bill|dave
e sam|dave
f sam|dave
h bill

<colgroup><col width="64" style="width:48pt" span="2"> </colgroup><tbody>
</tbody>

Basically, I need to consolidate all of the values from Col2 into a single data element where the values in col1 are repeated. Been looking at a creative Vlookup combined with a concat but cannot figure it out. My dataset is about 6000 rows.
 

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
What version of Xl are you using?
 
Upvote 0
with Power Query aka Get&Transform

Column1Column2Column1Custom
asamasam|bill
bsambsam|bill
csamcsam
dsamdsam|bill|dave
esamesam|dave
fsamfsam|dave
gsamgsam|bill
abillhbill
bbill
dbill
gbill
hbill
ddave
edave
fdave

Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Group = Table.Group(Source, {"Column1"}, {{"Count", each _, type table}}),
    List = Table.AddColumn(Group, "Custom", each Table.Column([Count],"Column2")),
    Extract = Table.TransformColumns(List, {"Custom", each Text.Combine(List.Transform(_, Text.From), "|"), type text})
in
    Extract[/SIZE]
 
Upvote 0
Ok... I am sorry, I am sure that solves the problem but that is substantially beyond my capabilities... I do not have any idea how to execute that nor where to put it so I could execute it.
 
Upvote 0
Or with a macro
Code:
Sub Roonie847()
   Dim Cl As Range
   
   With CreateObject("scripting.dictionary")
      .CompareMode = 1
      For Each Cl In Range("A2", Range("A" & Rows.Count).End(xlUp))
         If Not .exists(Cl.Value) Then
            .Add Cl.Value, Cl.Offset(, 1).Value
         Else
            .Item(Cl.Value) = .Item(Cl.Value) & "|" & Cl.Offset(, 1).Value
         End If
      Next Cl
      Range("D2").Resize(.Count, 2).Value = Application.Transpose(Array(.keys, .items))
   End With
End Sub
 
Upvote 0
Thanks for all of the help folks... I clearly need to take some Excel classes. It looks like that what I need to do is going to require something well beyond my abilities. Was thinking this was a simple thing that would not require coding or macros.
 
Upvote 0
If you had TEXTJOIN it could be done with formulae, but as you dont PQ or VBA is probably the easiest option.
 
Upvote 0

Forum statistics

Threads
1,213,486
Messages
6,113,932
Members
448,533
Latest member
thietbibeboiwasaco

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