How to consolidate records based on a key, and create semicolon delimited list from ID fields

tynachua

New Member
Joined
Jan 18, 2018
Messages
1
<style type="text/css"><!--td {border: 1px solid #ccc;}br {mso-data-placement:same-cell;}--></style>Hi,

Would love some help, will buy first automation that works lunch! :)

I am trying to go from List A like this:
<style type="text/css"><!--td {border: 1px solid #ccc;}br {mso-data-placement:same-cell;}--></style>
NameIDTypeKey
Test person 1980234980393A1LeaderAMERRegion1SR1ALL
Test person 2980234980393A2LeaderAMERRegion1SR1ALL
Test person 3980234980393A3LeaderAMERRegion1SR1ALL
Test person 4980234980393A4LeaderLACARegion4SR4
Test person 5980234980393A5LeaderLACARegion4SR4
Test person 6980234980393A6LeaderLACARegion4SR4
Test person 7980234980393A7LeaderLACARegion4SR4

<colgroup><col style="width: 157px"><col width="148"><col width="100"><col width="144"></colgroup><tbody>
</tbody>

to List B like this:

<style type="text/css"><!--td {border: 1px solid #ccc;}br {mso-data-placement:same-cell;}--></style>
KeyIDsNames
AMERRegion1SR1ALL980234980393A1;980234980393A2;980234980393A3Test person 1;Test person 2;Test person 3
LACARegion4SR4980234980393A4;980234980393A5;980234980393A6;980234980393A7Test person 4;Test person 5;Test person 6;Test person 7

<colgroup><col style="width: 157px"><col width="148"><col width="100"></colgroup><tbody>
</tbody>

While I can concat ID's manually, I want functionality where when I add a new row in List A, the IDs and names from this new row will be appended to the existing semi-colon delimited list, where the key matches. I'm also on a Mac which puts some additional limits to what I can do i.e. no VBA functionality it seems.

Thank you!


<colgroup><col style="width: 157px"><col width="148"><col width="100"><col width="100"><col width="100"><col width="100"><col width="100"><col width="100"><col width="144"></colgroup><tbody></tbody>
 

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"
Assuming columnA to columnD of Sheet1 has data which will be added data manualy.

Sheet Module of Sheet1.
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
Dim ws2 As Worksheet
Dim FC As Range
Set ws2 = Sheets("Sheet2")
With ws2
    If Intersect(Target, Range("A:D")) Is Nothing Then Exit Sub
    If WorksheetFunction.CountA(Range(cells(Target.row, 1), cells(Target.row, 4))) <> 4 Then Exit Sub
    
    Set FC = .Range("A:A").Find(What:=cells(Target.row, 4))
    If FC Is Nothing Then
        LR = .cells(Rows.count, 1).End(xlUp).row + 1
        .cells(LR, 1).Value = cells(Target.row, 4).Value
        .cells(LR, 2).Value = cells(Target.row, 2).Value
        .cells(LR, 3).Value = cells(Target.row, 1).Value
    Else
        .cells(FC.row, 2).Value = .cells(FC.row, 2).Value & ";" & cells(Target.row, 2).Value
        .cells(FC.row, 3).Value = .cells(FC.row, 3).Value & ";" & cells(Target.row, 1).Value
    End If
End With
End Sub

If ColumnA to ColumnD of shet1 of each data has blank, it does not work.
Hope this helps.
 
Upvote 0
Can you use this? Assume simple example has ID in A1, A1:A8 has ID numbers. Assume Key is in B1. and B1:B8 has key letters. Assume Criteria cell DI has A. Place formula in E1. In addition to a concatenation and transposing, I add a substitute part to remove "FALSE". When you create your full formula, you need to highlight the transpose(part of total formula all the way to the 2nd ) after " ; " with your mouse. Hit F9. Remove both { and }. Hit enter
The formula is =substitute(concatenate(transpose(if(b2:b8=d1,a2:a8)&" ; "))),"FALSE","")

IDKeyA1 ; 2 ; 3 ; 4 ;
1A
2A
3A
4A
6B
7B
8b

<colgroup><col span="3"><col><col></colgroup><tbody>
</tbody>
 
Upvote 0

Forum statistics

Threads
1,214,377
Messages
6,119,185
Members
448,872
Latest member
lcaw

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