Search and display row with results in Listbox

sharky12345

Well-known Member
Joined
Aug 5, 2010
Messages
3,404
Office Version
  1. 2016
Platform
  1. Windows
I've come across this as a method for searching a sheet for a value and displaying the results in a Listbox;

Code:
Sub FindAllMatches()
Dim SearchRange As Range
Dim FindWhat As Variant
Dim FoundCells As Range
Dim FoundCell As Range
Dim arrResults() As Variant
Dim lFound As Long
If Len(Me.Controls.Item("TextBox_Find").Value) > 1 Then
Set SearchRange = ActiveSheet.UsedRange.Cells
FindWhat = Me.Controls.Item("TextBox_Find").Value
Set FoundCells = FindAll(SearchRange:=SearchRange, FindWhat:=FindWhat, LookIn:=xlValues, LookAt:=xlPart, SearchOrder:=xlByColumns, MatchCase:=False, BeginsWith:=vbNullString, EndsWith:=vbNullString, BeginEndCompare:=vbTextCompare)
If FoundCells Is Nothing Then
ReDim arrResults(1 To 1, 1 To 2)
arrResults(1, 1) = "No Results"
Else
ReDim arrResults(1 To FoundCells.Count, 1 To 2)
lFound = 1
For Each FoundCell In FoundCells
arrResults(lFound, 1) = FoundCell.Value
arrResults(lFound, 2) = FoundCell.Address
lFound = lFound + 1
Next FoundCell
End If
Me.Controls.Item("ListBox_Results").List = arrResults
Else
Me.Controls.Item("ListBox_Results").Clear
End If
End Sub

I'd like some help to tweak it if someone can assist please...

What I need is for the Listbox to display the values from Columns A:G in the listbox if the item searched for has been found in each row.

For example, if I searched for the value 'Email' and that appeared in cell A20 and D45 then I'd want rows 20 and 45 to appear in the Listbox.

Makes sense?
 

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
See if this does it. I'm also posting Chip's code for completeness:

Code:
Sub FindAllMatches()
Dim SearchRange As Range, FindWhat, FoundCells As Range, FoundCell As Range, arrResults(), lFound&, i%
Me.ListBox_Results.ColumnCount = 7
Me.ListBox_Results.ColumnWidths = 20
If Len(Me.Controls.Item("TextBox_Find").Value) > 1 Then
    Set SearchRange = ActiveSheet.UsedRange.Cells
    FindWhat = Me.Controls.Item("TextBox_Find").Value
    Set FoundCells = FindAll(SearchRange:=SearchRange, FindWhat:=FindWhat, LookIn:=xlValues, LookAt:=xlPart, _
    SearchOrder:=xlByColumns, MatchCase:=False, BeginsWith:=vbNullString, EndsWith:=vbNullString, BeginEndCompare:=1)
    If FoundCells Is Nothing Then
        ReDim arrResults(1 To 1, 1 To 7)
        arrResults(1, 1) = "No Results"
    Else
        ReDim arrResults(1 To FoundCells.Count, 1 To 7)
        lFound = 1
        For Each FoundCell In FoundCells
            For i = 1 To 7
               arrResults(lFound, i) = Cells(FoundCell.Row, i)
            Next
            lFound = lFound + 1
        Next
    End If
    Me.Controls.Item("ListBox_Results").List = arrResults
Else
    Me.Controls.Item("ListBox_Results").Clear
End If
End Sub

Code:
Option Compare Text
''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
' modFindAll
' By Chip Peasron, [EMAIL="chip@cpearson.com"]chip@cpearson.com[/EMAIL]. [URL="http://www.cpearson.com"]Default Excel Redirect[/URL]
' Web page for this module: [URL="http://www.cpearson.com/Excel/FindAll.aspx"]FindAll VBA Function[/URL]
' 24-October-2007
' Revised 5-January-2010
' This module is described at [URL="http://www.cpearson.com/Excel/FindAll.aspx"]FindAll VBA Function[/URL]
' Requires Excel 2000 or later.
'
' This module contains two functions, FindAll and FindAllOnWorksheets that are use
' to find values on a worksheet or multiple worksheets.
'
' FindAll searches a range and returns a range containing the cells in which the
'   searched for text was found. If the string was not found, it returns Nothing.

