Vlookup values in an array and store them in another array

cruzrji1

New Member
Joined
Apr 22, 2016
Messages
4
I´ve been struggling witht this for a while, please help...

I want to store range("G7:G200") as arr1, then store range ("A7:C500") as arr2, also have a third array called arr3, then I need to vlookup all the values for arr1 in arr2 and store the results in arr3, then write arr3 in range("H1:H200"). I need to do this in VBA and store the results as variables in another array, because I will perform more calculations based on the result of the vlookup, also this is as a test, actual values to vlookup and return results are about 4,000

so far...

sub looking()
dim arr1() as variant
dim arr2() as variant
dim arr3() as variant

arr1= range("G7:G200").value
arr2= range("A7:C500").value

for i=1 to 200

arr3(i,1)=worksheetfunction.vlookup(arr1(i,1),arr2,2,false)
next i

range("H1:H200").value=arr3

end sub


What is wrong with this?!
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
You'll need to allocate storage space for arr3 using the ReDim statement. There's no need to do the same with arr1 and arr2 since storage space is automatically allocated to them when assigning an array. Also, I would suggest you use the VLookup method of the Application object, instead of the WorksheetFunction object. In doing so, you'll get a non-breaking error when there's no match. So you might want to try something like this...

Code:
[COLOR=darkblue]Option[/COLOR] [COLOR=darkblue]Explicit[/COLOR]

[COLOR=darkblue]Sub[/COLOR] looking()

    [COLOR=darkblue]Dim[/COLOR] arr1() [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Variant[/COLOR]
    [COLOR=darkblue]Dim[/COLOR] arr2() [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Variant[/COLOR]
    [COLOR=darkblue]Dim[/COLOR] arr3() [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Variant[/COLOR]
    [COLOR=darkblue]Dim[/COLOR] i [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR]
    
    arr1 = Range("G7:G" & Cells(Rows.Count, "G").End(xlUp).Row).Value
    arr2 = Range("A7:C500").Value
    
    [COLOR=darkblue]ReDim[/COLOR] arr3(1 [COLOR=darkblue]To[/COLOR] [COLOR=darkblue]UBound[/COLOR](arr1, 1), 1 [COLOR=darkblue]To[/COLOR] 1)
    
    [COLOR=darkblue]For[/COLOR] i = 1 [COLOR=darkblue]To[/COLOR] [COLOR=darkblue]UBound[/COLOR](arr3, 1)
        arr3(i, 1) = Application.VLookup(arr1(i, 1), arr2, 2, [COLOR=darkblue]False[/COLOR])
    [COLOR=darkblue]Next[/COLOR] i
    
    Range("H1").Resize(UBound(arr3, 1)).Value = arr3

[COLOR=darkblue]End[/COLOR] [COLOR=darkblue]Sub[/COLOR]

Hope this helps!
 
Last edited:
Upvote 0
You'll need to allocate storage space for arr3 using the ReDim statement. There's no need to do the same with arr1 and arr2 since storage space is automatically allocated to them when assigning an array. Also, I would suggest you use the VLookup method of the Application object, instead of the WorksheetFunction object. In doing so, you'll get a non-breaking error when there's no match. So you might want to try something like this...

Code:
[COLOR=darkblue]Option[/COLOR] [COLOR=darkblue]Explicit[/COLOR]

[COLOR=darkblue]Sub[/COLOR] looking()

    [COLOR=darkblue]Dim[/COLOR] arr1() [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Variant[/COLOR]
    [COLOR=darkblue]Dim[/COLOR] arr2() [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Variant[/COLOR]
    [COLOR=darkblue]Dim[/COLOR] arr3() [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Variant[/COLOR]
    [COLOR=darkblue]Dim[/COLOR] i [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR]
    
    arr1 = Range("G7:G" & Cells(Rows.Count, "G").End(xlUp).Row).Value
    arr2 = Range("A7:C500").Value
    
    [COLOR=darkblue]ReDim[/COLOR] arr3(1 [COLOR=darkblue]To[/COLOR] [COLOR=darkblue]UBound[/COLOR](arr1, 1), 1 [COLOR=darkblue]To[/COLOR] 1)
    
    [COLOR=darkblue]For[/COLOR] i = 1 [COLOR=darkblue]To[/COLOR] [COLOR=darkblue]UBound[/COLOR](arr3, 1)
        arr3(i, 1) = Application.VLookup(arr1(i, 1), arr2, 2, [COLOR=darkblue]False[/COLOR])
    [COLOR=darkblue]Next[/COLOR] i
    
    Range("H1").Resize(UBound(arr3, 1)).Value = arr3

[COLOR=darkblue]End[/COLOR] [COLOR=darkblue]Sub[/COLOR]

Hope this helps!


Heey thanks! this was very helpful, especially for the redim part. I was also having troubles because of the base 0 array, but I figured about that for myself =D
 
Upvote 0

Forum statistics

Threads
1,215,472
Messages
6,125,004
Members
449,203
Latest member
Daymo66

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