May 01 2024 10:57 AM
Hello All,
Example: I have 10 Invoice numbers (C093705926 C093705927 C093725527 C093750757 C093750759 C093769955 C093769956 C093789382 C093808525 C093808526) and need to search these in a workbook where they are all located.
1. Can I search for them at the same time?
2. Even if I cannot search for them at the same time, is it possible for the search to return the entire row "C093705926" is located in?
3. What happens if I have to do this for 200 invoices, will this mess up my workbook?
Thank you!
May 01 2024 11:57 AM
May 01 2024 12:06 PM
May 01 2024 12:22 PM
Thanks. How many sheets do you want to search, and is this fixed or variable?
May 01 2024 01:20 PM
I'd say it would be around 4-5 sheets, but this is variable since I might need to search through more, maybe11-12.
May 01 2024 01:21 PM
May 01 2024 01:32 PM
Do you want to search ALL sheets except for the sheet with the output, or only specific sheets?
May 01 2024 02:35 PM
May 01 2024 02:56 PM
SolutionTry this macro:
Sub ListEm()
Dim wbkSource As Workbook
Dim wshSource As Worksheet
Dim rngSource As Range
Dim strAddress As String
Dim wbkTarget As Workbook
Dim wshTarget As Worksheet
Dim varSearch As Variant
Dim lngRow As Long
Application.ScreenUpdating = False
Set wbkSource = ActiveWorkbook
Set wbkTarget = Workbooks.Add(xlWBATWorksheet)
Set wshTarget = wbkTarget.Worksheets(1)
For Each wshSource In wbkSource.Worksheets
For Each varSearch In Array("C093705926", "C093705927", "C093725527", _
"C093750757", "C093750759", "C093769955", "C093769956", _
"C093789382", "C093808525", "C093808526")
Set rngSource = wshSource.Range("C:C").Find(What:=varSearch, LookAt:=xlWhole)
If Not rngSource Is Nothing Then
strAddress = rngSource.Address
Do
lngRow = lngRow + 1
rngSource.EntireRow.Copy Destination:=wshTarget.Range("A" & lngRow)
Set rngSource = wshSource.Range("C:C").Find(What:=varSearch, _
After:=rngSource, LookAt:=xlWhole)
If rngSource Is Nothing Then Exit Do
Loop Until rngSource.Address = strAddress
End If
Next varSearch
Next wshSource
Application.CutCopyMode = False
Application.ScreenUpdating = True
End Sub
May 02 2024 12:48 AM - edited May 02 2024 12:50 AM
https://answers.microsoft.com/en-us/msoffice/forum/all/how-can-i-lookup-and-pull-data-from-specific/...
consolidate all sheets and query by sql
multiple select checkbox
May 02 2024 04:42 AM
May 02 2024 05:51 AM
The code assumes that the workbook with the sheets to be searched is the active workbook.
You can add more invoice numbers to the array in the code.
May 02 2024 06:10 AM
May 02 2024 07:05 AM
Yes - if you want to keep the macro for later use, save the workbook as a macro-enabled workbook (*.xlsm)
May 01 2024 02:56 PM
SolutionTry this macro:
Sub ListEm()
Dim wbkSource As Workbook
Dim wshSource As Worksheet
Dim rngSource As Range
Dim strAddress As String
Dim wbkTarget As Workbook
Dim wshTarget As Worksheet
Dim varSearch As Variant
Dim lngRow As Long
Application.ScreenUpdating = False
Set wbkSource = ActiveWorkbook
Set wbkTarget = Workbooks.Add(xlWBATWorksheet)
Set wshTarget = wbkTarget.Worksheets(1)
For Each wshSource In wbkSource.Worksheets
For Each varSearch In Array("C093705926", "C093705927", "C093725527", _
"C093750757", "C093750759", "C093769955", "C093769956", _
"C093789382", "C093808525", "C093808526")
Set rngSource = wshSource.Range("C:C").Find(What:=varSearch, LookAt:=xlWhole)
If Not rngSource Is Nothing Then
strAddress = rngSource.Address
Do
lngRow = lngRow + 1
rngSource.EntireRow.Copy Destination:=wshTarget.Range("A" & lngRow)
Set rngSource = wshSource.Range("C:C").Find(What:=varSearch, _
After:=rngSource, LookAt:=xlWhole)
If rngSource Is Nothing Then Exit Do
Loop Until rngSource.Address = strAddress
End If
Next varSearch
Next wshSource
Application.CutCopyMode = False
Application.ScreenUpdating = True
End Sub