VBA loop through folder and copy all workbooks into a master sheet

TaskMaster

Board Regular
Joined
Oct 15, 2020
Messages
75
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
Hi all, I have been using some VBA that copies all workbooks in a pre-determined folder and copies that data into a mastersheet. This works well but there are a couple of tweaks that would make is so much better. Rather than having the folder location pre-determined, is it possible to have a pop up box where you find the folder location, as this folder changes month to month. Also I have a pre-determined range of A4:U2000 which I would rather have it find the last row of data and just paste that as this range could also change. Appreciate you taking the time to look at this.

VBA Code:
Sub MergeAllWorkbooks()
    Dim MyPath As String, FilesInPath As String
    Dim MyFiles() As String
    Dim SourceRcount As Long, FNum As Long
    Dim mybook As Workbook, BaseWks As Worksheet
    Dim sourceRange As Range, destrange As Range
    Dim rnum As Long, CalcMode As Long

    'Fill in the path\folder where the files are
    MyPath = "C:\Users\Flowers\test"

    'Add a slash at the end if the user forget it
    If Right(MyPath, 1) <> "\" Then
        MyPath = MyPath & "\"
    End If

    'If there are no Excel files in the folder exit the sub
    FilesInPath = Dir(MyPath & "*.xl*")
    If FilesInPath = "" Then
        MsgBox "No files found"
        Exit Sub
    End If

    'Fill the array(myFiles)with the list of Excel files in the folder
    FNum = 0
    Do While FilesInPath <> ""
        FNum = FNum + 1
        ReDim Preserve MyFiles(1 To FNum)
        MyFiles(FNum) = FilesInPath
        FilesInPath = Dir()
    Loop

    'Change ScreenUpdating, Calculation and EnableEvents
    With Application
        CalcMode = .Calculation
        .Calculation = xlCalculationManual
        .ScreenUpdating = False
        .EnableEvents = False
    End With

    'Add a new workbook with one sheet
    Set BaseWks = Workbooks.Add(xlWBATWorksheet).Worksheets("Sheet1")
    rnum = 1

    'Loop through all files in the array(myFiles)
    If FNum > 0 Then
        For FNum = LBound(MyFiles) To UBound(MyFiles)
            Set mybook = Nothing
            On Error Resume Next
            Set mybook = Workbooks.Open(MyPath & MyFiles(FNum))
            On Error GoTo 0

            If Not mybook Is Nothing Then

                On Error Resume Next

                With mybook.Worksheets(1)
                    Set sourceRange = .Range("A4:U2000")
                End With

                If Err.Number > 0 Then
                    Err.Clear
                    Set sourceRange = Nothing
                Else
                    'if SourceRange use all columns then skip this file
                    If sourceRange.Columns.Count >= BaseWks.Columns.Count Then
                        Set sourceRange = Nothing
                    End If
                End If
                On Error GoTo 0

                If Not sourceRange Is Nothing Then

                    SourceRcount = sourceRange.Rows.Count

                    If rnum + SourceRcount >= BaseWks.Rows.Count Then
                        MsgBox "Sorry there are not enough rows in the sheet"
                        BaseWks.Columns.AutoFit
                        mybook.Close savechanges:=False
                        GoTo ExitTheSub
                    Else

                        'Copy the file name in column A
                        With sourceRange
                            BaseWks.Cells(rnum, "A"). _
                                    Resize(.Rows.Count).Value = MyFiles(FNum)
                        End With

                        'Set the destrange
                        Set destrange = BaseWks.Range("B" & rnum)

                        'we copy the values from the sourceRange to the destrange
                        With sourceRange
                            Set destrange = destrange. _
                                            Resize(.Rows.Count, .Columns.Count)
                        End With
                        destrange.Value = sourceRange.Value

                        rnum = rnum + SourceRcount
                    End If
                End If
                mybook.Close savechanges:=False
            End If

        Next FNum
        BaseWks.Columns.AutoFit
    End If

ExitTheSub:
    'Restore ScreenUpdating, Calculation and EnableEvents
    With Application
        .ScreenUpdating = True
        .EnableEvents = True
        .Calculation = CalcMode
    End With
End Sub
 
Last edited by a moderator:

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
Hi welcome to forum

Place following code in a STANDARD module

VBA Code:
Function GetFolder(Optional ByVal Title As String = "Select Folder") As String
    Dim Folder As FileDialog
    Dim SelectedFolder As String
    Set Folder = Application.FileDialog(msoFileDialogFolderPicker)
    With Folder
        .Title = Title
        .AllowMultiSelect = False
        .ButtonName = "Select Folder"
        .InitialFileName = ThisWorkbook.Path
        If .Show <> -1 Then GoTo EndFile
        SelectedFolder = .SelectedItems(1)
    End With
