I created an Excel add-in called “Search deList”, to create searchable data validation

Akuini

Well-known Member
Joined
Feb 1, 2016
Messages
5,271
Office Version
  1. 365
Platform
  1. Windows
I created an add-in called “Search deList”, and I share it as a freeware.
Its function is to speed up searching in data validation list. In any cell that has data validation (with List type) pressing ALT+RIGHT will open a Userform with a combobox. You can type multiple keywords (separated by a space) in the combobox and the list will be narrowed down as you type.
I’d be appreciate if anyone can test this add-in to find any bugs or just suggesting ideas to improve its functionality.
Also, the code is not protected by password, so if anyone needs to change or add specific feature or behavior then feel free to amend the code, and if you need help for that I’ll help if I can.

How it works:
  • In any cell that has data validation (with List type) pressing ALT+RIGHT will open a Userform with a combobox.
  • Type some keywords to search, separated by a space, e.g "ma la"
  • The list will be narrowed down as you type.
  • The search ignores the keywords order, so the keyword "ma la" would match "Maryland" and "Alabama".
  • You can use up-down arrow to select an item, then hit ENTER, the selected item will be inserted into the cell, and the userform will be closed.
  • You can also use single-click to select an item, then DOUBLE-CLICK inside the box, the selected item will be inserted into the cell, and the userform will be closed.
  • To leave the combobox without inserting its value to the activecell: hit TAB or ESC
  • Numeric values in the list will be treated as text.
  • In the Status Bar you can see how many unique items are found & displayed.
  • You don't need VBA (except if you want to use additional feature as I explain below), so you can save your workbook as .xlsx.
Additional feature :
If you want, you can also activate the userform by double-clicking a cell, but you need VBA to do that. Here’s how:
Copy-paste this code into Thisworkbook code window of your workbook:
VBA Code:
Private Sub Workbook_SheetBeforeDoubleClick(ByVal Sh As Object, ByVal Target As Range, Cancel As Boolean)
If TypeName(Selection) = "Range" Then
    Dim v
    On Error Resume Next
        v = ActiveCell.Validation.Type
    On Error GoTo 0
    'if activecell has data validation type 3
    'run "Search deList" add-in by doubke-clicking a cell
    If v = 3 Then Cancel = True: Application.Run ("toShow__dheeDAV")
End If
End Sub
Now, in every sheet, double-clicking any cell that has data validation (with List type) will open the Userform.

Image:

image Search deList.jpg


How to use it:
  1. Install the add-in. This article explains how to install an add-in: How to install or uninstall an Excel Add-in - Excel Off The Grid
  2. Open any workbook that has data validation (with list type).
  3. In any cell that has data validation, pressing ALT+RIGHT will open a Userform with a combobox.
  4. Play with it & see how it works.
NOTES:
  • This add-in also works on dependent data validation.
  • It works on large list (I tested it on 100K rows of data).
  • One caveat of using macro is when macro changes/writes something on sheet it will delete Undo Stack, so at that time you can't use UNDO. In this case it happens every time the combobox value is inserted into the active cell.

Search_deList_v1 add-in:
Search_deList_v1

=========================================================================================

Update, 2022-Nov-18:
Search deList v.2.1 + manual.zip, it works on Excel 2007 or later:

Search deList v.365.1 + manual.zip, it works on Excel 365 or later

This new version has some additional features, some of them:
Several ways to search, like using AND or OR or LIKE operator , with or without keyword order.
Sort the list by original order or ascending order.
Widen or shorten the combobox width at run time.
Insert multiple entries into the cell.

=======================================================================================

Regards,
Akuini
 
Last edited by a moderator:
@Akuini
link sample file
I share sample files but the code in excel is the actual data maybe you have a solution and the record there is 260000. Because I opened the comboxbox so slowly
thanks
roykana
 
Upvote 0

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"
@roykana
  1. Note: you need to add the reference “Microsoft Forms 2.0 Object Library” (to work with clipboard)
    And this is how:
    Open your VBA editor.
    Click Tools > References.
    Check the box next to “Microsoft Forms 2.0 Object Library.”


  2. This method works only if there are no cell that has multiple lines, otherwise it won't work correctly.
  3. This code is faster than the earlier code but with 350K records, you still need few seconds to display the combobox.
  4. Replace "Private Sub ComboBox1_Enter()" with this:
VBA Code:
Private Sub ComboBox1_Enter()
Dim x, vb, ary
Dim c As Range, g As Range
Dim cf As String, msg As String
Dim i As Long, h As Long

cf = ActiveCell.Validation.Formula1

't = Timer
msg = "Can't get the range as the list source from data validation formula." & vbLf & "Please, check the formula:" _
            & vbLf & cf
       
        wFlag = False

        On Error Resume Next
        Set c = Evaluate(cf)
        On Error GoTo 0
       
        On Error GoTo skip
       
    If UCase(Left(cf, 5)) = "=CCTA" Then 'if the name range start with "CCTA"
             If Not c Is Nothing Then
            
                Dim obj As New DataObject
                Dim tx As String, z As String
                Dim va, arz, k As Long
            
            If c.Parent.FilterMode = True Then
                    c.Parent.ShowAllData
            End If
             Set d = CreateObject("scripting.dictionary"): d.CompareMode = vbTextCompare

                If cf = "=CCTA_X" Then
                   
                    ReDim va(1 To c.Cells.Count, 1 To 2)
                    Do
                    c.Resize(, 2).Copy
                      DoEvents
                    obj.GetFromClipboard
                    tx = obj.GetText
                    Loop Until tx <> Empty
'                      Application.Wait Now + TimeValue("0:00:01")
                   

                    tx = vbTab & Replace(tx, vbCrLf, vbTab)
                    arz = Split(tx, vbTab)
                    For i = 1 To UBound(arz) - 2 Step 2
                        k = k + 1
                        va(k, 1) = CStr(arz(i))
                        va(k, 2) = arz(i + 1)
                    Next
                   

                    For i = 1 To UBound(va, 1)
                        d(va(i, 1) & " " & ChrW(8213) & " " & va(i, 2)) = Empty 'convert number to text, 1D  array, Lbound = 0
                    Next

                Else
                    Do
                    c.Copy
                      DoEvents
                    obj.GetFromClipboard
                    tx = obj.GetText
                    Loop Until tx <> Empty

                    obj.GetFromClipboard
                    tx = obj.GetText
                   
                    For Each x In Split(tx, vbCrLf)
                        d(CStr(x)) = Empty 'convert number to text, 1D  array, Lbound = 0
                    Next
                End If
             End If
               
    Else
        If Not c Is Nothing Then

            vb = c.Value
            If Not IsArray(vb) Then
                    ReDim vb(0 To 0): vb(0) = c.Value
            End If
        Else 'if formula doesn't return a range
            If Left(cf, 1) = "=" Then GoTo skip  'if the formula doesn't return a range
            vb = (Split(cf, Application.International(xlListSeparator))) 'if the list is a string
        End If
        
         Set d = CreateObject("scripting.dictionary"): d.CompareMode = vbTextCompare
            For Each x In vb
                d(CStr(x)) = Empty 'convert number to text, 1D  array, Lbound = 0
            Next
           
    End If
           
           
'            vList becomes unique, sorted & has no blank
            If d.Exists("") Then d.Remove ""
            vList = d.keys '1D array, Lbound = 0
            d.RemoveAll
            If UBound(vList) > 0 Then Call QuickSort(vList, LBound(vList), UBound(vList))
       
    With ComboBox1
       
        .MatchEntry = fmMatchEntryNone
        .Value = ""
        .List = toList(vList)

    End With

'Application.StatusBar = Timer - t
Exit Sub
skip:
On Error GoTo 0
       MsgBox msg: wFlag = True

End Sub
 
Upvote 0
@roykana
  1. Note: you need to add the reference “Microsoft Forms 2.0 Object Library” (to work with clipboard)
    And this is how:
    Open your VBA editor.
    Click Tools > References.
    Check the box next to “Microsoft Forms 2.0 Object Library.”


  2. This method works only if there are no cell that has multiple lines, otherwise it won't work correctly.
  3. This code is faster than the earlier code but with 350K records, you still need few seconds to display the combobox.
  4. Replace "Private Sub ComboBox1_Enter()" with this:
VBA Code:
Private Sub ComboBox1_Enter()
Dim x, vb, ary
Dim c As Range, g As Range
Dim cf As String, msg As String
Dim i As Long, h As Long

cf = ActiveCell.Validation.Formula1

