Macro to copy sheets from multiple workbooks

petes

Board Regular
Joined
Sep 12, 2009
Messages
168
Hi Friends!!

I have one Master file (MAIN.xlsx) and other files (A.xslx, B.xslx, C.xslx........). All these files are in the same folder (C:\test)

I need a macro in MAIN.xlsx file, so that it should copy all the data only from sheet1 of other files (A.xslx, B.xslx, C.xslx........) and paste it after the sheet1 of MAIN.xlsx file along with their sheet names.

Also, the other files (A.xslx, B.xslx, C.xslx........) should be closed after this operation.

Your help is very much appreciated...!!
 
Try

Code:
Sub ImportFiles()
Dim MyFolder As String
Dim MyFile As String
Dim wb As Workbook
With ThisWorkbook
    MyFolder = .Path
    MyFile = Dir(MyFolder & "\*.xlsx")
    Do While MyFile <> ""
        If MyFile <> .Name Then
            .Sheets.Add after:=.Sheets(.Sheets.Count)
            On Error Resume Next
            .Sheets(.Sheets.Count).Name = Left(MyFile, Len(MyFile) - 5)
            On Error GoTo 0
            Set wb = Workbooks.Open(MyFolder & "\" & MyFile)
            wb.Sheets(1).UsedRange.Copy Destination:=.Sheets(.Sheets.Count).Range("A1")
            wb.Close False
        End If
        MyFile = Dir
    Loop
End With
End Sub
 
Last edited:
Upvote 0

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
Thanks for your reply...This does not throw any error but there is one problem.... If I run it for the second time or more than that, it actually runs without any error but also creates other additional sheets which is not required.....

The additional sheet that it creates is equal to the number of files that it consolidates during first run (This additional sheets keeps on increasing from second onwards)... these additional sheets should not be created
 
Upvote 0
Try

Code:
Sub ImportFiles()
Dim MyFolder As String
Dim MyFile As String
Dim wb As Workbook
With ThisWorkbook
    MyFolder = .Path
    MyFile = Dir(MyFolder & "\*.xlsx")
    Do While MyFile <> ""
        If MyFile <> .Name Then
            If Not WorksheetExists(.Name, Left(MyFile, Len(MyFile) - 5)) Then
                .Sheets.Add(after:=.Sheets(.Sheets.Count)).Name = Left(MyFile, Len(MyFile) - 5)
                Set wb = Workbooks.Open(MyFolder & "\" & MyFile)
                wb.Sheets(1).UsedRange.Copy Destination:=.Sheets(.Sheets.Count).Range("A1")
                wb.Close False
            Else
                Application.StatusBar = Left(MyFile, Len(MyFile) - 5) & " exists: skipped"
            End If
        End If
        MyFile = Dir
    Loop
End With
Application.StatusBar = False
End Sub

Function WorksheetExists(WBName As String, WSName As String) As Boolean
On Error Resume Next
WorksheetExists = Workbooks(WBName).Worksheets(WSName).Name = WSName
End Function
 
Upvote 0
This is ok but need some changes.....

This modified code actually look for the exisiting sheets (from the first run) and does not run (for the second time) if this sheet is already present...
My requirement is, it should actually get updated during each and every run since the users might have made some changes in the files that is getting consolidated here...

I hope you understood..
 
Upvote 0
Try

Code:
Sub ImportFiles()
Dim MyFolder As String
Dim MyFile As String
Dim wb As Workbook
With ThisWorkbook
    MyFolder = .Path
    MyFile = Dir(MyFolder & "\*.xlsx")
    Do While MyFile <> ""
        If MyFile <> .Name Then
            If WorksheetExists(.Name, Left(MyFile, Len(MyFile) - 5)) Then
                .Sheets(Left(MyFile, Len(MyFile) - 5)).UsedRange.ClearContents
             Else
                .Sheets.Add(after:=.Sheets(.Sheets.Count)).Name = Left(MyFile, Len(MyFile) - 5)
            End If
            Set wb = Workbooks.Open(MyFolder & "\" & MyFile)
            wb.Sheets(1).UsedRange.Copy Destination:=.Sheets(Left(MyFile, Len(MyFile) - 5)).Range("A1")
            wb.Close False
        End If
        MyFile = Dir
    Loop
End With
End Sub

Function WorksheetExists(WBName As String, WSName As String) As Boolean
On Error Resume Next
WorksheetExists = Workbooks(WBName).Worksheets(WSName).Name = WSName
End Function
 
Upvote 0
The code for merging my data from multiple workbooks onto one workbook is great. The problem I have is everytime I run the macro it produces another new sheet/workbook.
I need it to write the data in one sheet in one workbook and overwrite the previous data everytime I run the macro. Hope someone can help

Thanks
 
Upvote 0
This post has been exceptionally helpfull.

I have 40 seperate .xls that individual users input data via a VBA form and post to an internal WS (Data). I need to periodically pull row 2 and below from each Data worksheet and paste it into a master.xlsm file. The number of rows of source data varies dailybut is always 6 columns with the same headers in each file.

I used the Link from post #2 to create the code below. It does almost all I need it to do.

1) How do I clear the data that is copied in the source files and keep the source sheets and header row. this way the next time I import only new data?
2) How do I retain the hyperlink format during paste? (column D of source range are hyperlinks.
3) How do I make the the destination start at the first empty row?


Code:
Function RDB_Last(choice As Integer, rng As Range)
' By Ron de Bruin, 5 May 2008
' A choice of 1 = last row.
' A choice of 2 = last column.
' A choice of 3 = last cell.
   Dim lrw As Long
   Dim lcol As Integer
   Select Case choice
   Case 1:
      On Error Resume Next
      RDB_Last = rng.Find(What:="*", _
                          after:=rng.Cells(1), _
                          Lookat:=xlPart, _
                          LookIn:=xlFormulas, _
                          SearchOrder:=xlByRows, _
                          SearchDirection:=xlPrevious, _
                          MatchCase:=False).Row
      On Error GoTo 0
   Case 2:
      On Error Resume Next
      RDB_Last = rng.Find(What:="*", _
                          after:=rng.Cells(1), _
                          Lookat:=xlPart, _
                          LookIn:=xlFormulas, _
                          SearchOrder:=xlByColumns, _
                          SearchDirection:=xlPrevious, _
                          MatchCase:=False).Column
      On Error GoTo 0
   Case 3:
      On Error Resume Next
      lrw = rng.Find(What:="*", _
                    after:=rng.Cells(1), _
                    Lookat:=xlPart, _
                    LookIn:=xlFormulas, _
                    SearchOrder:=xlByRows, _
                    SearchDirection:=xlPrevious, _
                    MatchCase:=False).Row
      On Error GoTo 0
      On Error Resume Next
      lcol = rng.Find(What:="*", _
                     after:=rng.Cells(1), _
                     Lookat:=xlPart, _
                     LookIn:=xlFormulas, _
                     SearchOrder:=xlByColumns, _
                     SearchDirection:=xlPrevious, _
                     MatchCase:=False).Column
      On Error GoTo 0
      On Error Resume Next
      RDB_Last = rng.Parent.Cells(lrw, lcol).Address(False, False)
      If Err.Number > 0 Then
         RDB_Last = rng.Cells(1).Address(False, False)
         Err.Clear
      End If
      On Error GoTo 0
   End Select
End Function
 
 
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
    Dim FirstCell As String
 
 
    ' Change this to the path\folder location of your files.
    MyPath = "C:\Users\...\Desktop\Test"
    ' Add a slash at the end of the path if needed.
    If Right(MyPath, 1) <> "\" Then
        MyPath = MyPath & "\"
    End If
    ' If there are no Excel files in the folder, exit.
    FilesInPath = Dir(MyPath & "*.xl*")
    If FilesInPath = "" Then
        MsgBox "No files found"
        Exit Sub
    End If
    ' Fill the myFiles array with the list of Excel files
    ' in the search folder.
    FNum = 0
    Do While FilesInPath <> ""
        FNum = FNum + 1
        ReDim Preserve MyFiles(1 To FNum)
        MyFiles(FNum) = FilesInPath
        FilesInPath = Dir()
    Loop
    ' Set various application properties.
    With Application
        CalcMode = .Calculation
        .Calculation = xlCalculationManual
        .ScreenUpdating = False
        .EnableEvents = False
    End With
    ' Add a new workbook with one sheet.
    Set BaseWks = Workbooks("Master.xlsm").Worksheets(1)
    rnum = 2
    ' Loop through all files in the myFiles array.
    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
                ' Change this range to fit your own needs.
                 With mybook.Worksheets(1)
                    FirstCell = "A2"
                    Set sourceRange = .Range(FirstCell & ":" & RDB_Last(3, .Cells))
                    ' Test if the row of the last cell is equal to or greater than the row of the first cell.
                    If RDB_Last(1, .Cells) < .Range(FirstCell).Row Then
                    Set sourceRange = Nothing
                    End If
                End With
                If Err.Number > 0 Then
                    Err.Clear
                    Set sourceRange = Nothing
                Else
                    ' If source range uses 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 "There are not enough rows in the target worksheet."
                        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 destination range.
                        Set destrange = BaseWks.Range("B" & rnum)
                        ' Copy the values from the source range
                        ' to the destination range.
                        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 the application properties.
    With Application
        .ScreenUpdating = True
        .EnableEvents = True
        .Calculation = CalcMode
    End With
End Sub

Thanks all
 
Last edited:
Upvote 0
Hi VOG... need your help again!!

I have this code which will prompt for a source file and copy that contents to a "Master.xls" file which contains this macro. I need two tweak to this code.

1) The user should NOT be allowed to select (Master.xls) file when the browse dialog box prompts, as this is the main file that i am running the macro----- This should be either hidden in the dialog box or it should display some kind of message when user clicks on it

