Combobox populated with Named Range Dynamic

Status
Not open for further replies.

timk5000

New Member
Joined
Feb 29, 2016
Messages
8
I have several Comboboxes on a user form that are each populated with Named Ranges. I would like to put a button next to each combobox so that If a user types something into the combo box that is not in the list They could click the button and insert it into the list.

Currently all the lists are on the same page each with its own name.

I am hoping there is a simple way of doing this.

Thanks
 

Excel Facts

How to calculate loan payments in Excel?
Use the PMT function: =PMT(5%/12,60,-25000) is for a $25,000 loan, 5% annual interest, 60 month loan.
Duplicate https://www.mrexcel.com/forum/excel...opulated-named-range-dynamic.html#post5226385

Please do not post the same question multiple times. All clarifications, follow-ups, and bumps should be posted back to the original thread.
Per forum rules, posts of a duplicate nature will be locked or deleted (rule 12 here: Forum Rules).

Note that sometimes posts from new users require Moderator approval before you can see them on the public forums. When this happens, you should see a message to that effect when you try to post it.
Please be patient and do not attempt to post the question again.
 
Upvote 0
I can't promise if this is the simple way or not, but here how I would do that.

Following needs the named ranges to be "dynamic", which means they must be created by using OFFSET function.

I have a sample input list in A1:A5. So I defined a named range called as "named1" by using the following formula:

Code:
=OFFSET(Sheet1!$A$1,0,0,COUNTA(Sheet1!$A:$A),1)

This way, it will be possible to expand the input range when the missing items are entered in the combobox.

Next, I created a combobox in my userform, ComboBox1, and set its RowSource property to be "Sheet1!named1".

And I wrote the following function called "validateItem", which I created as a separate function, so I can call it from multiple combobox exit event. This function takes one parameter, which is the ComboBox object that is calling it.

Code:
Public Function validateItem(cmb As MSForms.ComboBox)
Dim rng As Range
    With cmb
        If Not .MatchFound Then
            Set rng = Application.Range(.RowSource)
            rng.Offset(rng.Rows.Count).Resize(1).Value = .Value
            .RowSource = .RowSource
        End If
    End With
End Function

Now I can call this function from each ComboBox Exit event to make sure that "not existing" values will be added into the corresponding named range after the last cell in the range. (You can still use a button for this, but making it more automated might be better idea. It just works as soon as user moves away from the combobox. No need to click on a button.)

Code:
Private Sub ComboBox1_Exit(ByVal Cancel As MSForms.ReturnBoolean)
    Me.validateItem Me.ComboBox1
End Sub

And now I can add more ComboBoxes with more named ranges following the same method to create and link the named ranges with the RowSource property of the combobox controls. All I need to do is, adding the same function call into the Exit event of the comboboxes, like below for ComboBox2.

Code:
Private Sub ComboBox2_Exit(ByVal Cancel As MSForms.ReturnBoolean)
    Me.validateItem Me.ComboBox2
End Sub

In fact, if I had hundreds of comboboxes on the same form, which is unlikely but just to mention this, then I wouldn't want to copy and paste the function call into each control's event procedure, instead I would create a special combobox object class by using withevents, and catch all combobox Exit events in that centralized class module. As I said, just to mention.

I hope this helps, and gives the idea.
 
Upvote 0
Status
Not open for further replies.

Forum statistics

Threads
1,223,911
Messages
6,175,322
Members
452,635
Latest member
laura12345

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