Do *something* for each match contained in two arrays

Luke777

Board Regular
Joined
Aug 10, 2020
Messages
243
Office Version
  1. 365
Platform
  1. Windows
Hi all,

I have two Arrays, each set As String. The first, Array1, contains a list of names as specified in the VBA code itself.

VBA Code:
Array1 = Array ("Dave", "Ethel", "Danger Mouse", "King Erebus III, Destroyer of Realms")

The second, Array2, is a variable length list of names imported from an .accdb file and dumped onto the 'NameDump' worksheet. This is the method I have used to set the array (which works as far as I can tell).

VBA Code:
Dim LastNameEntry As Long
LastNameEntry = Worksheets("NameDump"),Range("A1").CurrentRegion.Rows.Count

Dim Array2  As String
Array2 = Array("A2:A" & LastNameEntry")

What I would like to do is compare the names of Array1 with those found in Array2. Each time there is a match, I would like to set a variable (lets call it Var1) as the cell next-door to the match in Column B, which contains a string related to each name. I will then perform some other shenanigans on Var1 (I've got that bit of code sorted), before continuing to search for matches.

I've have looked into this a fair bit for the last few hours, just so you beautiful folks at mrexcel know I have at least tried (I know effort is appreciated before questions are asked), and I believe the solution will combine For Each, 'i', Match and Offset - but I'm afraid the combination, and solution to my task, is a bit beyond my current understanding of VBA unfrotunately.

Thank you all in advance for any help :)
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
How about
VBA Code:
Sub Luke()
   Dim Ary As Variant
   Dim Dic As Object
   Dim r As Long
   
   Set Dic = CreateObject("Scripting.dictionary")
   Ary = Array("Dave", "Ethel", "Danger Mouse", "King Erebus III, Destroyer of Realms")
   For r = 1 To UBound(Ary)
      Dic(Ary(r)) = Empty
   Next r
   With Sheets("NameDump")
      Ary = .Range("A2:B" & .Range("A" & Rows.Count).End(xlUp).Row).Value2
   End With
   For r = 1 To UBound(Ary)
      If Dic.Exists(Ary(r, 1)) Then
         var1 = Ary(r, 2)
         'do something
      End If
   Next r
End Sub
 
Upvote 0
Solution
How about
VBA Code:
Sub Luke()
   Dim Ary As Variant
   Dim Dic As Object
   Dim r As Long
  
   Set Dic = CreateObject("Scripting.dictionary")
   Ary = Array("Dave", "Ethel", "Danger Mouse", "King Erebus III, Destroyer of Realms")
   For r = 1 To UBound(Ary)
      Dic(Ary(r)) = Empty
   Next r
   With Sheets("NameDump")
      Ary = .Range("A2:B" & .Range("A" & Rows.Count).End(xlUp).Row).Value2
   End With
   For r = 1 To UBound(Ary)
      If Dic.Exists(Ary(r, 1)) Then
         var1 = Ary(r, 2)
         'do something
      End If
   Next r
End Sub

Thank you! I shall give this a go :)

From reading through, it looks like the Array is created very differently from what I had imagined. If I'm looking at is correctly Ary is used to create a custom dictionary thing which then allows Ary to be emptied and then used again later for the range on the sheet?

Also, I notice Ary is set to Variant whereas I was using String - is this a case of personal preference, due to the scripting dictionary or just more proficient coding generally speaking?

Sorry for all the questions, I'm just trying to learn as much as I possibly can so I can eventually help others :)
 
Upvote 0
If I'm looking at is correctly Ary is used to create a custom dictionary thing which then allows Ary to be emptied and then used again later for the range on the sheet?
That's right. :)
Also, I notice Ary is set to Variant whereas I was using String - is this a case of personal preference
Nope, your code doesn't work. If you are loading an array from the sheet it needs to be defined as a Variant.
 
Upvote 0
That's right. :)

Nope, your code doesn't work. If you are loading an array from the sheet it needs to be defined as a Variant.
Ahh I see! :) Thank you! :)

One last question, for future reference - if the information on the sheet is in different columns - lets say the names are dumped to H and the other bit is still dumped into B, am I correct in thinking that I'd simply set the range as B2:H and change

VBA Code:
If Dic.Exists(Ary(r, 1)) Then
         var1 = Ary(r, 2)

to an 8 and a 2 respectively? - or if 1 is representative of the position within the 'box' of the array, to a 7 and a 1? :) Hope that makes sense...
 
Upvote 0
It would need to be 7 & 1 as column B is the 1st column in the array.
 
Upvote 0
It would need to be 7 & 1 as column B is the 1st column in the array.
Thanks for the help!


VBA Code:
   Ary = Array("Dave", "Ethel", "Danger Mouse", "King Erebus III, Destroyer of Realms")
   For r = 1 To UBound(Ary)

Should r = 0 for this? I was watching the Locals window whilst using F8 and it was always missing the first entry of that particular array - not sure about the other r = though
 
Upvote 0
Oops, your right that should be 0, but the other one needs to be 1.
Alternatively you could use
VBA Code:
For r = LBound(Ary) To UBound(Ary)
for both of them
 
Upvote 0
Oops, your right that should be 0, but the other one needs to be 1.
Alternatively you could use
VBA Code:
For r = LBound(Ary) To UBound(Ary)
for both of them

One last question if you'd be so kind :)

I'm using the exact same method/code as you suggested on another project, but this time I'm deleting the row where there's a match - however this causes problem because deleting an entire row sort of causes it to skip part of array as everything shifts up a row. I've tried adding
VBA Code:
r=r-1
after deletion, but that didn't work unfortunately
 
Upvote 0
Try it like
VBA Code:
Sub Luke()
   Dim Ary As Variant
   Dim Dic As Object
   Dim r As Long
   Dim Rng As Range
   
   Set Dic = CreateObject("Scripting.dictionary")
   Ary = Array("Dave", "Ethel", "Danger Mouse", "King Erebus III, Destroyer of Realms")
   For r = LBound(Ary) To UBound(Ary)
      Dic(Ary(r)) = Empty
   Next r
   With Sheets("NameDump")
      Ary = .Range("A2:B" & .Range("A" & Rows.Count).End(xlUp).Row).Value2
   End With
   For r = LBound(Ary) To UBound(Ary)
      If Dic.Exists(Ary(r, 1)) Then
         var1 = Ary(r, 2)
         If Rng Is Nothing Then Set Rng = Cells(r + 1, 1) Else Set Rng = Union(Rng, Cells(r + 1, 1))
      End If
   Next r
   If Not Rng Is Nothing Then Rng.EntireRow.Delete
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,551
Messages
6,114,268
Members
448,558
Latest member
aivin

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