VLOOKUP vs. INDEX/MATCH on variant array

jgscanlon

New Member
Joined
Jan 8, 2014
Messages
46
I have a multidimensional array with 'x' rows and 3 columns of data, and I'd like to perform a VLOOKUP on the array information stored in memory rather than calling the worksheet each time. I'm just not sure how to write the code to perform the VLOOKUP using INDEX/MATCH, and repeat that process for a variable number of items in a list.

The list of values is in column 1 in the array, and I'd like to return the corresponding value in column 3 from the array (table for data in the array is below).

I have a list of values from another sheet that I'll want to VLOOKUP or INDEX/MATCH against this array. If the value in my list doesn't exist in the array, then we just need a blank or NULL value.

Can anyone point me in the right direction?

Thank you!

[TABLE="class: grid, width: 500, align: left"]
<tbody>[TR]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]External Portfolio Code[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]Base Currency Code[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]Master Portfolio Code[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]25D058[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]USD[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]00000960[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]25D080[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]USD[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]00001412[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]047761[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]USD[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]00001480[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]RUA0100[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]USD[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]00001894[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]RUL002[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]USD[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]00001896[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]097682[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]USD[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]00000026[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]247685[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]USD[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]00000021[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]003345[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]USD[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]00002441[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]970030[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]USD[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]00002623[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]146405[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]USD[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR]
[TD="class: xl65, width: 64"]00002685[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

Enter current date or time
Ctrl+: enters current time. Ctrl+; enters current date. Use Ctrl+: Ctrl+; Enter for current date & time.
You can just use VLOOKUP. Consider:

Code:
Sub test2()


    mytable = Range("A1:C11").Value
    
    code = "25D080"
    x = ""
    On Error Resume Next
    x = WorksheetFunction.VLookup(code, mytable, 3, 0)
    
    Debug.Print x
End Sub
There are several ways to handle the "not found" condition. Here I just set the result to what I want if it's not found, then use the On Error line to just continue if it hits "Not found" and the result variable isn't changed.
 
Upvote 0
You haven't specified then names of either of the sheet which contain the lookuip data or the data to be lookup.
You haven't specified where you want the answer to go, so I assumed:
1: the table of lookup data was on sheet "lookupdata"
2: the data to be looked up was in column A of sheet "data"
3: the answers are written into column B of sheet Data
this is all done by using variant arrays which is a very fast way of doing vlookps in VBA
Code:
Sub test()
With Worksheets("LookupData")
' load all thje lookup table into a variant array
lastrow = .Cells(Rows.Count, "A").End(xlUp).Row
Ldatar = Range(.Cells(1, 1), .Cells(lastrow, 3))
End With
With Worksheets("Data")
' load all the dat to be lookup in to a variant array
lastrw = .Cells(Rows.Count, "A").End(xlUp).Row
inarr = Range(.Cells(1, 1), .Cells(lastrw, 1))
' load and out put rangein a variant aarrayt
Range(.Cells(1, 2), .Cells(lastrw, 2)) ="" 
outarr = Range(.Cells(1, 2), .Cells(lastrw, 2))
For i = 1 To lastrw
 For j = 1 To lastrow
  If inarr(i, 1) = Ldatar(j, 1) Then
   outarr(i, 1) = Ldatar(j, 3)
   Exit For
  End If
 Next j
Next i


Range(.Cells(1, 2), .Cells(lastrw, 2)) = outarr
End With
End Sub
 
Last edited:
Upvote 0
This is the option you request, make a match and get the 3 value.

Code:
Sub Test_Array()
  Dim sh1 As Worksheet, sh2 As Worksheet
  Dim a() As Variant, b() As Variant, c() As Variant, n As Variant
  Set sh1 = Sheets("Sheet1")
  Set sh2 = Sheets("Sheet2")
  a = sh1.Range("A2:C" & sh1.Range("A" & Rows.Count).End(xlUp).Row).Value
  b = sh2.Range("A2:A" & sh2.Range("A" & Rows.Count).End(xlUp).Row).Value
  ReDim c(1 To UBound(b))
  For i = 1 To UBound(b)
    n = [COLOR=#0000ff]Application.Match[/COLOR](b(i, 1), [COLOR=#0000ff]Application.Index[/COLOR](a, 0, 1), 0)
    If IsError(n) Then
      c(i) = ""
    Else
      c(i) = a(n, 3)
    End If
  Next
End Sub

----------------------------------------

But the following, I think is faster. In the c () array you will have the results.

Code:
Sub Test_Array_2()
  Dim sh1 As Worksheet, sh2 As Worksheet
  Dim a() As Variant, b() As Variant, c() As Variant, n As Variant
  Dim dict As Object
  Set sh1 = Sheets("Sheet1")
  Set sh2 = Sheets("Sheet2")
  a = sh1.Range("A2:C" & sh1.Range("A" & Rows.Count).End(xlUp).Row).Value
  b = sh2.Range("A2:A" & sh2.Range("A" & Rows.Count).End(xlUp).Row).Value
  ReDim c(1 To UBound(b))
  Set dict = CreateObject("Scripting.Dictionary")
  For i = 1 To UBound(a)
    dict.Add a(i, 1), a(i, 3)
  Next
  dict.CompareMode = TextCompare
  For i = 1 To UBound(b)
    If Not dict.Exists(b(i, 1)) Then
      c(i) = ""
    Else
      c(i) = dict(b(i, 1))
    End If
  Next
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,903
Messages
6,175,284
Members
452,630
Latest member
OdubiYouth

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