Error in vlookup function

rdev

Active Member
Joined
Dec 3, 2007
Messages
273
Can someone help me , I am getting error with this 2nd line of code
If Sheets(1).Cells(x, 2).Value = Sheets(2).Name Then
Sheets(1).Cells(x, 4).Value = Application.WorksheetFunction.VLookup(Sheets(1).Cells(x, 4), Sheets(2).Range("E6:F30"), 2, False)
Else
Sheets(1).Cells(x, 4).Value = 0
End If
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
There is nothing 'Wrong' with the code syntactically.

What error do you get?

It could just be that the value in Sheets(1).Cells(x, 4) doesn't exist in Sheets(2).Range("E6:E30")
Basically the same as an #N/A error from Vlookup formula in a cell.
 
Last edited:
Upvote 0
Often those #N/A errors are expected in a small percentage of cells you do the vlookup on.
In a formula you normally use an iferror type of function to handle that.
=IFERROR(vlookup(..),"")

In VBA, try like this

Code:
Dim MyVariable
If Sheets(1).Cells(x, 2).Value = Sheets(2).Name Then
   MyVariable = Application.VLookup(Sheets(1).Cells(x, 4), Sheets(2).Range("E6:F30"), 2, False)
   If Not IsError(MyVariable) Then
       Sheets(1).Cells(x, 4).Value = MyVariable
   End If
Else
    Sheets(1).Cells(x, 4).Value = 0
End If
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,022
Latest member
Mohamed Magdi Tawfiq Emam

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