't = Timer
msg = "Can't get the range as the list source from data validation formula." & vbLf & "Please, check the formula:" _
            & vbLf & cf
      
        wFlag = False

        On Error Resume Next
        Set c = Evaluate(cf)
        On Error GoTo 0
      
        On Error GoTo skip
      
    If UCase(Left(cf, 5)) = "=CCTA" Then 'if the name range start with "CCTA"
             If Not c Is Nothing Then
           
                Dim obj As New DataObject
                Dim tx As String, z As String
                Dim va, arz, k As Long
           
            If c.Parent.FilterMode = True Then
                    c.Parent.ShowAllData
            End If
             Set d = CreateObject("scripting.dictionary"): d.CompareMode = vbTextCompare

                If cf = "=CCTA_X" Then
                  
                    ReDim va(1 To c.Cells.Count, 1 To 2)
                    Do
                    c.Resize(, 2).Copy
                      DoEvents
                    obj.GetFromClipboard
                    tx = obj.GetText
                    Loop Until tx <> Empty
'                      Application.Wait Now + TimeValue("0:00:01")
                  

                    tx = vbTab & Replace(tx, vbCrLf, vbTab)
                    arz = Split(tx, vbTab)
                    For i = 1 To UBound(arz) - 2 Step 2
                        k = k + 1
                        va(k, 1) = CStr(arz(i))
                        va(k, 2) = arz(i + 1)
                    Next
                  

                    For i = 1 To UBound(va, 1)
                        d(va(i, 1) & " " & ChrW(8213) & " " & va(i, 2)) = Empty 'convert number to text, 1D  array, Lbound = 0
                    Next

                Else
                    Do
                    c.Copy
                      DoEvents
                    obj.GetFromClipboard
                    tx = obj.GetText
                    Loop Until tx <> Empty

                    obj.GetFromClipboard
                    tx = obj.GetText
                  
                    For Each x In Split(tx, vbCrLf)
                        d(CStr(x)) = Empty 'convert number to text, 1D  array, Lbound = 0
                    Next
                End If
             End If
              
    Else
        If Not c Is Nothing Then

            vb = c.Value
            If Not IsArray(vb) Then
                    ReDim vb(0 To 0): vb(0) = c.Value
            End If
        Else 'if formula doesn't return a range
            If Left(cf, 1) = "=" Then GoTo skip  'if the formula doesn't return a range
            vb = (Split(cf, Application.International(xlListSeparator))) 'if the list is a string
        End If
       
         Set d = CreateObject("scripting.dictionary"): d.CompareMode = vbTextCompare
            For Each x In vb
                d(CStr(x)) = Empty 'convert number to text, 1D  array, Lbound = 0
            Next
          
    End If
          
          
'            vList becomes unique, sorted & has no blank
            If d.Exists("") Then d.Remove ""
            vList = d.keys '1D array, Lbound = 0
            d.RemoveAll
            If UBound(vList) > 0 Then Call QuickSort(vList, LBound(vList), UBound(vList))
      
    With ComboBox1
      
        .MatchEntry = fmMatchEntryNone
        .Value = ""
        .List = toList(vList)

    End With

'Application.StatusBar = Timer - t
Exit Sub
skip:
On Error GoTo 0
       MsgBox msg: wFlag = True

End Sub
@Akuini
It went perfectly
if the position of the item column before the code column as in the picture below then I should change your code in which position?

Capture22012022.JPG
 
Upvote 0
@roykana
Sorry for the late reply.
Try this:
  1. If the CODE is on the left then create a named range "CCTA_X1", refer to the range (list) where CODE is located.
  2. If the CODE is on the right then create a named range "CCTA_X2", refer to the range (list) where CODE is located.
  3. Use the named range in the data validation.
  4. Replace "Private Sub ComboBox1_Enter()" & "Sub insertValue(tx As String)" with this:
VBA Code:
Private Sub ComboBox1_Enter()
Dim x, vb, ary
Dim c As Range, g As Range
Dim cf As String, msg As String
Dim i As Long, h As Long

cf = ActiveCell.Validation.Formula1

