Excel search function issues

davmmcdonald

New Member
Joined
Aug 10, 2016
Messages
2
I am having a bit of trouble with a search function that I'm trying to implement in a Excel spreadsheet. I followed a tutorial online and adapted it to work for my uses. Unfortunately, it only can search and filter columns A - E. I updated the data range to include my whole sheet (A6:S100), but I can't figure out how to edit the filter field. See code below. Thanks in advance!

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


Dim myButton As OptionButton
Dim SearchString As String
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("A6:S100") '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
   
'Determine if user is searching for number or text
  If IsNumeric(mySearch) = True Then
    SearchString = "=" & mySearch
  Else
    SearchString = "=*" & mySearch & "*"
  End If
    
'Loop Through Option Buttons
  For Each myButton In sht.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:=SearchString, _
    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

 

Excel Facts

Get help while writing formula
Click the italics "fx" icon to the left of the formula bar to open the Functions Arguments dialog. Help is displayed for each argument.
That code as is worked for me. Are all of your option buttons Form Control option buttons?

Does
?activesheet.OptionButtons.count
in the immediate pane return the number of option buttons you have in the worksheet?

Does the visible text for each option button exactly match the row 6 header column text (not case sensitive, but extra/missing spaces or hard returns in row six will keep a match from happening
 
Upvote 0
For dates you should use CDate(year(searchdate) , month(searchdate), day(searchDate)) as your search date value. If the dates you are searching come from another system, be sure they are integer values. 8/18/2016 13:55:53 would show up as 8/18/2016 in a field that was formatted as m/d/yyyy and searching for cdate(2016,18,8) would not find it. I create a helper column with INT(date column) values then replace the original date column with the values of the helper column.

Problems also occur when you have both "25" and 25 in your columns. I generally execute pastespecial addition 0 in vba on numeric columns I am searching then set the numberformat to what I want to display.
 
Upvote 0

Forum statistics

Threads
1,214,641
Messages
6,120,694
Members
448,979
Latest member
DET4492

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