Combobox Error on Change event

hstaubyn

Board Regular
Joined
Sep 13, 2010
Messages
91
Hi,

I have a combobox that is misbehaving. It has a change event that should change a label on the same userform depending on the combobox value that is selected. To do this I use the worksheet function 'vlookup', but whenever the code runs, I get a run-time error 1004. The problem seems to be in the use of vlookup, but this method works on another combobox (referencing text) on the same userform. My code is below:

Code:
Private Sub CboJobNo_Change()
    LblProjName.Caption = Application.WorksheetFunction.VLookup(CboJobNo.Value, Range("Job_List"), 2, False)
End Sub

'LblProjName' is the label being changed
'CboJobNo' is the combobox being changed

'Job_List' is a named range in the worksheet of two columns with job numbers in the first (stored as numbers) and corresponding job names in the second (stored as text).

The error message is as follows:

"Unable to get the VLookup property of the WorksheetFunction class"


Does anyone know where I am going wrong? Any help would be greatly appreciated.
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce

Ruddles

Well-known Member
Joined
Aug 24, 2010
Messages
5,792
Office Version
  1. 365
Platform
  1. Windows
Replace CboJobNo.Value with CLng(CboJobNo.Value) in the VLookup and see if that works.
 

hstaubyn

Board Regular
Joined
Sep 13, 2010
Messages
91
Ruddles,

no joy I'm afraid, still doesn't work. Thanks for the suggestion though.
 

RoryA

MrExcel MVP, Moderator
Joined
May 2, 2008
Messages
38,782
Office Version
  1. 365
  2. 2019
  3. 2016
  4. 2010
Platform
  1. Windows
  2. MacOS
Assuming you are sure there is a match, then try:
Code:
Private Sub CboJobNo_Change()
    LblProjName.Caption = Application.WorksheetFunction.VLookup(Val(CboJobNo.Value), Range("Job_List"), 2, False)
End Sub
 

Mike Blackman

Well-known Member
Joined
Jun 8, 2007
Messages
2,494

ADVERTISEMENT

Hi,

It may well be worth declaring which sheet your lookup range is on as this can cause issues at times:

Code:
Private Sub CboJobNo_Change()
    LblProjName.Caption = Application.WorksheetFunction.VLookup(Val(CboJobNo.Value), Sheets("MySheet").Range("Job_List"), 2, False)
End Sub
 
Last edited:

hstaubyn

Board Regular
Joined
Sep 13, 2010
Messages
91
Brilliant, the "val(..." addition to the code works perfectly.

I didn't think of that because the combobox is populated from the same cells that appear in the left hand column of the lookup range! One would have thought they would match formats (or whatever property was causing the problem) because of that.

Anyway, one step closer to ultimate VBA knowledge, thanks!
 

Norie

Well-known Member
Joined
Apr 28, 2004
Messages
76,344
Office Version
  1. 365
Platform
  1. Windows
If the combobox is populated from the left column why not use the combobox's ListIndex to get the data instead of VLookUp?

Then there would be no need to worry about formats.
Code:
Private Sub CboJobNo_Change()
 
    If CboJobNo.ListIndex <> -1 Then
        LblProjName.Caption = Range("Job_List").Cells(1, 1).Offset(CboJobNo.ListIndex, 1)
    End If
End Sub
 
Private Sub UserForm_Initialize()
    CboJobNo.List = Range("Job_List").Resize(, 1).Value
End Sub
 
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,164,017
Messages
5,834,960
Members
430,330
Latest member
drAli77

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