't = Timer
msg = "Can't get the range as the list source from data validation formula." & vbLf & "Please, check the formula:" _
            & vbLf & cf
       
        wFlag = False

        On Error Resume Next
        Set c = Evaluate(cf)
        On Error GoTo 0
       
        On Error GoTo skip
       
    If UCase(Left(cf, 5)) = "=CCTA" Then 'if the name range start with "CCTA"
             If Not c Is Nothing Then
            
                Dim obj As New DataObject
                Dim tx As String, z As String
                Dim va, arz, k As Long
            
            If c.Parent.FilterMode = True Then
                    ActiveSheet.ShowAllData
            End If
             Set d = CreateObject("scripting.dictionary"): d.CompareMode = vbTextCompare

                If UCase(Left(cf, 7)) = "=CCTA_X" Then

                    ReDim va(1 To c.Cells.Count, 1 To 2)

                    If cf = "=CCTA_X1" Then
                        Set c = c.Resize(, 2)
                    ElseIf cf = "=CCTA_X2" Then
                        Set c = c.Offset(, -1).Resize(, 2)
                    End If
                   
                    Do
                    c.Copy
                      DoEvents
                    obj.GetFromClipboard
                    tx = obj.GetText
                    Loop Until tx <> Empty

                    tx = vbTab & Replace(tx, vbCrLf, vbTab)
                    arz = Split(tx, vbTab)
                   
                    If cf = "=CCTA_X1" Then
                        For i = 1 To UBound(arz) - 2 Step 2
                            k = k + 1
                            va(k, 1) = CStr(arz(i))
                            va(k, 2) = arz(i + 1)
                        Next
                    ElseIf cf = "=CCTA_X2" Then
                        For i = 1 To UBound(arz) - 2 Step 2
                            k = k + 1
                            va(k, 1) = CStr(arz(i + 1))
                            va(k, 2) = arz(i)
                        Next
                    End If
                   

                    For i = 1 To UBound(va, 1)
                        d(va(i, 1) & " " & ChrW(8213) & " " & va(i, 2)) = Empty 'convert number to text, 1D  array, Lbound = 0
                    Next

                Else
                    Do
                    c.Copy
                      DoEvents
                    obj.GetFromClipboard
                    tx = obj.GetText
                    Loop Until tx <> Empty

                    obj.GetFromClipboard
                    tx = obj.GetText
                   
                    For Each x In Split(tx, vbCrLf)
                        d(CStr(x)) = Empty 'convert number to text, 1D  array, Lbound = 0
                    Next
                End If
             End If
               
    Else
        If Not c Is Nothing Then
        c.AutoFilter
            vb = c.Value
            If Not IsArray(vb) Then
                    ReDim vb(0 To 0): vb(0) = c.Value
            End If
        Else 'if formula doesn't return a range
            If Left(cf, 1) = "=" Then GoTo skip  'if the formula doesn't return a range
            vb = (Split(cf, Application.International(xlListSeparator))) 'if the list is a string
        End If
        
         Set d = CreateObject("scripting.dictionary"): d.CompareMode = vbTextCompare
            For Each x In vb
                d(CStr(x)) = Empty 'convert number to text, 1D  array, Lbound = 0
            Next
           
    End If
           
           
'            vList becomes unique, sorted & has no blank
            If d.Exists("") Then d.Remove ""
            vList = d.keys '1D array, Lbound = 0
            d.RemoveAll
            If UBound(vList) > 0 Then Call QuickSort(vList, LBound(vList), UBound(vList))
       
    With ComboBox1
       
        .MatchEntry = fmMatchEntryNone
        .Value = ""
        .List = toList(vList)

    End With

'Application.StatusBar = Timer - t
Exit Sub
skip:
On Error GoTo 0
       MsgBox msg: wFlag = True

End Sub

VBA Code:
Sub insertValue(tx As String)
Dim c As Range, cf As String

'insert combobox value into the active cell
    If IsNumeric(Application.Match(tx, vList, 0)) Or tx = "" Then
        Application.EnableEvents = False
            If UCase(Left(ActiveCell.Validation.Formula1, 5)) = "=CCTA" Then
                cf = ActiveCell.Validation.Formula1
                If UCase(Left(cf, 7)) = "=CCTA_X" Then
                    tx = Split(ComboBox1.Value, " " & ChrW(8213) & " ")(0)
                End If
                tx = "'" & tx
            End If

            ActiveCell = tx
            Application.EnableEvents = True
            Unload Me
    Else
            MsgBox "Wrong input", vbCritical
    End If
End Sub
 
Upvote 0
@roykana
Sorry for the late reply.
Try this:
  1. If the CODE is on the left then create a named range "CCTA_X1", refer to the range (list) where CODE is located.
  2. If the CODE is on the right then create a named range "CCTA_X2", refer to the range (list) where CODE is located.
  3. Use the named range in the data validation.
  4. Replace "Private Sub ComboBox1_Enter()" & "Sub insertValue(tx As String)" with this:
VBA Code:
Private Sub ComboBox1_Enter()
Dim x, vb, ary
Dim c As Range, g As Range
Dim cf As String, msg As String
Dim i As Long, h As Long

cf = ActiveCell.Validation.Formula1

't = Timer
msg = "Can't get the range as the list source from data validation formula." & vbLf & "Please, check the formula:" _
            & vbLf & cf
     
        wFlag = False

        On Error Resume Next
        Set c = Evaluate(cf)
        On Error GoTo 0
     
        On Error GoTo skip
     
    If UCase(Left(cf, 5)) = "=CCTA" Then 'if the name range start with "CCTA"
             If Not c Is Nothing Then
          
                Dim obj As New DataObject
                Dim tx As String, z As String
                Dim va, arz, k As Long
          
            If c.Parent.FilterMode = True Then
                    ActiveSheet.ShowAllData
            End If
             Set d = CreateObject("scripting.dictionary"): d.CompareMode = vbTextCompare

                If UCase(Left(cf, 7)) = "=CCTA_X" Then

                    ReDim va(1 To c.Cells.Count, 1 To 2)

                    If cf = "=CCTA_X1" Then
                        Set c = c.Resize(, 2)
                    ElseIf cf = "=CCTA_X2" Then
                        Set c = c.Offset(, -1).Resize(, 2)
                    End If
                 
                    Do
                    c.Copy
                      DoEvents
                    obj.GetFromClipboard
                    tx = obj.GetText
                    Loop Until tx <> Empty

                    tx = vbTab & Replace(tx, vbCrLf, vbTab)
                    arz = Split(tx, vbTab)
                 
                    If cf = "=CCTA_X1" Then
                        For i = 1 To UBound(arz) - 2 Step 2
                            k = k + 1
                            va(k, 1) = CStr(arz(i))
                            va(k, 2) = arz(i + 1)
                        Next
                    ElseIf cf = "=CCTA_X2" Then
                        For i = 1 To UBound(arz) - 2 Step 2
                            k = k + 1
                            va(k, 1) = CStr(arz(i + 1))
                            va(k, 2) = arz(i)
                        Next
                    End If
                 

                    For i = 1 To UBound(va, 1)
                        d(va(i, 1) & " " & ChrW(8213) & " " & va(i, 2)) = Empty 'convert number to text, 1D  array, Lbound = 0
                    Next

                Else
                    Do
                    c.Copy
                      DoEvents
                    obj.GetFromClipboard
                    tx = obj.GetText
                    Loop Until tx <> Empty

                    obj.GetFromClipboard
                    tx = obj.GetText
                 
                    For Each x In Split(tx, vbCrLf)
                        d(CStr(x)) = Empty 'convert number to text, 1D  array, Lbound = 0
                    Next
                End If
             End If
             
    Else
        If Not c Is Nothing Then
        c.AutoFilter
            vb = c.Value
            If Not IsArray(vb) Then
                    ReDim vb(0 To 0): vb(0) = c.Value
            End If
        Else 'if formula doesn't return a range
            If Left(cf, 1) = "=" Then GoTo skip  'if the formula doesn't return a range
            vb = (Split(cf, Application.International(xlListSeparator))) 'if the list is a string
        End If
      
         Set d = CreateObject("scripting.dictionary"): d.CompareMode = vbTextCompare
            For Each x In vb
                d(CStr(x)) = Empty 'convert number to text, 1D  array, Lbound = 0
            Next
         
    End If
         
         
'            vList becomes unique, sorted & has no blank
            If d.Exists("") Then d.Remove ""
            vList = d.keys '1D array, Lbound = 0
            d.RemoveAll
            If UBound(vList) > 0 Then Call QuickSort(vList, LBound(vList), UBound(vList))
     
    With ComboBox1
     
        .MatchEntry = fmMatchEntryNone
        .Value = ""
        .List = toList(vList)

    End With

'Application.StatusBar = Timer - t
Exit Sub
skip:
On Error GoTo 0
       MsgBox msg: wFlag = True

End Sub

VBA Code:
Sub insertValue(tx As String)
Dim c As Range, cf As String