' FindAllOnWorksheets searches the same range on one or more workshets. It return
'   an array of ranges, each of which is the range on that worksheet in which the
'   value was found. If the value was not found on a worksheet, that worksheet's
'   element in the returned array will be Nothing.
'
' In both functions, the parameters that control the search have the same meaning
' and effect as they do in the Range.Find method.
' This module is compatible with 64-bit Excel.
''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''

Function FindAll(SearchRange As Range, _
                FindWhat As Variant, _
               Optional LookIn As XlFindLookIn = xlValues, _
                Optional LookAt As XlLookAt = xlWhole, _
                Optional SearchOrder As XlSearchOrder = xlByRows, _
                Optional MatchCase As Boolean = False, _
                Optional BeginsWith As String = vbNullString, _
                Optional EndsWith As String = vbNullString, _
                Optional BeginEndCompare As VbCompareMethod = vbTextCompare) As Range
'''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
' FindAll
' This searches the range specified by SearchRange and returns a Range object
' that contains all the cells in which FindWhat was found. The search parameters to
' this function have the same meaning and effect as they do with the
' Range.Find method. If the value was not found, the function return Nothing. If
' BeginsWith is not an empty string, only those cells that begin with BeginWith
' are included in the result. If EndsWith is not an empty string, only those cells
' that end with EndsWith are included in the result. Note that if a cell contains
' a single word that matches either BeginsWith or EndsWith, it is included in the
' result.  If BeginsWith or EndsWith is not an empty string, the LookAt parameter
' is automatically changed to xlPart. The tests for BeginsWith and EndsWith may be
' case-sensitive by setting BeginEndCompare to vbBinaryCompare. For case-insensitive
' comparisons, set BeginEndCompare to vbTextCompare. If this parameter is omitted,
' it defaults to vbTextCompare. The comparisons for BeginsWith and EndsWith are
' in an OR relationship. That is, if both BeginsWith and EndsWith are provided,
' a match if found if the text begins with BeginsWith OR the text ends with EndsWith.
'''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''

Dim FoundCell As Range
Dim FirstFound As Range
Dim LastCell As Range
Dim ResultRange As Range
Dim XLookAt As XlLookAt
Dim Include As Boolean
Dim CompMode As VbCompareMethod
Dim Area As Range
Dim MaxRow As Long
Dim MaxCol As Long
Dim BeginB As Boolean
Dim EndB As Boolean


CompMode = BeginEndCompare
If BeginsWith <> vbNullString Or EndsWith <> vbNullString Then
    XLookAt = xlPart
Else
    XLookAt = LookAt
End If

' this loop in Areas is to find the last cell
' of all the areas. That is, the cell whose row
' and column are greater than or equal to any cell
' in any Area.
For Each Area In SearchRange.Areas
    With Area
        If .Cells(.Cells.Count).Row > MaxRow Then
            MaxRow = .Cells(.Cells.Count).Row
        End If
        If .Cells(.Cells.Count).Column > MaxCol Then
            MaxCol = .Cells(.Cells.Count).Column
        End If
    End With
Next Area
Set LastCell = SearchRange.Worksheet.Cells(MaxRow, MaxCol)

'On Error Resume Next
On Error GoTo 0
Set FoundCell = SearchRange.Find(what:=FindWhat, _
        after:=LastCell, _
        LookIn:=LookIn, _
        LookAt:=XLookAt, _
        SearchOrder:=SearchOrder, _
        MatchCase:=MatchCase)

If Not FoundCell Is Nothing Then
    Set FirstFound = FoundCell
    'Set ResultRange = FoundCell
    'Set FoundCell = SearchRange.FindNext(after:=FoundCell)
    Do Until False ' Loop forever. We'll "Exit Do" when necessary.
        Include = False
        If BeginsWith = vbNullString And EndsWith = vbNullString Then
            Include = True
        Else
            If BeginsWith <> vbNullString Then
                If StrComp(Left(FoundCell.Text, Len(BeginsWith)), BeginsWith, BeginEndCompare) = 0 Then
                    Include = True
                End If
            End If
            If EndsWith <> vbNullString Then
                If StrComp(Right(FoundCell.Text, Len(EndsWith)), EndsWith, BeginEndCompare) = 0 Then
                    Include = True
                End If
            End If
        End If
        If Include = True Then
            If ResultRange Is Nothing Then
                Set ResultRange = FoundCell
            Else
                Set ResultRange = Application.Union(ResultRange, FoundCell)
            End If
        End If
        Set FoundCell = SearchRange.FindNext(after:=FoundCell)
        If (FoundCell Is Nothing) Then
            Exit Do
        End If
        If (FoundCell.Address = FirstFound.Address) Then
            Exit Do
        End If

    Loop
