Reusing VBA Codes using Arguments

animas

Active Member
Joined
Sep 28, 2009
Messages
396
I am trying to use the below code to create unique and sorted list dropdown inside a combobox list. What I am looking for is a subruoutine with arguments (List Range, Combobox), so that I can reuse the code for multiple comboboxes. How to modify the below code for this. Codes between "Private Sub UserForm_Initialize() .. End Sub" will be reused.

Thanks.

Code:
Option Explicit
Dim FArray()
Dim DataList As Range
Dim MyList As String
 
Private Sub UserForm_Initialize()
    Dim Found As Long, i As Long
    Dim cel As Range
 
     'Set Range Name to suit
    MyList = "[B]Table_Customer[Customer Name]"[/B]
 
    Set DataList = Range(MyList)
    ReDim FArray(DataList.Cells.Count)
    i = -1
 
    For Each cel In DataList
        On Error Resume Next
        Found = Application.WorksheetFunction.Match(CStr(cel), FArray, 0)
        If Found > 0 Then GoTo Exists
        i = i + 1
        FArray(i) = cel
Exists:
        Found = 0
    Next
    ReDim Preserve FArray(i)
    Call BubbleSort(FArray)
    [B]cmbName[/B].ListRows = i + 1
    [B]cmbName[/B].List() = FArray
End Sub
 
Last edited:

Some videos you may like

Excel Facts

How to create a cell-sized chart?
Tiny charts, called Sparklines, were added to Excel 2010. Look for Sparklines on the Insert tab.

RoryA

MrExcel MVP, Moderator
Joined
May 2, 2008
Messages
35,523
Office Version
  1. 365
  2. 2019
  3. 2016
  4. 2010
Platform
  1. Windows
  2. MacOS
Something like:
Code:
Private Sub SortList(DataList As Range, cmbName As MSForms.ComboBox)
    Dim Found As Long, i As Long
    Dim cel As Range
 
    ReDim FArray(DataList.Cells.Count)
    i = -1
 
    For Each cel In DataList
        On Error Resume Next
        Found = Application.WorksheetFunction.Match(CStr(cel), FArray, 0)
        If Found > 0 Then GoTo Exists
        i = i + 1
        FArray(i) = cel
Exists:
        Found = 0
    Next
    ReDim Preserve FArray(i)
    Call BubbleSort(FArray)
    cmbName.ListRows = i + 1
    cmbName.List() = FArray
End Sub
 

animas

Active Member
Joined
Sep 28, 2009
Messages
396
Code:
Private Sub UserForm_Initialize()
    SortList(Table_Customer[Customer Name], cmbCustomerName)...
End Sub

is showing error. My range is a column of a table. how can I pass this as argument?
 

RoryA

MrExcel MVP, Moderator
Joined
May 2, 2008
Messages
35,523
Office Version
  1. 365
  2. 2019
  3. 2016
  4. 2010
Platform
  1. Windows
  2. MacOS
Remove the parentheses - they don't belong there - and add the Range call:
Code:
Private Sub UserForm_Initialize()
    SortList Range("Table_Customer[Customer Name]"), cmbCustomerName 
End Sub
 

animas

Active Member
Joined
Sep 28, 2009
Messages
396
Wonderful. I tried that with multiple comboboxes and working nice.
Many thanks.
 

Watch MrExcel Video

Forum statistics

Threads
1,109,493
Messages
5,529,187
Members
409,856
Latest member
MAO
Top