ComboBox ERROR when trying to clear after INDEX/MATCH lookup...

calumbus53

New Member
Joined
Feb 22, 2018
Messages
17
Hi guys,

I searched the forum and found some code which I was able to use in my form to create a lookup to populate other TextBox within my Form.

The code works fine when matching and looking up the values for the other cells, but I am not able to delete the value/enter my own random property in the ComboBox for use when "adding" to the database at a later date.


I have been using the code below:
Private Sub cmbTestDesc_Change()
Dim matchTest As Variant
matchTest = cmbTestDesc.Value = Application.WorksheetFunction.Index(Sheets("Sheet_Working").Range("B3:B13"), _
Application.WorksheetFunction.Match(cmbTestDesc.Value, Sheets("Sheet_Working").Range("B3:B10000"), 0), 1)
If matchTest = True Then
txtTestProc.Value = Application.WorksheetFunction.Index(Sheets("Sheet_Working").Range("C3:C10000"), _
Application.WorksheetFunction.Match(cmbTestDesc.Value, Sheets("Sheet_Working").Range("B3:B10000"), 0), 1)
txtUTID.Value = Application.WorksheetFunction.Index(Sheets("Sheet_Working").Range("A3:A13"), _
Application.WorksheetFunction.Match(cmbTestDesc.Value, Sheets("Sheet_Working").Range("B3:B10000"), 0), 1)
End If
End Sub


I have tried it a number of different ways but when I try typing in the ComboBox or deleting the value that is in there, I get the error: "Run-time Error '1004: Unable to get the Match property of the WorksheetFunction class."

The bit I will need to try do after solving this is add the value "IF DOES NOT EXIST" to the bottom of the list in the data base.


Any help would be great, cheers.

Cal
 

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
Instead of referring to the Match method of the Worksheetfunction property, refer to the Match method of the Application object. This way you'll get a non-breaking error when there's no match and you can test for an error using the IsError function. Here's a quick example..

Code:
    [COLOR=darkblue]Dim[/COLOR] vMatchVal [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Variant[/COLOR]    

    vMatchVal = Application.Match("x", Range("A1:A10"), 0)
    
    [COLOR=darkblue]If[/COLOR] [COLOR=darkblue]Not[/COLOR] IsError(vMatchVal) [COLOR=darkblue]Then[/COLOR]
        [COLOR=green]'do stuff here[/COLOR]
        '
        [COLOR=green]'[/COLOR]
    [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]

Hope this helps!
 
Upvote 0

Forum statistics

Threads
1,214,641
Messages
6,120,693
Members
448,979
Latest member
DET4492

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