linking combobox value with VLOOKUP to a textbox in userform

NDMDRB

Board Regular
Joined
Jun 20, 2016
Messages
164
Office Version
  1. 2016
Platform
  1. Windows
Hello,

I have a sheet "Clients" that contains all clients details as the table below and I have all these data as dynamic named range "Client_Details" "A2:D4"

I have a userform with many text boxes and combo boxes, but what I need right now is:
  • Once I choose a Client name in the combobox1, get the ID for this client on textbox1 and the phone number on textbox2
    • ex: if I typed "Nael" from the combobox1, get the ID "102" on textbox1 and the phone number "654654" on textbox2
  • If I typed a name that not exist, get msgbox ("This Client Name is not Exist" & vbCrLf & vbCrLf & "Do you wanna add a new client?" , vbYesNo)
    • If vbYes then, open the userform "NewClient" (And add a new client and then update the list on combobox1 to get the new client)
    • If vbNo, combobox1 = ""


ABCD
1IDNamePhoneEmail
2101Nadim123456sadas
3102Nael654654asdasd
4103Rami545645asfdaf

<tbody>
</tbody>


Many thanks in advanced
 

Excel Facts

Can Excel fill bagel flavors?
You can teach Excel a new custom list. Type the list in cells, File, Options, Advanced, Edit Custom Lists, Import, OK
For the first part, how about
Code:
Dim UfDic As Object

Private Sub ComboBox1_AfterUpdate()
   With Me.ComboBox1
      If UfDic.exists(.Value) Then
         Me.TextBox1.Value = UfDic.Item(.Value)(0)
         Me.TextBox2.Value = UfDic.Item(.Value)(1)
      Else
         MsgBox .Value & " does not exist"
      End If
   End With
End Sub

Private Sub UserForm_Initialize()
   Dim Cl As Range
   
   Set UfDic = CreateObject("scripting.dictionary")
   UfDic.CompareMode = 1
   For Each Cl In Range("Client_Details").Columns(2).Rows
      If Not UfDic.exists(Cl.Value) Then UfDic.Add Cl.Value, Array(Cl.Offset(, -1).Value, Cl.Offset(, 1).Value)
   Next Cl
   Me.ComboBox1.List = UfDic.keys
End Sub
 
Upvote 0
Thank you so much Fluff,

It works great, I just need one more help regarding the msgbox if yes or no, I added the below new lines to the provided code, but I got an error and don't know what it is!!

So, what I need is, once the msgbox pop up, If I pressed no, just close the msgbox and continue, if I pressed yes, show the form "frmNewClient"

Here is the updated code

Code:
Private Sub [COLOR=#333333]ComboBox1[/COLOR]_AfterUpdate()
Dim MsgBoxResult As Long
   With Me.[COLOR=#333333]ComboBox1[/COLOR]
      If UfDic.exists(.Value) Then
         Me.TextBox1.Value = UfDic.Item(.Value)(0)
         Me.Textbox2.Value = UfDic.Item(.Value)(1)
      Else
         MsgBoxResult = MsgBox(.Value & "!!!" & vbCrLf & vbCrLf & "The above client name is not Exist" & vbCrLf & vbCrLf & "Do you wanna add a new client?", vbYesNo)


If MsgBoxResult = vbYes Then
frmNewClient.Show
Else


End If


End Sub
 
Upvote 0
How about
Code:
Private Sub ComboBox1_AfterUpdate()
   With Me.ComboBox1
      If UfDic.exists(.Value) Then
         Me.TextBox1.Value = UfDic.Item(.Value)(0)
         Me.TextBox2.Value = UfDic.Item(.Value)(1)
      Else
         If MsgBox(.Value & "!!!" & vbCrLf & vbCrLf & "The above client name is not Exist" & vbCrLf & vbCrLf & "Do you wanna add a new client?", vbYesNo) = vbYes Then
            frmNewClient.Show
         End If
      End If
   End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,489
Messages
6,113,954
Members
448,535
Latest member
alrossman

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