Macro to Find Match Value in Multiple Workbooks with Multiple Sheets

epoiezam

New Member
Joined
Jan 28, 2016
Messages
36
Office Version
  1. 2016
Platform
  1. Windows
Hi Guys,

Appended Macro below,
Current it only find a match on multiple workbooks in Sheet1.
How can we make it, to also search multiple sheets if a workbook has more then one.

Thanks.


Dim xFso As Object
Dim xFld As Object
Dim xStrSearch As String
Dim xStrPath As String
Dim xStrFile As String
Dim xOut As Worksheet
Dim xWb As Workbook
Dim xWk As Worksheet
Dim xRow As Long
Dim xFound As Range
Dim xStrAddress As String
Dim xFileDialog As FileDialog
Dim xUpdate As Boolean
Dim xCount As Long
On Error GoTo ErrHandler
Set xFileDialog = Application.FileDialog(msoFileDialogFolderPicker)
xFileDialog.AllowMultiSelect = False
xFileDialog.Title = "Select a folder"
If xFileDialog.Show = -1 Then
xStrPath = xFileDialog.SelectedItems(1)
End If
If xStrPath = "" Then Exit Sub
xStrSearch = "#N/A"
xUpdate = Application.ScreenUpdating
Application.ScreenUpdating = False
Set xOut = Worksheets.Add
xRow = 1
With xOut
.Cells(xRow, 1) = "Workbook"
.Cells(xRow, 2) = "Worksheet"
.Cells(xRow, 3) = "Cell"
.Cells(xRow, 4) = "Text in Cell"
Set xFso = CreateObject("Scripting.FileSystemObject")
Set xFld = xFso.GetFolder(xStrPath)
xStrFile = Dir(xStrPath & "\*.xlsx*")
Do While xStrFile <> ""
Set xWb = Workbooks.Open(Filename:=xStrPath & "\" & xStrFile, UpdateLinks:=0, ReadOnly:=True, AddToMRU:=False)
For Each xWk In xWb.Worksheets
Set xFound = xWk.UsedRange.Find(xStrSearch)
If Not xFound Is Nothing Then
xStrAddress = xFound.Address
End If
Do
If xFound Is Nothing Then
Exit Do
Else
xCount = xCount + 1
xRow = xRow + 1
.Cells(xRow, 1) = xWb.Name
.Cells(xRow, 2) = xWk.Name
.Cells(xRow, 3) = xFound.Address
.Cells(xRow, 4) = xFound.Value
End If
Set xFound = xWk.Cells.FindNext(After:=xFound)
Loop While xStrAddress <> xFound.Address
Next
xWb.Close (False)
xStrFile = Dir
Loop
.Columns("A:D").EntireColumn.AutoFit
End With
MsgBox xCount & "cells have been found"
ExitHandler:
Set xOut = Nothing
Set xWk = Nothing
Set xWb = Nothing
Set xFld = Nothing
Set xFso = Nothing
Application.ScreenUpdating = xUpdate
Exit Sub
ErrHandler:
MsgBox Err.Description, vbExclamation
Resume ExitHandler
End Sub
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
Hi,
try this update to your code & see if it will do what you want

VBA Code:
Sub SearchSheetsInFolder()
    
    Dim xStrSearch  As String, xStrPath As String
    Dim xStrAddress As String, xStrFile As String
    Dim xRow        As Long, xCount As Long
    
    Dim xOut        As Worksheet, xWk As Worksheet
    Dim xWb         As Workbook
    
    Dim xFound      As Range
    Dim xFileDialog As FileDialog
    
    On Error GoTo ErrHandler
    
    '--------------------------------------------------------------------------------------------------------------
    '                                           Select Folder
    '--------------------------------------------------------------------------------------------------------------
    Set xFileDialog = Application.FileDialog(msoFileDialogFolderPicker)
    
    With xFileDialog
        .AllowMultiSelect = False
        .Title = "Select a folder"
        If .Show = -1 Then xStrPath = xFileDialog.SelectedItems(1)
    End With
    
    If xStrPath = "" Then Exit Sub
    '--------------------------------------------------------------------------------------------------------------
    
    'search value
    xStrSearch = "#N/A"
    
    Application.ScreenUpdating = False
    
    '----------------------------------------------------------------------------------------------------------------
    '                                              Add Sheet
    '----------------------------------------------------------------------------------------------------------------
    Set xOut = Worksheets.Add(after:=Worksheets(Sheets.Count))
    
    xRow = 1
    'add headers
    xOut.Cells(xRow, 1).Resize(, 4).Value = Array("Workbook", "Worksheet", "Cell", "Text in Cell")
    
    '-----------------------------------------------------------------------------------------------------------------
    '                                       Open Each File In Folder
    '-----------------------------------------------------------------------------------------------------------------
    
    xStrFile = Dir(xStrPath & "\*.xlsx*")
    
    Do While xStrFile <> ""
    
        Set xWb = Workbooks.Open(Filename:=xStrPath & "\" & xStrFile, UpdateLinks:=0, ReadOnly:=True, AddToMRU:=False)
        
        For Each xWk In xWb.Worksheets
            'search string value
            Set xFound = xWk.UsedRange.Find(xStrSearch, LookIn:=xlValues, lookat:=xlWhole)
            If Not xFound Is Nothing Then
                xStrAddress = xFound.Address
                Do
                    xCount = xCount + 1
                    xRow = xRow + 1
                    
                    'add values to sheet
                    xOut.Cells(xRow, 1).Resize(, 4).Value = Array(xWb.Name, xWk.Name, xFound.Address, xFound.Value)
                    
                    Set xFound = xWk.Cells.FindNext(after:=xFound)
                    If xFound Is Nothing Then Exit Do
                    
                Loop While xStrAddress <> xFound.Address
            End If
            'close file
            xWb.Close False
            'release objects
            Set xWb = Nothing
            Set xFound = Nothing
            'next worksheet
        Next xWk
        
        'next file
        xStrFile = Dir
    Loop
    '-----------------------------------------------------------------------------------------------------------------
    
    xOut.Columns("A:D").EntireColumn.AutoFit
    
    'inform user
    MsgBox xCount & "cells have been found", 64, "Results"
    
ErrHandler:
    If Not xWb Is Nothing Then xWb.Close False
    Application.ScreenUpdating = True
    'report errors
    If Err <> 0 Then MsgBox (Error(Err)), 48, "Error"
    
End Sub

Dave
 
Upvote 0

Forum statistics

Threads
1,223,231
Messages
6,170,885
Members
452,364
Latest member
springate

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