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.