VBA Vlookup using Array

Guinaba

Board Regular
Joined
Sep 19, 2018
Messages
165
Office Version
  1. 2016
Platform
  1. Windows
Hi guys,

I'm trying to use vlookup within array to make the code runs faster, in the code below the .Cells(ii, 1).Formula with vlookup is working ok, however the other two lines don't. Any suggestion? These two lines are doing the same thing, just trying different approaches.

.Cells(ii, 1).value = Application.VLookup(ArrCalc(ii, 1), ArrVlkup1, 2, False)

ArrResult1(ii) = Application.VLookup(ArrCalc(ii, 1), ArrVlkup1, 2, False)


VBA Code:
Sub TPRP_Refresh()

Application.ScreenUpdating = False

'Loop to calculate the formulas

Dim RangeCalc As Range

Set RangeCalc = Sheets("TPRP").Range("A1").CurrentRegion

Dim ArrCalc() As Variant

Dim RangeVlkup1 As Range

Set RangeVlkup1 = Sheets("criteria").Range("A2").CurrentRegion

Dim ArrVlkup1() As Variant, ArrResult(500) As Variant

ArrVlkup1 = RangeVlkup1
ArrCalc = RangeCalc
 
Dim ii As Long

For ii = 5 To UBound(ArrCalc)

.Cells(ii, 1).Formula = "VLOOKUP(H" & ii & ",criteria!A:B,2,FALSE))" ‘This method works

.Cells(ii, 1).value = Application.VLookup(ArrCalc(ii, 1), ArrVlkup1, 2, False) ‘This method doesn’t work

ArrResult1(ii) = Application.VLookup(ArrCalc(ii, 1), ArrVlkup1, 2, False) ‘This method doesn’t work

Next ii

ii = ii + 1

End With

Application.ScreenUpdating = True

End sub
 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.

Alex Blakenburg

Well-known Member
Joined
Feb 23, 2021
Messages
2,267
Office Version
  1. 365
Platform
  1. Windows
That is not how a vlookup works.
The 2nd parameter needs a range of cells, it can't use a VBA Array.

If you want to make your code run faster, you could try asking a question on this forum with an XL2BBs of your main data and you lookup data and ask specifically for a dictionary solution.

VLOOKUP (lookup_value, table_array, col_index_num, [range_lookup])
Ref: Microsoft Doc - VLOOKUP function

1628168257815.png
 

Marcelo Branco

MrExcel MVP
Joined
Aug 23, 2010
Messages
16,907
Office Version
  1. 2019
  2. 2010
Platform
  1. Windows
That is not how a vlookup works.
The 2nd parameter needs a range of cells, it can't use a VBA Array

hmm...i'm not so sure

This worked for me
Pasta1
BC
1TextValue
2a10
3b20
4c30
Plan12


VBA Code:
Sub aTest()
    Dim vData As Variant, s As String
    Dim myVar As Long
    
    vData = Range("B2:C4").Value
    s = "b"
    myVar = Application.VLookup(s, vData, 2, 0)
    MsgBox myVar
End Sub

M.
 

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
51,773
Office Version
  1. 365
Platform
  1. Windows
I agree with Marcelo.
However, I am having difficulty advising the OP re that code as it is incomplete and not valid code as it stands.
 

Alex Blakenburg

Well-known Member
Joined
Feb 23, 2021
Messages
2,267
Office Version
  1. 365
Platform
  1. Windows

ADVERTISEMENT

Thanks @Marcelo Branco, Learn something new everyday. 🤔
@Peter_SSs, do you know if it would be faster than using a dictionary ?
 

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
51,773
Office Version
  1. 365
Platform
  1. Windows

ADVERTISEMENT

@Peter_SSs, do you know if it would be faster than using a dictionary ?
I don't know because I don't really know what the OP has or exactly what is being attempted.
 

Marcelo Branco

MrExcel MVP
Joined
Aug 23, 2010
Messages
16,907
Office Version
  1. 2019
  2. 2010
Platform
  1. Windows
Just a guess. I would bet on that known VLOOKUP issue, Text vs. Number, i.e., one of the values is a number and the other is text

M.
 

Guinaba

Board Regular
Joined
Sep 19, 2018
Messages
165
Office Version
  1. 2016
Platform
  1. Windows
Thanks guys! @Marcelo Branco you are right! That was my mistake, I was using the incorrect col. to look for the value in the another array. I have corrected the code below and now it is working.

VBA Code:
Sub TPRP_Refresh()

    With Sheets("TPRP")
            
      'Loop to calculate the formulas
       Dim ArrCalc As Variant, ArrVlkup1 As Variant, ArrVlkup2 As Variant
       Dim LastRow As Long
       ArrCalc = Sheets("TPRP").Range("A1").CurrentRegion
       LastRow = Sheets("criteria").Cells(.Rows.Count, "A").End(xlUp).Row
       ArrVlkup1 = Sheets("criteria").Range("A2:B" & LastRow)
       Dim ii As Long
               
       For ii = 5 To UBound(ArrCalc)
          .Cells(ii, 1).Value = Application.VLookup(ArrCalc(ii, 8), ArrVlkup1, 2, False)
         Next ii
       ii = ii + 1
    End With
      
    Erase ArrCalc, ArrVlkup1
     
End Sub
 
Solution

Guinaba

Board Regular
Joined
Sep 19, 2018
Messages
165
Office Version
  1. 2016
Platform
  1. Windows
Hi @Marcelo Branco,

Just one question, forgot to ask you before, what is the difference when you declare an array with () or not. in your code you are not using. I did the same and the code worked, if I add the ( ) the code doesn't.

For example:

Dim ArrCalc
Dim ArrCalc ()
 

Forum statistics

Threads
1,147,962
Messages
5,744,057
Members
423,843
Latest member
alex2022

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
Top