Well Tom:
I'm going to give you a solution that should work , though I wish I could have gotten my 2 questions answered before doing the coding .
The following procedure "GetDirXlsContents" is the code that you must configure and Run. It will call the other procedure with the details that you configure in GetDirXlsContents.
THINGS TO CONFIGURE IN "GetDirXlsContentS"
SHEETNAME
I've configured the Source Sheet as "Sheet1" if all workbooks have a specific sheet inside it then change this value to what ever it is. If the sheets have multiple sheets of data then run this one for each sheet name. If all books have different named sheets then change this varible to "shxyzzyz" and the program will ask you to select the appropriate sheet in each book.
PATH:
The path / directory has been set up as "C:\test" . Please modify to point to the directory where all files are stored ... note the missing trailing "\" . If you put a final "\" the system will fail.
Example: If you source files are in the directory called Nimrod , of the C root , then the Path should be changed from "C:\test" to "C:\Nimrod"
RANGE:
This is the range of cells that will be scanned for data.
Public Sub GetDirXlsContents()
' Source sheet name, Source directory path, Source cell Range
Call CopyFromEachFileInPath("Sheet1", "C:\test", "A1:I500")
End Sub
Private Sub CopyFromEachFileInPath(SheetName, Path, Rng)
Dim fs, f, f1, fc, s
Set fs = CreateObject("Scripting.FileSystemObject")
Set f = fs.GetFolder(Path & "\")
Set fc = f.Files
' make a temp sheet
Application.ScreenUpdating = False
TargSh = ActiveSheet.Name
Sheets.Add
TempSh = ActiveSheet.Name
Sheets(TargSh).Activate
Application.ScreenUpdating = True
For Each f1 In fc
With Sheets(TempSh)
' clear temp sheet and start again
.Cells.ClearContents
' Place Src Info on Temp Targ Sheet
If Right(f1.Name, 3) = "xls" Then
fName = Left(f1.Name, Len(f1.Name) - 4)
.Range(Rng).FormulaArray = "='" & Path & "\[" & fName & "]" & SheetName & "'!" & Rng
.Range(Rng).Value = .Range(Rng).Value
'GetValuesFromAClosedWorkbook Path, f1.Name, SheetName, "A1:K30"
End If
' if columD = 1 copy over
For Each D In .Columns("D:D").SpecialCells(xlCellTypeConstants, 1)
If Not D.Value = 0 Then ' copy to final sheet
NxRw = Cells(65536, 4).End(xlUp).Row + 1
Range("A" & NxRw & ":I" & NxRw).Value = .Range("A" & D.Row & ":Z" & D.Row).Value
Range("J" & NxRw).Value = fName
End If
Next D
End With
' have user see list build, so know not frozen
Cells(NxRw, 1).Select
Next ' workbook
' get rid of temp sheet
Application.DisplayAlerts = False
Sheets(TempSh).Delete
Application.DisplayAlerts = True
End Sub
TO INSTALL CODE in module:
1.Open the Workbook you want code copied into
2.Press the Keys ALT and F11 at the same time (this open VBE window)
3.In VBE window goto tool bar and click "INSERT"
4.On Insert drop down menu click "Module"
5.A new module winow will appear on the rt side of VBE
6.Paste the code and close VBE by pressing ALT + F11
TO RUN MY CODE:
1.While the sheet to evaluate is active goto tool bar
2. ON tool bar goto "Tools...Macro....Macros"
3. A list of Macros should appear
4. To run the above Macro Double Click on it's name in the list