How to Create a filtering search box with more than 1 key word

PritishS

Board Regular
Joined
Dec 29, 2015
Messages
119
Office Version
  1. 2007
Platform
  1. Windows
Dear Sir/Madam,
Good Day!

My requirement is to make a filtering search box in my whroksheet so user can type desired word and it should appear with filtered row only.

I googled it and found a really helpful post from Mr. Chris Newman. This great code fulfilled my requirement 90%.
Here is the Link for anyone looking for something like this-
http://www.thespreadsheetguru.com/blog/2014/11/3/filtering-search-box

I modified this code to match my excel sheet. Here is the code. All credit goes to Mr. Newman,

Code:
Sub SearchBox()'PURPOSE: Filter Data on User-Determined Column & Text
'SOURCE: www.TheSpreadsheetGuru.com


Dim myButton As OptionButton
Dim MyVal As Long
Dim ButtonName As String
Dim sht As Worksheet
Dim myField As Long
Dim DataRange As Range
Dim mySearch As Variant
   
'Load Sheet into A Variable
  Set sht = ActiveSheet


'Unfilter Data (if necessary)
  On Error Resume Next
    sht.ShowAllData
  On Error GoTo 0
   
'Filtered Data Range (include column heading cells)
  Set DataRange = sht.Range("A3:D400000") 'Cell Range
  'Set DataRange = sht.ListObjects("Table1").Range 'Table


'Retrieve User's Search Input
  'mySearch = sht.Shapes("UserSearch").TextFrame.Characters.Text 'Control Form
  mySearch = sht.OLEObjects("UserSearch").Object.Text 'ActiveX Control
  'mySearch = sht.Range("A1").Value 'Cell Input


'Loop Through Option Buttons
  For Each myButton In ActiveSheet.OptionButtons
      If myButton.Value = 1 Then
        ButtonName = myButton.Text
        Exit For
      End If
  Next myButton
  
'Determine Filter Field
  On Error GoTo HeadingNotFound
    myField = Application.WorksheetFunction.Match(ButtonName, DataRange.Rows(1), 0)
  On Error GoTo 0
  
'Filter Data
  DataRange.AutoFilter _
    Field:=myField, _
    Criteria1:="*" & mySearch & "*", _
    Operator:=xlAnd
  
'Clear Search Field
  'sht.Shapes("UserSearch").TextFrame.Characters.Text = "" 'Control Form
  sht.OLEObjects("UserSearch").Object.Text = "" 'ActiveX Control
  'sht.Range("A1").Value = "" 'Cell Input


Exit Sub


'ERROR HANDLERS
HeadingNotFound:
  MsgBox "The column heading [" & ButtonName & "] was not found in cells " & DataRange.Rows(1).Address & ". " & _
    vbNewLine & "Please check for possible typos.", vbCritical, "Header Name Not Found!"
    
End Sub

This search criteria searches adjacent keywords of a defined column name. Ex:- In col-A there is sentence-'I have a Pen'. I can write in search box-'I','have','a pen','have a,'I have'. But If I enter 'I Pen' or 'have Pen', it's returning no result. Can anyone please guide me any modification which can be done in this code to match my requirement? Hoping for the best. Have a Nice Day!!
Regards,
PritishS
 
Hello Sir,
Good Day!

First of all I apologize for getting back late. I was outstation and couldn't access internet. Also sorry for bothering you again.
However I have tested your last suggestion too. But unfortunately the result it is providing is not up to mark.

Lets take a example- I have a table like this.

Description
Pritish has a red pen.
Sam has a red pen.
Hari has a yellow shoe.
Pat has red ball.
Robbie has a green pen
Maggie had a orange cap.

<tbody>
</tbody>

with your last suggested modification, if I enter key words with space -" Pritish Red pen", it is giving me a search result-

Description
Pritish has a red pen.
Sam has a red pen.
Pat has red ball.
Robbie has a green pen

<tbody>
</tbody>

Because it is setting 'True' to col-5 for all key word individully.

Though My expected result is-

Description
Pritish has a red pen.

<tbody>
</tbody>

This is possible with your first code, but problem is I have a filter on Col-Description and after running this code it is removing filter sign from the column. I understand it may be because we are using 'Advance Filter Method'.

In case of Code-3 with filtering col=5 with comma: It is working fine. But we need to enter 1 word at a time and press search. Like to get the result- 'Pritish has a red pen', my search words will be-

1. "Pen">click on Search

Description
Pritish has a red pen.
Sam has a red pen.
Robbie has a green pen

<tbody>
</tbody>

