Vlookup Dynamic Range Macro

JADownie

Active Member
Joined
Dec 11, 2007
Messages
395
I am using the code below to do a vlookup on a column in a sheet in my work to pull in matching values from another.

Lets suppose in column A I have values in 500 rows. Is it possible to alter this code to ignore blanks, and continue copying the formula down to the row where the last value is conatined. Example, there was data in A2-A200, and then cells A201-A205 were blank, and then A206-A500 contained values. Instead of stopping at A200, can a macro continue down to A500 where the last value is present?


Sheets("Matching").Select
Dim LastRow As Long
LastRow = Cells.Find(What:="*", _
SearchDirection:=xlPrevious, _
SearchOrder:=xlByRows).Row
Range("B2:B" & LastRow).FormulaR1C1 = "= VLOOKUP(RC[-1],'Old Map'!C[-1]:C[9],11,FALSE)"
Application.CutCopyMode = False
 

Excel Facts

What do {} around a formula in the formula bar mean?
{Formula} means the formula was entered using Ctrl+Shift+Enter signifying an old-style array formula.
I'm not understanding your question. Since your code uses the .Find method to find the last row in any column with any data, it will ignore blanks.

In the scenario you describe, the code you have will enter the formula from B2:B500.
Of course the any blank cells in Column A will yield #N/A values for the same row in Column B. You could add the IFERROR function to your formula if you want to eliminate the #N/A's.

Please clarify if I misunderstood.
 
Upvote 0
I am using the code below to do a vlookup on a column in a sheet in my work to pull in matching values from another.

Lets suppose in column A I have values in 500 rows. Is it possible to alter this code to ignore blanks, and continue copying the formula down to the row where the last value is conatined. Example, there was data in A2-A200, and then cells A201-A205 were blank, and then A206-A500 contained values. Instead of stopping at A200, can a macro continue down to A500 where the last value is present?


Sheets("Matching").Select
Dim LastRow As Long
LastRow = Cells.Find(What:="*", _
SearchDirection:=xlPrevious, _
SearchOrder:=xlByRows).Row
Range("B2:B" & LastRow).FormulaR1C1 = "= VLOOKUP(RC[-1],'Old Map'!C[-1]:C[9],11,FALSE)"
Application.CutCopyMode = False


Maybe:

Code:
Sub JADownie()

Sheets("Matching").Select

Dim LastRow As Long

LastRow = Cells.Find(What:="*", SearchDirection:=xlPrevious, SearchOrder:=xlByRows).Row

With Range("A2:A" & LastRow)

        .AutoFilter Field:=1, Criteria1:="<>"


            With Range("B2:B" & LastRow)

                .SpecialCells(xlCellTypeVisible).FormulaR1C1 = "= VLOOKUP(RC[-1],'Old Map'!C[-1]:C[9],11,FALSE)"
    
            End With
            
        .AutoFilter
    
End With

End Sub
 
Upvote 0

Forum statistics

Threads
1,226,287
Messages
6,190,065
Members
453,592
Latest member
bcexcel

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