EndFile:
    GetFolder = SelectedFolder
    Set Folder = Nothing
End Function

then replace this line of your code

VBA Code:
MyPath = "C:\Users\Flowers\test"

with this

VBA Code:
MyPath = GetFolder
'cancel pressed
If Len(MyPath) = 0 Then Exit Sub

and see if this will do what you want.

The function GetFolder can be used in other codes in your project if required.

Hope Helpful

Dave
 
Upvote 0
Hi welcome to forum

Place following code in a STANDARD module

VBA Code:
Function GetFolder(Optional ByVal Title As String = "Select Folder") As String
    Dim Folder As FileDialog
    Dim SelectedFolder As String
    Set Folder = Application.FileDialog(msoFileDialogFolderPicker)
    With Folder
        .Title = Title
        .AllowMultiSelect = False
        .ButtonName = "Select Folder"
        .InitialFileName = ThisWorkbook.Path
        If .Show <> -1 Then GoTo EndFile
        SelectedFolder = .SelectedItems(1)
    End With
EndFile:
    GetFolder = SelectedFolder
    Set Folder = Nothing
End Function

then replace this line of your code

VBA Code:
MyPath = "C:\Users\Flowers\test"

with this

VBA Code:
MyPath = GetFolder
'cancel pressed
If Len(MyPath) = 0 Then Exit Sub

and see if this will do what you want.

The function GetFolder can be used in other codes in your project if required.

Hope Helpful

Dave
 
Upvote 0
Hi welcome to forum

Place following code in a STANDARD module

VBA Code:
Function GetFolder(Optional ByVal Title As String = "Select Folder") As String
    Dim Folder As FileDialog
    Dim SelectedFolder As String
    Set Folder = Application.FileDialog(msoFileDialogFolderPicker)
    With Folder
        .Title = Title
        .AllowMultiSelect = False
        .ButtonName = "Select Folder"
        .InitialFileName = ThisWorkbook.Path
        If .Show <> -1 Then GoTo EndFile
        SelectedFolder = .SelectedItems(1)
    End With
EndFile:
    GetFolder = SelectedFolder
    Set Folder = Nothing
End Function

then replace this line of your code

VBA Code:
MyPath = "C:\Users\Flowers\test"

with this

VBA Code:
MyPath = GetFolder
'cancel pressed
If Len(MyPath) = 0 Then Exit Sub

and see if this will do what you want.

The function GetFolder can be used in other codes in your project if required.

Hope Helpful

Dave

Hi Dave this is perfect thank you so much, with regards to making my fixed range copy all the data in the work sheet and pasting it below the rest of the data who could I apply that?
 
Upvote 0
Hi Dave this is perfect thank you so much, with regards to making my fixed range copy all the data in the work sheet and pasting it below the rest of the data who could I apply that?

sorry did not look at that requirement

try replacing this part of your code

VBA Code:
With mybook.Worksheets(1)
Set sourceRange = .Range("A4:U2000")
End With

with this

VBA Code:
Set sourceRange = mybook.Worksheets(1).Range("A4").CurrentRegion

and see it it does what you want

Dave
 
Upvote 0
sorry did not look at that requirement

try replacing this part of your code

VBA Code:
With mybook.Worksheets(1)
Set sourceRange = .Range("A4:U2000")
End With

with this

VBA Code:
Set sourceRange = mybook.Worksheets(1).Range("A4").CurrentRegion

and see it it does what you want

Dave

I tried that amendment, it opened all of the files but didn't seem to copy anything over.
 
Upvote 0
is the sheet you are copying protected? if so, CurrentRegion will fail

you can either include code to unprotect or try another approach maybe

VBA Code:
With mybook.Worksheets(1)
    lastrow = .Cells(.Rows.Count, "A").End(xlUp).Row
    lastcol = .Cells(4, .Columns.Count).End(xlToLeft).Column
    Set sourceRange = .Cells(4, 1).Resize(lastrow, lastcol)
End With

Dave
 
Upvote 0
is the sheet you are copying protected? if so, CurrentRegion will fail

you can either include code to unprotect or try another approach maybe

VBA Code:
With mybook.Worksheets(1)
    lastrow = .Cells(.Rows.Count, "A").End(xlUp).Row
    lastcol = .Cells(4, .Columns.Count).End(xlToLeft).Column
    Set sourceRange = .Cells(4, 1).Resize(lastrow, lastcol)
End With

Dave

Hi Dave this is perfect, this will save me tons of time every month. Really appreciate it!!
 
Upvote 0

Forum statistics

Threads
1,224,828
Messages
6,181,217
Members
453,024
Latest member
Wingit77

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