2. "Red">click on Search
Description
Pritish has a red pen.
Sam has a red pen.

<tbody>
</tbody>

3. "Pritish">click on Search

Description
Pritish has a red pen.

<tbody>
</tbody>

This is Okay to me at this stage. But I think I should restrict user with only one keyword at a time and I'll not allow 'Space' in Textbox(UserSearch) and if anyone tries to do that it will pop up restriction message.

Sir, you have helped me a lot and without it I couldn't go this far. but can you please suggest anything in this regards.
Wish you Very good day!!

Thanks & Regards,
PritishS
 
Upvote 0

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
Hello Sir,

Hope you are doing well.

I have decide to go with your suggested Code-3. I have restricted user from pressing 'Spacebar' in text box. If anyone needs the code. Also if anyone copy paste some text with 'Space', this code will remove space and paste value without text.

Paste the code in sheet module-

Code:
Public Sub UserSearch_Change()'One Keyword At a Time: Prevent User from pressing Spacebar
If InStr(UserSearch.Text, " ") > 0 Then
UserSearch.Text = Replace$(UserSearch.Text, " ", "")
'Now put the cursor back on the far right side.
UserSearch.SelStart = Len(UserSearch.Text)
End If
End Sub

Sir, I need a last favor. When search text does not match any result, it filtered to no result, then I click on 'RESET FILTER' Button to show all data.

Where can I place a message- "Your Search text is Invalid. Please click on 'RESET FILTER' Button to show all data again" in this code?

Thanks & Regards,

PritishS
 
Upvote 0
Sir, I need a last favor. When search text does not match any result, it filtered to no result, then I click on 'RESET FILTER' Button to show all data.

Where can I place a message- "Your Search text is Invalid. Please click on 'RESET FILTER' Button to show all data again" in this code?

This will not filter if there is no match. They won't have to reset.

Replace this...

Code:
            DataRange.AutoFilter Field:=FilterColumn, Criteria1:="True"

