Lookup values from two combobox on a userform

jooz56

New Member
Joined
Apr 13, 2018
Messages
2
Hi
Im trying to lookup two values that come from two comboboxes of a userform and the result to appear in a textbox

The values of the comboboxes are related to two different name ranges on my sheet 2 and the table array for the lookup formula is in the same sheet (sheet2)

I want that a button on the userform when clicked show me the lookup result from these two comboboxes on a texbox and if the combination ot this two comboboxes doesn´t match then send me a message that there is no match.

My first combobox has a list of products and the second a list of countries. My data has four columns the first its a help column to make the lookup the second contains a product, the third a country and the fourth a regulation that applies depending of the combination of the first and second column.


helperproductconuntryregulartion
tomatospaintomatospainregulation 1
avocadoUSAavocadoUSAregulation 3
blueberryjapanblueberryjapanregulation 9

<tbody>
</tbody>

Code:
Private Sub CommandButton1_click() 

txtregulation = Application.WorksheetFunction.VLookup(ComboBox1.value & ComboBox2.value, Sheet1.Range("tabla"), 4, False)


i tried with this code for the vlookup formula but the result doesnt appear

help please!!!
 

Excel Facts

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)
How about
Code:
Option Explicit
Private Dic As Object

Private Sub CommandButton1_Click()
   Dim ValU As String
    ValU = Dic(Me.[COLOR=#ff0000]ComboBox1[/COLOR].Value & Me.[COLOR=#ff0000]ComboBox2[/COLOR].Value)
    If ValU = "" Then MsgBox "No Value"
    Me.[COLOR=#ff0000]TextBox1[/COLOR].Value = ValU
End Sub

Private Sub UserForm_Initialize()

   Dim v1 As String
   Dim Cl As Range
   Set Dic = CreateObject("scripting.dictionary")
   Dic.CompareMode = vbTextCompare

   With Sheets("[COLOR=#ff0000]Pcode[/COLOR]")
      For Each Cl In .Range("B2", .Range("B" & Rows.count).End(xlUp))
         v1 = Cl.Value & Cl.Offset(, 1).Value
         If Not Dic.exists(v1) Then Dic.Add v1, Cl.Offset(, 2).Value
      Next Cl
   End With
End Sub
This doesn't need a helper column.
Change values in red to suit
 
Last edited:
Upvote 0
thanks for the reply

i tried this code but it only shows a msgbox "no value". my data is on sheet 1 the table array is on A1 to C9. I filled the two comboboxes so the values match with my third column (C) but it shows "No value"

what other option can i try ?
 
Upvote 0
If combobox1 values are in col A & combobox2 values are in col B try
Code:
Private Sub UserForm_Initialize()

   Dim v1 As String
   Dim Cl As Range
   Set Dic = CreateObject("scripting.dictionary")
   Dic.CompareMode = vbTextCompare

   With Sheets("Sheet1")
      For Each Cl In .Range("A1", .Range("A" & Rows.Count).End(xlUp))
         v1 = Cl.Value & Cl.Offset(, 1).Value
         If Not Dic.exists(v1) Then Dic.Add v1, Cl.Offset(, 2).Value
      Next Cl
   End With
End Sub
Also these 2 lines
Code:
Option Explicit
Private Dic As Object
must be at the very top of the userform module(ie before any code)
 
Upvote 0

Forum statistics

Threads
1,214,878
Messages
6,122,062
Members
449,064
Latest member
scottdog129

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