run macro on files within sub folders as well as in root folder

clobug1

New Member
Joined
Sep 7, 2017
Messages
2
I have some code that opens all excel files within a folder and copies cells from these files into a master recording spreadsheet. However, I have now been told that the source files will be saved within individual sub folders within this root folder. The code works perfectly for the root folder and I have tried a couple of solutions to also get information from the files in the sub folders but cannot get it to work. Could anyone suggest how I can loop through the sub folders:

Sub MergeReturns()
Dim SummarySheet As Worksheet
Dim FolderPath As String
Dim NRow As Long
Dim FileName As String
Dim WorkBk As Workbook
Dim SourceRange As Range
Dim DestRange As Range

'Set the sheet where you will store the merged data
Set SummarySheet = ActiveWorkbook.Worksheets(1)
' Modify this folder path to point to the files you want to use.
FolderPath = "H:\Catherine\ARMS Triage"

' NRow keeps track of where to insert new rows in the destination workbook.
NRow = InputBox("Please enter the next blank row to copy data to")

' Call Dir the first time, pointing it to all Excel files in the folder path.
FileName = Dir(FolderPath & "*.xl*")

' Loop until Dir returns an empty string.
Do While FileName <> ""
' Open a workbook in the folder

Set WorkBk = Workbooks.Open(FolderPath & FileName)

Dim ws As Worksheet
Dim Lastrow As Long
Set ws = Worksheets("TAD Tool")
Lastrow = ws.Cells(ws.Rows.Count, "A").End(xlUp).Row
'


' Set the source range, destination range and then copy
'Information about client
Set SourceRange1 = WorkBk.Worksheets(1).Range("C5")
Set DestRange1 = SummarySheet.Range("B" & NRow)
DestRange1.Value = SourceRange1.Value

'etc......etc. for each cell that needs copying

' Increase NRow so that we know where to copy data next.
NRow = NRow + 6

' Close the source workbook without saving changes.
WorkBk.Close savechanges:=False

' Use Dir to get the next file name.
FileName = Dir()
Loop

' Call AutoFit on the destination sheet so that all
' data is readable.
SummarySheet.Columns.AutoFit

'DeleteBlank
DeleteWhere

AutofillFormulae

ActiveWindow.ScrollRow = NRow - 10

End Sub
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
clobug1,

Welcome to the Board.

Could anyone suggest how I can loop through the sub folders:

The code below will loop through all files in the source folder as well its subfolders. The code is structured in two macros. The first - StartSubfolderLoop - establishes the initial FolderPath, then passes it as an argument to the main macro - SubfolderLoop. This is important, as paths for the subfolders will need to be passed to the SubfolderLoop.

Code:
Sub StartSubfolderLoop()

Dim FolderPath As String
FolderPath = "H:\Catherine\ARMS Triagel\" 'Change to your folder path and include "\" at the end

'True includes subfolders; False excludes subfolders
SubfolderLoop FolderPath, True
   
End Sub
Sub SubfolderLoop(SourceFolderName As String, IncludeSubfolders As Boolean)

' set a reference to Microsoft Scripting Runtime
' set a reference to Microsoft Outlook 14.0 Object Library

Dim fso As Scripting.FileSystemObject
Dim SourceFolder As Scripting.Folder
Dim SubFolder As Scripting.Folder
Dim FileItem As Scripting.File
  
Set fso = New Scripting.FileSystemObject
Set SourceFolder = fso.GetFolder(SourceFolderName)
 
For Each FileItem In SourceFolder.Files
    ' Your code goes here, for example...
    ' Test if the file is an excel file
    ' If yes, then open the file
    ' Perform some operation
    ' Close the file
Next FileItem

If IncludeSubfolders Then
    For Each SubFolder In SourceFolder.SubFolders
        SubfolderLoop SubFolder.Path, True
    Next SubFolder
End If

Set FileItem = Nothing
Set SourceFolder = Nothing
Set fso = Nothing
      
End Sub

Cheers,

tonyyy
 
Upvote 0

Forum statistics

Threads
1,215,022
Messages
6,122,726
Members
449,093
Latest member
Mnur

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