VBA - Concatenate Match Offset Loop

MixedUpExcel

Board Regular
Joined
Apr 7, 2015
Messages
222
Office Version
  1. 365
Platform
  1. Windows
Hi,

Detail of data:

Column A has a list of product codes (of which there can be duplicates upto 5000 duplicates but in some cases, there may only be 1)
Column B has a list of associated product codes (there may also be duplicates as more than one of the products in Column A can be associated with the products in Column B) - I don't think the duplicate issue will come in to this though

I have a unique list of product codes from Column A and these are placed under a header in Column J

I have a number from 1 to 5000 as headers in Cell K1 going to the right ->>>

I want a VBA code which will take the product code from Cell J2 - find the corresponding code in Column A and return the product code next to it in Column B and put that code in Cell K2

As there will be duplicates, I want the code to then move to Cell L2 and look for the next instance in Column A where it finds the product code from Cell J2 (the second instance) and puts the result in Cell L2 and so on until it can't find any more products (Cell J2) in Column A

Then, it moves to Row 3, Column J and does the process again until it can't find any more of the Product Code (Cell J3) in Column A.

I will have potentially 40,000 Unique Codes in Column J

I have a formula which can do this but takes FAR TOO LONG to process.

This is my formula:

Code:
{=INDEX(Sheet1!$B$2:$B$20000, SMALL(IF($J2=Sheet1!$A$2:$A$20000, ROW(Sheet1!$B$2:$B$20000)-MIN(ROW(Sheet1!$B$2:$B$20000))+1, ""), COLUMN(A1)))}

This is an example table as described above:

ABCDEFGHIJKLMNO
1ProductAssociated Unique Product12345
2AB123XY1 AB123XY1XY4XY1XY4#NUM!
3AB124XY2 AB124XY2XY5XY2XY5#NUM!
4AB125XY3 AB125XY3XY6XY3XY6#NUM!
5AB126XY4 AB126XY4XY5XY1XY2XY4
6AB126XY5 AB127XY6XY3XY6#NUM!
7AB127XY6 AB128XY1XY4XY1#NUM!
8AB128XY1 AB129XY2XY5XY2#NUM!
9AB129XY2 AB130XY3XY6XY3#NUM!
10AB130XY3
11AB123XY4
12AB124XY5
13AB125XY6
14AB126XY1
15AB126XY2
16AB127XY3
17AB128XY4
18AB129XY5
19AB130XY6
20AB123XY1
21AB124XY2
22AB125XY3
23AB126XY4
24AB126XY5
25AB127XY6
26AB128XY1
27AB129XY2
28AB130XY3
29AB123XY4
30AB124XY5
31AB125XY6
32AB126XY1

<colgroup><col span="2"><col><col span="7"><col><col span="5"></colgroup><tbody>
</tbody>


My thoughts were to possibly concatenate the unique codes in Column J with the header number (have an inserted Column at the start - a new Column A possibly) and using Countif eg. =Countif($A$2:A2,A2) in the new Column A - give me the number in the Count which I can concatenate in a new column and do a look up that way - or match / offset etc.

Is there any way to do the above or is there a better solution?

Thanks in advance.

Simon
 
Last edited:
Hi,

The highest value is 18125 which coincidentally is the product code it stopped on last time. The next one is 2100 after 18125

I'm guessing that's because there aren't enough Columns to run this.

As it's one product code, is there a way to ignore any that fail (in this case it's only 1 but I may have other data to run this against which may come up against a similar problem)

Or do you have any suggestions to get round this?

Thanks again.
 
Upvote 0

Excel Facts

Copy PDF to Excel
Select data in PDF. Paste to Microsoft Word. Copy from Word and paste to Excel.
How about
Code:
Sub MixedUpExcel()
   Dim Ary As Variant, Ky As Variant
   Dim Dic As Object
   Dim i As Long
   
   Ary = Range("A1").CurrentRegion.Value2
   
   Set Dic = CreateObject("scripting.dictionary")
   For i = 2 To UBound(Ary)
      If Not Dic.Exists(Ary(i, 1)) Then Dic.Add Ary(i, 1), CreateObject("scripting.dictionary")
      Dic(Ary(i, 1))(Ary(i, 2)) = Empty
   Next i
   i = 0
   With Range("J" & Rows.Count).End(xlUp).Offset(1)
      For Each Ky In Dic.Keys
         .Offset(i).Value = Ky
         If Dic(Ky).Count > 16370 Then
            .Offset(i, 1) = "Too many Products"
         Else
            .Offset(i, 1).Resize(, Dic(Ky).Count).Value = Dic(Ky).Keys
         End If
         i = i + 1
      Next Ky
   End With
End Sub
 
Upvote 0
Hi Fluff.

That worked brilliantly.

Nice touch putting 'Too many Products', so I don't miss any from the unique list.

Again,

I really appreciate the time you've put in today to help me out with this so quickly.

I'm now going to try and learn as much as I can about your code as I can see so many other places I can benefit from this.

Thank you again.

Simon
 
Upvote 0
You're welcome & thanks for the feedback.
Another thought if you add the line in red
Code:
         If Dic(Ky).Count > 16370 Then
            .Offset(i, 1) = "Too many Products"
           [COLOR=#ff0000] .Offset(i).Interior.Color = vbRed[/COLOR]
         Else
It will highlight the product that is a problem, making it a bit more obvious.
 
Upvote 0
You're welcome & thanks for the feedback.
Another thought if you add the line in red
Code:
         If Dic(Ky).Count > 16370 Then
            .Offset(i, 1) = "Too many Products"
           [COLOR=#ff0000] .Offset(i).Interior.Color = vbRed[/COLOR]
         Else
It will highlight the product that is a problem, making it a bit more obvious.

Thanks for the extra tip.. it's given me some more ideas as well.

Thanks.
 
Upvote 0

Forum statistics

Threads
1,214,529
Messages
6,120,070
Members
448,943
Latest member
sharmarick

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