With this...
Code:
        [COLOR=darkblue]If[/COLOR] Application.CountIf(Columns(FilterColumn), [COLOR=darkblue]True[/COLOR]) [COLOR=darkblue]Then[/COLOR]
            DataRange.AutoFilter Field:=FilterColumn, Criteria1:="True"
        [COLOR=darkblue]Else[/COLOR]
            MsgBox "No match to your critera.", , "Filter Canceled"
        [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
 
Last edited:
Upvote 0
Dear Sir,

Thank You...Thank You...Thank You!! That's really cool :biggrin:. I made it working now. Additionally I have added one userform to show 'Record Searching...Please wait!!' which I load at the starting and unload at the ending using

Code:
    'Show Searching in Progress
       UserForm4.Show vbModeless
       UserForm4.Repaint

' Code for Searching component
   
   'Unload Notification of Price Updation
    UserForm4.Hide

Thank you very much for your help. Wish you a very good luck!! Have a nice day!!

Thanks & Regards,

PritishS
 
Upvote 0
Hello Sir,

It's again me :p. I did some modification to "search Col-A and Col-B both at a same time". I have used myField = 1 and myField = 2 as default.

Basically Steps are--

1. Enter search string in 'Search Box'.
2. Look into Col-A.
3. If Found then Stop.
4. Else go for Col-B.
5. If data found then filter and show result.
6. Else show msg to user-'No match to your criteria.'

Here is the code for the same. I did it completely like a novice. Can you please look into this and suggest me if I'm wrong in any way.
One doubt--
This will not filter if there is no match. They won't have to reset.
Replace this...
This is working fine. In my actual data table I have few other columns for user to search using filter dropdown. Problem scenario is--

1. Search valid string and it filters records for me.
2. Now I search filter into other column using filter drop down.
3. Then if I put some invalid string in to search box and click on search box then no data is showing. Like when we were using -
Code:
[COLOR=#333333]DataRange.AutoFilter Field:=FilterColumn, Criteria1:="True"[/COLOR]
.
4. Ideally it should show me --'No match to your criteria.'.
5. Is there anything I am missing.

My latest update--

Code:
Sub Text_SearchBox2()    'PURPOSE: Filter Data on User-Determined Column & Text
    
    Dim myButton  As OptionButton
    Dim ButtonName As String
    Dim sht       As Worksheet
    Dim myField   As Variant
    Dim mySearch  As String
    Dim vMySearch As Variant
    Dim DataRange As Range
    Dim Crit As Variant
    Dim cell As Range
    
   'Show updation is in Progress
      UserForm4.Show vbModeless
      UserForm4.Repaint
       
    'Helper column used to filter Search terms
    'Empty coluumn included in the Autofilter Range
    'Optional: column can be hidden
    Const FilterColumn As Long = 26
    
    'Load Sheet into A Variable
    Set sht = ActiveSheet
    
    'Filtered Data Range (include column heading cells)
    Set DataRange = sht.AutoFilter.Range    'Cell Range
    
    'Retrieve User's Search Input
    
    mySearch = sht.OLEObjects("UserSearch").Object.Text    'ActiveX Control
    If mySearch = "" Then MsgBox "Search box is empty", vbExclamation, "Invalid Search Criteria: PriceApp": Exit Sub


    
    'Loop Through Option Buttons
    'For Each myButton In ActiveSheet.OptionButtons
        'If myButton.Value = 1 Then
            'ButtonName = myButton.Text
            'Exit For
        'End If
    'Next myButton
    
    'Determine Filter column
    'myField = Application.Match(ButtonName, sht.AutoFilter.Range.Rows(1), 0)
    
    myField = 1    'First Searching Col-1 For testing
    
    If Not IsError(myField) Then
    
        Application.ScreenUpdating = False
        ActiveSheet.Unprotect Password:="password"
    
        'Split search tems by comma
        vMySearch = Split(Replace("*" & Application.Trim(mySearch) & "*", " ", "* *"), " ")
        
        For Each cell In DataRange.Columns(myField).SpecialCells(xlCellTypeVisible)
            For Each Crit In vMySearch
                If " " & LCase(cell.Value) & " " Like "* " & LCase(Application.Trim(Crit)) & " *" Then
                    Cells(cell.Row, FilterColumn).Value = True
                    Exit For
                Else
                    Cells(cell.Row, FilterColumn) = ""
                End If
            Next Crit
        Next cell
        
        'Filter Data
        'DataRange.AutoFilter Field:=FilterColumn, Criteria1:="True"
        
        'If no data no filter will be applied
        If Application.CountIf(Columns(FilterColumn), True) Then
            DataRange.AutoFilter Field:=FilterColumn, Criteria1:="True"
            
    'Hide Userform4
    UserForm4.Hide
    
    'Clear Search Field
    sht.OLEObjects("UserSearch").Object.Text = ""    'ActiveX Control
    Application.ScreenUpdating = True
    ActiveSheet.Protect Password:="password", DrawingObjects:=True, Contents:=True, Scenarios:=True, AllowFiltering:=True, UserInterfaceOnly:=True
    
    Else
        
  'If Not IsError(myField) Then
  
  myField = 2    '2nd column For testing
    
    If Not IsError(myField) Then
    
        'Application.ScreenUpdating = False
        'ActiveSheet.Unprotect Password:="password"
    
        'Split search tems by comma
        vMySearch = Split(Replace("*" & Application.Trim(mySearch) & "*", " ", "* *"), " ")
        
        For Each cell In DataRange.Columns(myField).SpecialCells(xlCellTypeVisible)
            For Each Crit In vMySearch
                If " " & LCase(cell.Value) & " " Like "* " & LCase(Application.Trim(Crit)) & " *" Then
                    Cells(cell.Row, FilterColumn).Value = True
                    Exit For
                Else
                    Cells(cell.Row, FilterColumn) = ""
                End If
            Next Crit
        Next cell
        
        'Filter Data
        'DataRange.AutoFilter Field:=FilterColumn, Criteria1:="True"
        'If no data no filter will be applied
        If Application.CountIf(Columns(FilterColumn), True) Then
            DataRange.AutoFilter Field:=FilterColumn, Criteria1:="True"
         Else
            MsgBox "No match to your critera.", , "Filter Canceled"
        End If
        
'Unload Notification of Price Updation
 UserForm4.Hide


        'Clear Search Field
        
        sht.OLEObjects("UserSearch").Object.Text = ""    'ActiveX Control


        Application.ScreenUpdating = True
        ActiveSheet.Protect Password:="password", DrawingObjects:=True, Contents:=True, Scenarios:=True, AllowFiltering:=True, UserInterfaceOnly:=True
    Else
        MsgBox "The column heading [" & ButtonName & "] was not found in cells " & DataRange.Rows(1).Address & ". " & _
               vbNewLine & "Please check for possible typos.", vbCritical, "Header Name Not Found!"
    End If
    End If
    End If
End Sub

and in same module below above code--

Code:
Sub SearchReset()
    Const FilterColumn As Long = 26
    
    ActiveSheet.Unprotect Password:="password"
    
    ActiveSheet.Columns(FilterColumn).Replace What:="TRUE", _
                                              Replacement:="", _
                                              SearchOrder:=xlByRows, _
                                              MatchCase:=False
    
    ActiveSheet.AutoFilter.Range.AutoFilter Field:=FilterColumn, Criteria1:=""
    
    ActiveSheet.Protect Password:="password", DrawingObjects:=True, Contents:=True, Scenarios:=True, AllowFiltering:=True, UserInterfaceOnly:=True
    
End Sub

This code is working as per my requirement. Can you please guide me if this needs to be written in better way.

Thank You very Much.

PritishS
 
Upvote 0
Code:
[color=darkblue]Sub[/color] Text_SearchBox2()    [color=green]'PURPOSE: Filter Data on User-Determined Column & Text[/color]
    
     [color=darkblue]Dim[/color] myButton  [color=darkblue]As[/color] OptionButton
     [color=darkblue]Dim[/color] ButtonName [color=darkblue]As[/color] [color=darkblue]String[/color]
     [color=darkblue]Dim[/color] sht       [color=darkblue]As[/color] Worksheet
     [color=darkblue]Dim[/color] myField   [color=darkblue]As[/color] [color=darkblue]Variant[/color]
     [color=darkblue]Dim[/color] mySearch  [color=darkblue]As[/color] [color=darkblue]String[/color]
     [color=darkblue]Dim[/color] vMySearch [color=darkblue]As[/color] [color=darkblue]Variant[/color]
     [color=darkblue]Dim[/color] DataRange [color=darkblue]As[/color] Range
     [color=darkblue]Dim[/color] Crit      [color=darkblue]As[/color] [color=darkblue]Variant[/color]
     [color=darkblue]Dim[/color] cell      [color=darkblue]As[/color] Range
    
     [color=green]'Helper column used to filter Search terms[/color]
     [color=green]'Empty coluumn included in the Autofilter Range[/color]
     [color=green]'Optional: column can be hidden[/color]
     [color=darkblue]Const[/color] FilterColumn [color=darkblue]As[/color] [color=darkblue]Long[/color] = 26
    
     [color=green]'Load Sheet into A Variable[/color]
     [color=darkblue]Set[/color] sht = ActiveSheet
    
     [color=green]'Filtered Data Range (include column heading cells)[/color]
     [color=darkblue]Set[/color] DataRange = sht.AutoFilter.Range    [color=green]'Cell Range[/color]
    
     [color=green]'Retrieve User's Search Input[/color]
     mySearch = sht.OLEObjects("UserSearch").Object.Text    [color=green]'ActiveX Control[/color]
     [color=darkblue]If[/color] mySearch = "" [color=darkblue]Then[/color] MsgBox "Search box is empty", vbExclamation, "Invalid Search Criteria: PriceApp": [color=darkblue]Exit[/color] [color=darkblue]Sub[/color]
     
     [color=green]'Split search terms by comma[/color]
     vMySearch = Split(Replace("*" & Application.Trim(mySearch) & "*", " ", "* *"), " ")
     
[color=green]'    Loop Through Option Buttons[/color]
[color=green]'    For Each myButton In ActiveSheet.OptionButtons[/color]
[color=green]'        If myButton.Value = 1 Then[/color]
[color=green]'            ButtonName = myButton.Text[/color]
[color=green]'            Exit For[/color]
[color=green]'        End If[/color]
[color=green]'    Next myButton[/color]
[color=green]'    Determine Filter column[/color]
[color=green]'    myField = Application.Match(ButtonName, sht.AutoFilter.Range.Rows(1), 0)[/color]
[color=green]'    If IsError(myField) Then[/color]
[color=green]'        MsgBox "The column heading [" & ButtonName & "] was not found in cells " & DataRange.Rows(1).Address & ". " & _
'               vbNewLine & "Please check for possible typos.", vbCritical, "Header Name Not Found!"[/color]
[color=green]'        Exit Sub[/color]
[color=green]'    End If[/color]
    
    [B] myField = 1 [color=green]'Search column A[/color][/B]
    
     Application.ScreenUpdating = [color=darkblue]False[/color]
     ActiveSheet.Unprotect Password:="password"
     
     [color=green]'Show updation is in Progress[/color]
     UserForm4.Show vbModeless
     User[color=darkblue]For[/color]m4.Repaint
    
     [color=darkblue]For[/color] [color=darkblue]Each[/color] cell [color=darkblue]In[/color] DataRange.Columns(myField).SpecialCells(xlCellTypeVisible)
         [color=darkblue]For[/color] [color=darkblue]Each[/color] Crit [color=darkblue]In[/color] vMySearch
[B]             [color=green]'Search column 1 and column 2;   cell.value and cell.offset(,1).Value[/color]
             [color=darkblue]If[/color] " " & LCase(cell.Value) & " " [color=darkblue]Like[/color] "* " & LCase(Application.Trim(Crit)) & " *" _
             [color=darkblue]Or[/color] " " & LCase(cell.Offset(, 1).Value) & " " [color=darkblue]Like[/color] "* " & LCase(Application.Trim(Crit)) & " *" [color=darkblue]Then[/color][/B]
                 Cells(cell.Row, FilterColumn).Value = [color=darkblue]True[/color]
                 [color=darkblue]Exit[/color] For
             [color=darkblue]Else[/color]
                 Cells(cell.Row, FilterColumn) = ""
             [color=darkblue]End[/color] [color=darkblue]If[/color]
         [color=darkblue]Next[/color] Crit
     [color=darkblue]Next[/color] cell
     
     [color=green]'Hide Userform4[/color]
     UserForm4.Hide
    
     [color=green]'Filter Data. If no data no filter will be applied[/color]
     [color=darkblue]If[/color] Application.CountIf(Columns(FilterColumn), [color=darkblue]True[/color]) [color=darkblue]Then[/color]
         DataRange.AutoFilter field:=FilterColumn, Criteria1:="True"
     [color=darkblue]Else[/color]
         MsgBox "No match to your critera.", , "Filter Canceled"
     [color=darkblue]End[/color] [color=darkblue]If[/color]
    
     [color=green]'Clear Search Field[/color]
     sht.OLEObjects("UserSearch").Object.Text = ""            [color=green]'ActiveX Control[/color]
     Application.ScreenUpdating = [color=darkblue]True[/color]
     ActiveSheet.Protect Password:="password", DrawingObjects:=True, Contents:=True, Scenarios:=True, AllowFiltering:=True, UserInterfaceOnly:=True
    
[color=darkblue]End[/color] [color=darkblue]Sub[/color]
 
Upvote 0
Hello Sir!

Thank you once again. This method is very nice for searching in Col-A and Col-B at a time. This is doing the magic

Code:
 'Search column 1 and column 2;   cell.value and cell.offset(,1).Value
             If " " & LCase(cell.Value) & " " Like "* " & LCase(Application.Trim(Crit)) & " *" _
             Or " " & LCase(cell.Offset(, 1).Value) & " " Like "* " & LCase(Application.Trim(Crit)) & " *" Then

Just wondering if I add
Code:
Or " " & LCase(cell.Offset(, 2).Value) & " " Like "* " & LCase(Application.Trim(Crit)) & " *"
to your code, will it include Col-C as well?
and like that can I add the numbers of columns I want to search using "cell.Offset(, 3/4/5/6/7 etc.).Value"?

You are really awesome. My RESPECT!! Have a nice weekend!!

Thanks & Regards,

PritishS
 
Upvote 0
And answer for my last question is 'YES"...:biggrin:

I Just tested is this and it worked..one can use "cell.Offset(, (No.of Col-1)).Value" to include which column he wants to search.

Sir, I need a last favor. When search text does not match any result, it filtered to no result, then I click on 'RESET FILTER' Button to show all data.

Where can I place a message- "Your Search text is Invalid. Please click on 'RESET FILTER' Button to show all data again" in this code?


Can I do it anyway? Because as I mentioned below,
This is working fine. In my actual data table I have few other columns for user to search using filter dropdown. Problem scenario is--

1. Search valid string and it filters records for me.
2. Now I search filter into other column using filter drop down.
3. Then if I put some invalid string in to search box and click on search box then no data is showing. Like when we were using -
4. Ideally it should show me --'No match to your criteria.'.
5. Is there anything I am missing.

with this criteria, still there is chance to hide entire table if some 'Invalid String' entered by user.
Just in case anyone do the mistake I want to guide them what to do if you want to do show all data.

Thanks & Regards,

PritishS

 
Upvote 0
Hello Sir,

Thank you very much for everything!!:)

For this question,

with this criteria, still there is chance to hide entire table if some 'Invalid String' entered by user.
Just in case anyone do the mistake I want to guide them what to do if you want to do show all data.

I just took a simple method. I have added a sentence in 2 row after last row saying- "CLICK ON REST BUTTON TO SHOW ALL DATA". So whenever that case happens, my instruction is now clearly visible to User that what he/she has to do after that.

Thank you very much once again. Learnt a lot from you. Good Luck.

Thanks & Regards,

PritishS
 
Upvote 0

Forum statistics

Threads
1,215,107
Messages
6,123,126
Members
449,097
Latest member
mlckr

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