Running specific code after a VLOOKUP error '1004'

FeltRubber

New Member
Joined
Oct 6, 2014
Messages
4
Hey guys..

So i'm attempting to do a VLOOKUP on a list of names, the Lookup_Value being pulled from an added worksheet and the Lookup_Range being on a Master sheet (both within the same workbook)

The code works perfect when the VLOOKUP returns a value, but when returning the error '1004', it tells me the that the name is not on the master list and NEEDS TO BE ADDED TO IT.

So, I've been trying to run code from where the subroutine jumps to when the VLOOKUP returns a N/A value, but have had zero success. I am trying to take the names that are NOT found via the VLOOKUP and add them to the bottom of the master list

Here's a portion of what I have so far...

Code:
For b = 1 To players
    playerName = Worksheets(newSheet).Range("A" & d).Value
    playerScore = Application.VLookup(playerName, Sheets("Master").Range("A13:B500"), 2, False)
    If IsError(playerScore) Then
        Worksheets(newSheet).Range("A" & d).Copy Destination:=Range("A" & Rows.Count).End(xlUp).Offset(1)
        Worksheets(newSheet).Range("C" & d).Copy Destination:=Range("B" & Rows.Count).End(xlUp).Offset(1)
    Else
        Set GCell = ThisWorkbook.Worksheets("Master").Cells.Find(playerName)
        newPlayerScore = Worksheets(newSheet).Range("C" & d)
        oldPlayerScore = Worksheets("Master").Range(GCell.Address).Offset(0, 1).Value
        newPlayerScoreTotal = newPlayerScore + oldPlayerScore
        Worksheets("Master").Range(GCell.Address).Offset(0, 1).Value = newPlayerScoreTotal
    End If
    d = d + 1
Next

Any help would be greatly appreciated!
 

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off
Untested, but try:
Code:
For b = 1 To players
    playerName = Sheets(NewSheet).Range("A" & d).Value
    On Error Resume Next
    playerScore = Sheets("Master").Range("A13:B500").Find(What:=playerName, lookin:=xlvalues, lookat:=xlwhole).Offset(, 1).Value
    On Error GoTo 0

    If playerScore Is Nothing Then
       With Sheets(NewSheet)
            .Range("A" & .Rows.Count).End(xlUp).Offset(1).Value = .Range("A" & d).Value
            .Range("B" & .Rows.Count).End(xlUp).Offset(1).Value = .Range("C" & d).Value
        End With
    Else
        Set GCell = Sheets("Master").Cells.Find(what:=playerName, LookIn:=xlValues, lookat:=xlWhole)
        newPlayerScore = Sheets(NewSheet).Range("C" & d).Value
        GCell.Offset(, 1).Value = GCell.Offset(, 1).Value + newPlayerScore
    End If

Next b
 
Last edited:
Upvote 0
JackDan

Thank you for the time and effort! Never thought of doing it that way, but it makes it a much easier workaround for the VLOOKUP.

I'm getting a runtime error at the following spot
Code:
[COLOR=#333333] If playerScore Is Nothing Then[/COLOR]

I'm almost positive it is due to how the variable is declared at the beginning of the sub.
Any idea what I need to declare the variable 'playerScore' as so that it is compatible with the If <condition> Is Nothing Then?
I've tried INT, DOUBLE, LONG, OBJECT, NEW RETURNINT, etc...
 
Upvote 0
See if this works (changes in blue)
Rich (BB code):
For b = 1 To players
    playerName = Sheets(NewSheet).Range("A" & d).Value

    On Error Resume Next
    Set GCell = Sheets("Master").Range("A13:B500").Find(what:=playerName, LookIn:=xlValues, lookat:=xlWhole)
    On Error GoTo 0

    If GCell Is Nothing Then
       With Sheets(NewSheet)
            .Range("A" & .Rows.Count).End(xlUp).Offset(1).Value = .Range("A" & d).Value
            .Range("B" & .Rows.Count).End(xlUp).Offset(1).Value = .Range("C" & d).Value
        End With
    Else
        newPlayerScore = Sheets(NewSheet).Range("C" & d).Value
        GCell.Offset(, 1).Value = GCell.Offset(, 1).Value + newPlayerScore
    End If

Next b
 
Last edited:
Upvote 0
JackDan

You are the man! Worked like a charm!

Now, how do I go about giving you positive feedback for helping me with this???
 
Upvote 0
Glad it works and no need for feedback, I'm glad this site was around when I needed help (and still do!), so happy to be able to recipriocate back. Appreciate and thanks for the offer :)
 
Upvote 0

Forum statistics

Threads
1,213,506
Messages
6,114,025
Members
448,543
Latest member
MartinLarkin

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