End If
    
Set FindAll = ResultRange

End Function
 
Upvote 0
Worf,

Works a treat, thank you.

I need to tweak it now for another project so how would this look if I only wanted to search column B from B2 onwards?

Columns need to display are only 5, A:E.

Code:
Sub FindData()
Dim SearchRange As Range, FindWhat, FoundCells As Range, FoundCell As Range, arrResults(), lFound&, i%
SearchFrm.ListBox_Results.ColumnCount = 5
SearchFrm.ListBox_Results.ColumnWidths = 20
If Len(SearchFrm.Controls.Item("TextBox_Find").Value) > 0 Then
    Set SearchRange = ActiveSheet.UsedRange.Cells
    FindWhat = SearchFrm.Controls.Item("TextBox_Find").Value
    Set FoundCells = FindAll(SearchRange:=SearchRange, FindWhat:=FindWhat, LookIn:=xlValues, LookAt:=xlPart, _
    SearchOrder:=xlByColumns, MatchCase:=False, BeginsWith:=vbNullString, EndsWith:=vbNullString, BeginEndCompare:=1)
    If FoundCells Is Nothing Then
        ReDim arrResults(1 To 1, 1 To 5)
        arrResults(1, 1) = "No Results"
    Else
        ReDim arrResults(1 To FoundCells.Count, 1 To 5)
        lFound = 1
        For Each FoundCell In FoundCells
            For i = 1 To 5
               arrResults(lFound, i) = Cells(FoundCell.Row, i)
            Next
            lFound = lFound + 1
        Next
    End If
    SearchFrm.Controls.Item("ListBox_Results").List = arrResults
Else
    SearchFrm.Controls.Item("ListBox_Results").Clear
End If
End Sub

The other issue is that column 4 is formatted as hh:mm but it's appearing in the Listbox all strange?
 
Last edited:
Upvote 0
Please test this:

Code:
Sub FindData()
Dim SearchRange As Range, FindWhat, FoundCells As Range, FoundCell As Range, arrResults(), lFound&, i%
SearchFrm.ListBox_Results.ColumnCount = 5
SearchFrm.ListBox_Results.ColumnWidths = 20
If Len(SearchFrm.Controls.Item("TextBox_Find").Value) > 0 Then
    Set SearchRange = ActiveSheet.Range("b2:b" & ActiveSheet.Range("b" & Rows.Count).End(xlUp).Row)
    FindWhat = SearchFrm.Controls.Item("TextBox_Find").Value
    Set FoundCells = FindAll(SearchRange:=SearchRange, FindWhat:=FindWhat, LookIn:=xlValues, LookAt:=xlPart, _
    SearchOrder:=xlByColumns, MatchCase:=False, BeginsWith:=vbNullString, EndsWith:=vbNullString, BeginEndCompare:=1)
    If FoundCells Is Nothing Then
        ReDim arrResults(1 To 1, 1 To 5)
        arrResults(1, 1) = "No Results"
    Else
        ReDim arrResults(1 To FoundCells.Count, 1 To 5)
        lFound = 1
        For Each FoundCell In FoundCells
            For i = 1 To 5
               arrResults(lFound, i) = Cells(FoundCell.Row, i)
               If i = 4 Then arrResults(lFound, i) = Format(Cells(FoundCell.Row, i), "hh:mm")
            Next
            lFound = lFound + 1
        Next
    End If
    SearchFrm.Controls.Item("ListBox_Results").List = arrResults
Else
    SearchFrm.Controls.Item("ListBox_Results").Clear
End If
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,643
Messages
6,120,702
Members
448,980
Latest member
CarlosWin

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