Create a Searchable Drop Down List in Excel

,

This post will guide you how to create a searchable drop down list in Excel. How do I create an excel drop down list with search suggestions in Excel. How to search data validation drop down list in Excel.

Create a Searchable Drop Down List


If you want to create a searchable drop down list in Excel, you just need to do the following steps:

#1 go to DEVELOPER tab, click Insert command Under Controls group, and select Combo Box button from the ActiveX Controls section.

#2 Move your cusor to the worksheet and draw the combo box.

#3 right click on the combo Box and select Properties from the popup menu list. And the properties dialog will open.

#4 In the Properties dialog box, you need to make the below changes:

set AutoWordSelect as False

set Linked Cell as A9

set ListFillRange as DropDownList

set MatchEntry as 2

 

#5 close the Properties dialog box.

#6 Go to Developer tab and click on Design Mode to close the design mode.

#7 select a blank cell B1 and then copy and paste the following formual into the formula box, and then press Enter key in your keyboard. and drag the AutoFill Handle down other cells to apply this formula.

=–ISNUMBER(IFERROR(SEARCH($A$9,A1,1),””))

 

#8 select a blank cell C1 and then type the following formula into the formula box, and then press enter key. and then drag the AutoFill Handle down other cells.

=IF(B1=1,COUNTIF($B$1:B1,1),””)

 

#9 select a blank cell D1, and type the following formula into the formula box. and press Enter key. and then drag the AutoFill Handle over other cells.

 

=IFERROR(INDEX($A$1:$A$6,MATCH(ROWS($C$1:C1),$C$1:$C$6,0)),””)

#10 go to FORMULAS tab, click Name Manager command. and the Name Manager dialog box will open.

#11 click New button in the Name Manager dialog box. and type DropDownList as the Name Field. and type the below formula into the refers to Field.

=$D$1:INDEX($D$1:$D$6,MAX($C$1:$C$6),1)

 

#12 go to DEVELOPER tab, click Design MODE to enable the design mode.

#13 right click on the worksheet tab and select View Code from the popup menu list.

#14 copy and paste the following code into the VBA code Window.

Private Sub ComboBox1_GotFocus()
   ComboBox1.ListFillRange = "DropDownList"
   Me.ComboBox1.DropDown
End Sub

#15 lets see the result.

 

Leave a Reply