worksheetFunction.vlookup doesnt work in my vba code

ke9c

Board Regular
Joined
Jul 27, 2010
Messages
75
hi, i am trying to do lookup in sheet "Rawdata", while referencing table sheet "CFG", but when i run till b=application.worksheetFunction.vlookup, it always prompt error msg "unable to get the vlookup property of the worksheetfunction class", can help? Thanks
-----------------------
Worksheets("RawData").Select
Call LoadTicker(Range("AA1", "AA100" ), -3)

Sub LoadTicker(rRange As Range, iOffset As Integer)
Worksheets("CFG").Select
Dim varCell As Range
For Each varCell In rRange.Cells
varCell.Select
Dim b As Variant
b = Application.WorksheetFunction.VLookup(varCell.Offset(0, iOffset ).Value, Range("A10", "B14"), 2, False)
varCell.value=b
' varCell.FormulaR1C1 = "=VLOOKUP(RC[-2],rr,2,FALSE)"

Next varCell
End Sub
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.

ke9c

Board Regular
Joined
Jul 27, 2010
Messages
75
And even if i use b = Application.WorksheetFunction.VLookup("aa", Range("C17", "D30"), 2, False), i will get same error
 

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707
Please can you be explicit about where the lookup values are (please give actual sheet name and range address - not just range name) and where the lookup range resides (sheet name and range address). You currently appear to have problems caused by unqualified references (you are probably pointing at ranges you didn't intend).

Note that you will be able to do this without looping - so please answer my first questions above.
 

Michael M

Well-known Member
Joined
Oct 27, 2005
Messages
21,346
Office Version
  1. 365
  2. 2007
Platform
  1. Windows
Is "aa" a sheet name or a named range ??
It needs to be a single cell reference I believe, also
Have you tried using
Code:
b = Application.WorksheetFunction.VLookup("aa", Range("C17:D30"), 2, False)
 

ke9c

Board Regular
Joined
Jul 27, 2010
Messages
75
aa is a string, i want to test whether vlookup function can lookup out data in CFG sheet based on first column have value "aa". Thanks
 

ke9c

Board Regular
Joined
Jul 27, 2010
Messages
75
My Table is as below, basically, i want to use vlookup in RawData sheet, if CFG C col contains Y col Data, then overwrite AA col in RawData with value in D col of CFG sheet.

In RawData
Y Col AA Col
----- ------
aaa xxx
bbb yyy
ccc zzz

In CFG
C col D Col
----- ------
aaa ggg
ddd hhh
eee iii
 

Michael M

Well-known Member
Joined
Oct 27, 2005
Messages
21,346
Office Version
  1. 365
  2. 2007
Platform
  1. Windows
I'm not quite following you but if you are looking for a string "aa" then you will have to include an IF statement in your VLOOKUP, because it won't do the search for you.
I'd suggest you reread Richards post and provide us with more info.
 

ke9c

Board Regular
Joined
Jul 27, 2010
Messages
75
hi, Michael, thanks, does my post #6 clarify my question? Thanks
 

ke9c

Board Regular
Joined
Jul 27, 2010
Messages
75
yes, i should use if, but \whenever i use vlookup in this way, the debugger will complain, so i cannot get a value out to do comparision in if statement.
 

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707
Hi

Try this:

Code:
Sub Test()
Dim vArray As Variant  'use this to hold all lookedup values (means we can do lookup in one go)
Dim i As Long  'for next counter
Dim rngOfValues As Range

With Sheets("Raw Data")
    Set rngOfValues = .Range("Y1:Y" & .Cells(.Rows.Count, "Y").End(xlUp).Row)
End With

vArray = Application.VLookup(rngOfValues.Value, Sheets("CFG").Range("C:D"), 2, 0)


For i = 1 To UBound(vArray, 1)
    If IsError(vArray(i, 1)) Then _
        vArray(i, 1) = rngOfValues.Cells(i, 1).Offset(, 2).Value 'this serves to replace any error values (ie those without a match on sheet CFG) with the existing value in Raw Data
Next i

'write values back to Raw Data sheet:

rngOfValues.Offset(, 2).Value = vArray


End Sub
 

Forum statistics

Threads
1,171,573
Messages
5,876,240
Members
433,187
Latest member
schellett

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