2) Even though the source file that is selected in the browse dialog box is open, the macro should run without any error.

Sub openfile()
Dim sFil As String
Dim sTitle As String
Dim sWb As String
Dim iFilterIndex As Integer
With Application
.ScreenUpdating = False
' Set up list of file filters
sFil = "Excel Files (*.xls),*.xls"
' Display *.xls by default
iFilterIndex = 1
' Set the dialog box caption
sTitle = "Select File to Open"
' Get the filename
On Error GoTo err_handler
sWb = Application.GetOpenFilename(sFil, iFilterIndex, sTitle)

Workbooks.Open Filename:=sWb
ActiveWorkbook.Sheets(1).UsedRange.Copy ThisWorkbook.Sheets("Operational_Tasks_Current").Range("A1")
'close source workbook
ActiveWorkbook.Close False
exit_proc:
.ScreenUpdating = True
.CutCopyMode = False

End With
Exit Sub
err_handler:
MsgBox "No selection made", vbCritical, "User Cancelled"
Resume exit_proc
End Sub
 
Upvote 0
Maybe this

Code:
Sub openfile()
Dim sFil As String
Dim sTitle As String
Dim sWb As String
Dim iFilterIndex As Integer
With Application
    .ScreenUpdating = False
    ' Set up list of file filters
    sFil = "Excel Files (*.xls),*.xls"
    ' Display *.xls by default
    iFilterIndex = 1
    ' Set the dialog box caption
    sTitle = "Select File to Open"
    ' Get the filename
    sWb = Application.GetOpenFilename(sFil, iFilterIndex, sTitle)
    If LCase(sWb) = "master.xls" Then
        MsgBox "Error: you cannot select" & sWb, vbExclamation
        Exit Sub
    End If
    If Not BookOpen(sWb) Then Workbooks.Open Filename:=sWb
    ActiveWorkbook.Sheets(1).UsedRange.Copy ThisWorkbook.Sheets("Operational_Tasks_Current").Range("A1")
    'close source workbook
    ActiveWorkbook.Close False
exit_proc:
    .ScreenUpdating = True
    .CutCopyMode = False
    
End With
Exit Sub
err_handler:
MsgBox "No selection made", vbCritical, "User Cancelled"
Resume exit_proc
End Sub

Function BookOpen(wbName As String) As Boolean
On Error Resume Next
BookOpen = Len(Workbooks(wbName).Name)
End Function
 
Upvote 0

Forum statistics

Threads
1,224,595
Messages
6,179,798
Members
452,943
Latest member
Newbie4296

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