Unique values in two different comboboxes in a form....

raghuprabhu

New Member
Joined
Apr 8, 2017
Messages
7
Good evening All,

I have a form with 2 combo boxes.

For the first combo box, combobox1, I have has unique list from Column A as record source using the following code

Code:
Private Sub UserForm_Initialize()
    Dim myCollection As Collection
    Dim cell As Range
    
    On Error Resume Next
    Set myCollection = New Collection
        With combobox1
        .Clear
            For Each cell In Range("A2:A" & Cells(Rows.Count, 1).End(xlUp).Row)
                If Len(cell) <> 0 Then
                    Err.Clear
                    myCollection.Add cell.Value, cell.Value
                    If Err.Number = 0 Then .AddItem cell.Value
                End If
            Next cell
        End With
    combobox1.ListIndex = 0
End Sub

How do I change it to include a unique list as source for the second combo box, combobox2 from column E?

Thank you

Regards

Raghu Prabhu
From Chilly Melbourne.
 

Excel Facts

Convert text numbers to real numbers
Select a column containing text numbers. Press Alt+D E F to quickly convert text to numbers. Faster than "Convert to Number"
Can you give an example of what you have in both columns; and column E what data would you upload in combo2?
 
Upvote 0
Is combo2 dependant on combo1, or is it all the unique values from col E?
 
Upvote 0
If combo2 is not dependant on combo1, try
Code:
Private Sub UserForm_Initialize()
   Dim DicA As Object, DicE As Object
   Dim Cl As Range
   
   Set DicA = CreateObject("scripting.dictionary")
   Set DicE = CreateObject("scripting.dictionary")
   For Each Cl In Range("A2:A" & Cells(Rows.Count, 1).End(xlUp).Row)
      If Cl.Value <> "" Then DicA(Cl.Value) = Empty
      If Cl.Offset(, 4).Value <> "" Then DicE(Cl.Offset(, 4).Value) = Empty
   Next Cl
   With Me.ComboBox1
      .List = DicA.Keys
      .ListIndex = 0
   End With
   With Me.ComboBox2
      .List = DicE.Keys
      .ListIndex = 0
   End With
End Sub
 
Upvote 0
Thank you very much Fluff,

Your code is working like a charm!

I used the following and it works too, but sometimes one of the combo boxes does not get populated...what could be the reason?

I consider this post as solved.

Code:
Private Sub UserForm_Initialize()
    Dim myCollection1 As Collection
    Dim myCollection2 As Collection
    Dim cell As Range
    
    On Error Resume Next
    Set myCollection1 = New Collection
        With combobox1
        .Clear
            For Each cell In Range("A2:A" & Cells(Rows.Count, 1).End(xlUp).Row)
                If Len(cell) <> 0 Then
                    Err.Clear
                    myCollection1.Add cell.Value, cell.Value
                    If Err.Number = 0 Then .AddItem cell.Value
                End If
            Next cell
        End With
    combobox1.ListIndex = -1
    
    Set myCollection2 = New Collection
        With ComboBox2
        .Clear
            For Each cell In Range("E2:E" & Cells(Rows.Count, 2).End(xlUp).Row)
                If Len(cell) <> 0 Then
                    Err.Clear
                    myCollection2.Add cell.Value, cell.Value
                    If Err.Number = 0 Then .AddItem cell.Value
                End If
            Next cell
        End With
    ComboBox2.ListIndex = -1
End Sub

Kind Regards

Raghu Prabhu
 
Last edited:
Upvote 0
I used the following and it works too, but sometimes one of the combo boxes does not get populated...what could be the reason?
This
Code:
On Error Resume Next
That line will simply mask any errors encountered.
 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,239
Members
452,621
Latest member
Laura_PinksBTHFT

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