Search multiple items in all worksheets.

seattlerose

New Member
Joined
Mar 8, 2012
Messages
23
Hello, I have the following code and I am having trouble figuring out how to change it so I can put in a list of different names in the search and have the results show up on different rows.

Example: This code will add a new worksheet with the following info

Workbook, Worksheet, Cell and Text in Cell

But I can only put one text string (say i'm looking for a last name) I want to be able to put in a list of last names and have it return the above data for each last name it finds. please help.

Sub SearchFolders()
Dim fso As Object
Dim fld As Object
Dim strSearch As String
Dim strPath As String
Dim strFile As String
Dim wOut As Worksheet
Dim wbk As Workbook
Dim wks As Worksheet
Dim lRow As Long
Dim rFound As Range
Dim strFirstAddress As String


On Error GoTo ErrHandler
Application.ScreenUpdating = False


'Change as desired
strPath = "c:\MyFolder"
strSearch = "Specific text"


Set wOut = Worksheets.Add
lRow = 1
With wOut
.Cells(lRow, 1) = "Workbook"
.Cells(lRow, 2) = "Worksheet"
.Cells(lRow, 3) = "Cell"
.Cells(lRow, 4) = "Text in Cell"
Set fso = CreateObject("Scripting.FileSystemObject")
Set fld = fso.GetFolder(strPath)


strFile = Dir(strPath & "\*.xls*")
Do While strFile <> ""
Set wbk = Workbooks.Open _
(Filename:=strPath & "\" & strFile, _
UpdateLinks:=0, _
ReadOnly:=True, _
AddToMRU:=False)


For Each wks In wbk.Worksheets
Set rFound = wks.UsedRange.Find(strSearch)
If Not rFound Is Nothing Then
strFirstAddress = rFound.Address
End If
Do
If rFound Is Nothing Then
Exit Do
Else
lRow = lRow + 1
.Cells(lRow, 1) = wbk.Name
.Cells(lRow, 2) = wks.Name
.Cells(lRow, 3) = rFound.Address
.Cells(lRow, 4) = rFound.Value
End If
Set rFound = wks.Cells.FindNext(After:=rFound)
Loop While strFirstAddress <> rFound.Address
Next


wbk.Close (False)
strFile = Dir
Loop
.Columns("A:D").EntireColumn.AutoFit
End With
MsgBox "Done"


ExitHandler:
Set wOut = Nothing
Set wks = Nothing
Set wbk = Nothing
Set fld = Nothing
Set fso = Nothing
Application.ScreenUpdating = True
Exit Sub


ErrHandler:
MsgBox Err.Description, vbExclamation
Resume ExitHandler
End Sub

thanks guys
 
Define an array of search terms

Code:
arrSearch = Array("Text1", "Text2", "Text3")


Loop through each search term for each workbook

Code:
        [COLOR=darkblue]For[/COLOR] [COLOR=darkblue]Each[/COLOR] vSearch [COLOR=darkblue]In[/COLOR] arrSearch
            [COLOR=darkblue]For[/COLOR] [COLOR=darkblue]Each[/COLOR] wks [COLOR=darkblue]In[/COLOR] wbk.Worksheets
                [COLOR=darkblue]Set[/COLOR] rFound = wks.UsedRange.Find(vSearch)

You'll likely want to log each search term with its matched data rows
Code:
.Cells(lRow, 5) = vSearch
 
Upvote 0
Define an array of search terms

Code:
arrSearch = Array("Text1", "Text2", "Text3")


Loop through each search term for each workbook

Code:
        [COLOR=darkblue]For[/COLOR] [COLOR=darkblue]Each[/COLOR] vSearch [COLOR=darkblue]In[/COLOR] arrSearch
            [COLOR=darkblue]For[/COLOR] [COLOR=darkblue]Each[/COLOR] wks [COLOR=darkblue]In[/COLOR] wbk.Worksheets
                [COLOR=darkblue]Set[/COLOR] rFound = wks.UsedRange.Find(vSearch)

You'll likely want to log each search term with its matched data rows
Code:
.Cells(lRow, 5) = vSearch


Thank you for the quick reply, I seem to still be having issues with how to incorporate this code into the code I have. I'm still in the starter stages of my VBA writing and usage. Could you possible alter the code I have with yours placed in?
 
Upvote 0
This is not tested. Change the search terms to suit.

Code:
[color=darkblue]Sub[/color] SearchFolders()
    
    [color=green]'Dim strSearch As String[/color]
    [color=darkblue]Dim[/color] arrSearch [color=darkblue]As[/color] [color=darkblue]Variant[/color]
    [color=darkblue]Dim[/color] vSearch [color=darkblue]As[/color] [color=darkblue]Variant[/color]
    [color=darkblue]Dim[/color] strPath [color=darkblue]As[/color] [color=darkblue]String[/color]
    [color=darkblue]Dim[/color] strFile [color=darkblue]As[/color] [color=darkblue]String[/color]
    [color=darkblue]Dim[/color] wbk    [color=darkblue]As[/color] Workbook
    [color=darkblue]Dim[/color] wks    [color=darkblue]As[/color] Worksheet
    [color=darkblue]Dim[/color] lRow   [color=darkblue]As[/color] [color=darkblue]Long[/color]
    [color=darkblue]Dim[/color] rFound [color=darkblue]As[/color] Range
    [color=darkblue]Dim[/color] strFirstAddress [color=darkblue]As[/color] [color=darkblue]String[/color]
    
    [color=darkblue]On[/color] [color=darkblue]Error[/color] [color=darkblue]GoTo[/color] ErrHandler
    Application.ScreenUpdating = [color=darkblue]False[/color]
    
    [color=green]'Change as desired[/color]
    strPath = "C:\Test"
    [color=green]'strSearch = "Specific text"[/color]
    arrSearch = Array([COLOR=#ff0000]"Text1", "Text2", "Text3"[/COLOR])    [color=green]'Search terms[/color]
    
    lRow = 1
    [color=darkblue]With[/color] Worksheets.Add
        .Range("A1:E1") = Array("Workbook", "Worksheet", "Cell", "Text in Cell", "Search Term")
    
        strFile = Dir(strPath & "\*.xls*")
        [color=darkblue]Do[/color] [color=darkblue]While[/color] strFile <> ""
            [color=darkblue]Set[/color] wbk = Workbooks.Open _
                      (Filename:=strPath & "\" & strFile, _
                       UpdateLinks:=0, _
                       ReadOnly:=True, _
                       AddToMRU:=False)
            
            [color=darkblue]For[/color] [color=darkblue]Each[/color] wks [color=darkblue]In[/color] wbk.Worksheets
                [color=darkblue]For[/color] [color=darkblue]Each[/color] vSearch [color=darkblue]In[/color] arrSearch
                    [color=darkblue]Set[/color] rFound = wks.UsedRange.Find(vSearch, LookAt:=xlWhole, MatchCase:=False)
                    [color=darkblue]If[/color] [color=darkblue]Not[/color] rFound [color=darkblue]Is[/color] [color=darkblue]Nothing[/color] [color=darkblue]Then[/color]
                        strFirstAddress = rFound.Address
                        [color=darkblue]Do[/color]
                            lRow = lRow + 1
                            .Cells(lRow, 1) = wbk.Name
                            .Cells(lRow, 2) = wks.Name
                            .Cells(lRow, 3) = rFound.Address
                            .Cells(lRow, 4) = rFound.Value
                            .Cells(lRow, 5) = vSearch
                            [color=darkblue]Set[/color] rFound = wks.Cells.FindNext(After:=rFound)
                        [color=darkblue]Loop[/color] [color=darkblue]While[/color] strFirstAddress <> rFound.Address
                    [color=darkblue]End[/color] [color=darkblue]If[/color]
                [color=darkblue]Next[/color] vSearch
            [color=darkblue]Next[/color] wks
    
            wbk.Close [color=darkblue]False[/color]
            strFile = Dir
        [color=darkblue]Loop[/color]
        .Columns("A:E").EntireColumn.AutoFit
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    MsgBox "Done"
    
    
ExitHandler:
    [color=darkblue]Set[/color] wks = [color=darkblue]Nothing[/color]
    [color=darkblue]Set[/color] wbk = [color=darkblue]Nothing[/color]
    Application.ScreenUpdating = [color=darkblue]True[/color]
    [color=darkblue]Exit[/color] [color=darkblue]Sub[/color]
    
    
ErrHandler:
    MsgBox Err.Description, vbExclamation
    [color=darkblue]Resume[/color] ExitHandler
[color=darkblue]End[/color] [color=darkblue]Sub[/color]
 
Upvote 0

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