VBA Vlookup using Array

Guinaba

Board Regular
Joined
Sep 19, 2018
Messages
217
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
 
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.

hmm...
I don't use parentheses when I want to use a variant array to store data from a range
I use parentheses when I declare an array that will hold values that will be inserted into it. After declaring them it is necessary to use the ReDim statement to assign dimensions to the array,

Maybe someone has a better and more complete explanation (help!)

M.
 
Upvote 0

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes
I don't know about speed compared to what you originally had, but this should be faster than the post #9 code since there is less interaction between the worksheets and the code.
I have also reduced the amount of data loaded into memory arrays. Perhaps you need that extra data for something else but it seems to me that the only data you need from 'TPRP' for this exercise is column H.

VBA Code:
Sub TPRP_Refresh_v2()
  Dim ArrCalc As Variant, ArrVlkup1 As Variant, Results As Variant
  Dim ii As Long
  
  With Sheets("TPRP")
    ArrCalc = Intersect(.Range("A1").CurrentRegion, .Columns("H")).Value
    ArrVlkup1 = Sheets("criteria").Range("A2:B" & Sheets("criteria").Cells(.Rows.Count, "A").End(xlUp).Row).Value
    ReDim Results(5 To UBound(ArrCalc), 1 To 1)
    For ii = 5 To UBound(ArrCalc)
      Results(ii, 1) = Application.VLookup(ArrCalc(ii, 1), ArrVlkup1, 2, False)
    Next ii
    .Range("A5").Resize(UBound(Results) - LBound(Results) + 1).Value = Results
  End With
  Erase ArrCalc, ArrVlkup1
End Sub
 
Upvote 0
I don't know about speed compared to what you originally had, but this should be faster than the post #9 code since there is less interaction between the worksheets and the code.
I have also reduced the amount of data loaded into memory arrays. Perhaps you need that extra data for something else but it seems to me that the only data you need from 'TPRP' for this exercise is column H.

VBA Code:
Sub TPRP_Refresh_v2()
  Dim ArrCalc As Variant, ArrVlkup1 As Variant, Results As Variant
  Dim ii As Long
 
  With Sheets("TPRP")
    ArrCalc = Intersect(.Range("A1").CurrentRegion, .Columns("H")).Value
    ArrVlkup1 = Sheets("criteria").Range("A2:B" & Sheets("criteria").Cells(.Rows.Count, "A").End(xlUp).Row).Value
    ReDim Results(5 To UBound(ArrCalc), 1 To 1)
    For ii = 5 To UBound(ArrCalc)
      Results(ii, 1) = Application.VLookup(ArrCalc(ii, 1), ArrVlkup1, 2, False)
    Next ii
    .Range("A5").Resize(UBound(Results) - LBound(Results) + 1).Value = Results
  End With
  Erase ArrCalc, ArrVlkup1
End Sub
Thanks @Peter_SSs! Much appreciate it!
 
Upvote 0

Forum statistics

Threads
1,214,620
Messages
6,120,554
Members
448,970
Latest member
kennimack

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