'insert combobox value into the active cell
    If IsNumeric(Application.Match(tx, vList, 0)) Or tx = "" Then
        Application.EnableEvents = False
            If UCase(Left(ActiveCell.Validation.Formula1, 5)) = "=CCTA" Then
                cf = ActiveCell.Validation.Formula1
                If UCase(Left(cf, 7)) = "=CCTA_X" Then
                    tx = Split(ComboBox1.Value, " " & ChrW(8213) & " ")(0)
                End If
                tx = "'" & tx
            End If

            ActiveCell = tx
            Application.EnableEvents = True
            Unload Me
    Else
            MsgBox "Wrong input", vbCritical
    End If
End Sub
@Akuini
Thank you very much for your reply. You're the best
It went perfectly.

thanks
roykana
 
Upvote 0
Hi Akuini,

despite of I try following your instructions , but I don't know how deal with your tool . I checked the tool is entered in adds in as in picture and create datavalidation and press alt+right but nothing happens.
1.PNG
 
Upvote 0
I checked the tool is entered in adds in as in picture and create datavalidation and press alt+right but nothing happens.
Not sure what happen.
  1. Does the data validation work normal?
  2. Can you give me an example of the data validation formula you're using?
  3. Open the VBE window, see if there's "vbaproject(Search_deList)".

deLIst vbaprojrct.jpg
 
Upvote 0
it doesn't show at all .
I'm not using Excel 2010, so I don't know how to check it. Probably it has something to do with Trusted Location.
Try putting the add-in in Trusted Location.
trusted location 1.jpg
 
Upvote 0
I created an add-in called “Search deList”, and I share it as a freeware.
Its function is to speed up searching in data validation list. In any cell that has data validation (with List type) pressing ALT+RIGHT will open a Userform with a combobox. You can type multiple keywords (separated by a space) in the combobox and the list will be narrowed down as you type.
I’d be appreciate if anyone can test this add-in to find any bugs or just suggesting ideas to improve its functionality.
Also, the code is not protected by password, so if anyone needs to change or add specific feature or behavior then feel free to amend the code, and if you need help for that I’ll help if I can.

How it works:
  • In any cell that has data validation (with List type) pressing ALT+RIGHT will open a Userform with a combobox.
  • Type some keywords to search, separated by a space, e.g "ma la"
  • The list will be narrowed down as you type.
  • The search ignores the keywords order, so the keyword "ma la" would match "Maryland" and "Alabama".
  • You can use up-down arrow to select an item, then hit ENTER, the selected item will be inserted into the cell, and the userform will be closed.
  • You can also use single-click to select an item, then DOUBLE-CLICK inside the box, the selected item will be inserted into the cell, and the userform will be closed.
  • To leave the combobox without inserting its value to the activecell: hit TAB or ESC
  • Numeric values in the list will be treated as text.
  • In the Status Bar you can see how many unique items are found & displayed.
  • You don't need VBA (except if you want to use additional feature as I explain below), so you can save your workbook as .xlsx.
Additional feature :
If you want, you can also activate the userform by double-clicking a cell, but you need VBA to do that. Here’s how:
Copy-paste this code into Thisworkbook code window of your workbook:
VBA Code:
Private Sub Workbook_SheetBeforeDoubleClick(ByVal Sh As Object, ByVal Target As Range, Cancel As Boolean)
If TypeName(Selection) = "Range" Then
    Dim v
    On Error Resume Next
        v = ActiveCell.Validation.Type
    On Error GoTo 0
    'if activecell has data validation type 3
    'run "Search deList" add-in by doubke-clicking a cell
    If v = 3 Then Cancel = True: Application.Run ("toShow__dheeDAV")
End If
End Sub
Now, in every sheet, double-clicking any cell that has data validation (with List type) will open the Userform.

Image:

View attachment 52701

How to use it:
  1. Install the add-in. This article explains how to install an add-in: How to install or uninstall an Excel Add-in - Excel Off The Grid
  2. Open any workbook that has data validation (with list type).
  3. In any cell that has data validation, pressing ALT+RIGHT will open a Userform with a combobox.
  4. Play with it & see how it works.
NOTES:
  • This add-in also works on dependent data validation.
  • It works on large list (I tested it on 100K rows of data).
  • One caveat of using macro is when macro changes/writes something on sheet it will delete Undo Stack, so at that time you can't use UNDO. In this case it happens every time the combobox value is inserted into the active cell.

Search_deList_v1 add-in:
Search_deList_v1

Regards,
Akuini
Love you bro, thank you so much
Jesus, plz bless him
 
Upvote 0

Forum statistics

Threads
1,223,948
Messages
6,175,571
Members
452,652
Latest member
eduedu

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