+ Reply to Thread
Results 1 to 5 of 5

Merging 1 worksheet from multiple workbooks into a master workbook

Hybrid View

  1. #1
    Registered User
    Join Date
    06-06-2011
    Location
    UK
    MS-Off Ver
    2016
    Posts
    22

    Merging 1 worksheet from multiple workbooks into a master workbook

    Hi All,

    I'm trying to take a single worksheet from a workbook and merge them all into one workbook.
    In that master workbook I'm looking to have each of the worksheets on different tabs and the tab names as the original workbook name.

    So if I have Workbook1, Workbook2, Workbook3, Workbook4 in a folder. I want to open a new spreadsheet, run this macro, select the folder with the Workbooks in, and have it take the range selected from the worksheet 'other' from each of the workbooks and generate a 'master' Spreasheet where each tab would be called Workbook1, Workbook2, Workbook3, Workbook4 and the contents would be from the 'other' tab

    I found some of Ron de Bruin's code online which I've tried to customise.

    Currently this takes a range from the tab specified, puts it into an array and then pastes it all into different columns on one worksheet. Could someone help me change this so that it creates a new worksheet for each original workbook, and names it after that workbook.



    Sub Merge()
        Dim MyPath As String, FilesInPath As String
        Dim MyFiles() As String
        Dim SourceCcount As Long, Fnum As Long
        Dim mybook As Workbook, BaseWks As Worksheet
        Dim sourceRange As Range, destrange As Range
        Dim Cnum As Long, CalcMode As Long
    
        'File path
        MyPath = "C:\My files\"
    
        'Add ending slash
        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(1)
        Cnum = 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
                    Set sourceRange = mybook.Worksheets("other").Range("A1:J20")
    
                    If Err.Number > 0 Then
                        Err.Clear
                        Set sourceRange = Nothing
                    Else
                        'if SourceRange use all rows then skip this file
                        If sourceRange.Rows.Count >= BaseWks.Rows.Count Then
                            Set sourceRange = Nothing
                        End If
                    End If
                    On Error GoTo 0
    
                    If Not sourceRange Is Nothing Then
    
                        SourceCcount = sourceRange.Columns.Count
    
                        If Cnum + SourceCcount >= BaseWks.Columns.Count Then
                            MsgBox "Sorry there are not enough columns in the sheet"
                            BaseWks.Columns.AutoFit
                            mybook.Close savechanges:=False
                            GoTo ExitTheSub
                        Else
    
                            'Copy the file name in the first row
                            With sourceRange
                                BaseWks.Cells(1, Cnum). _
                                        Resize(, .Columns.Count).Value = MyFiles(Fnum)
                            End With
    
                            'Set the destrange
                            Set destrange = BaseWks.Cells(2, Cnum)
    
                            '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
    
                            Cnum = Cnum + SourceCcount
                        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 neato; 04-08-2014 at 09:24 AM. Reason: Forgot to add code owner

  2. #2
    Forum Expert
    Join Date
    10-09-2012
    Location
    Dallas, Texas
    MS-Off Ver
    MO 2010 & 2013
    Posts
    3,049

    Re: Merging 1 worksheet from multiple workbooks into a master workbook

    So I would suggest stepping through your problems piece by piece so you can solve them.
    There is value in looking at the entire process at once, BUT I highly suggest you work through each problem to get a solution and THEN start tweaking for efficiency.


    So what I have done with things like this in the past is create two macros, one to list all the foldes in a file and another to actually process the data listed from the other macro. These keeps the code more simple for those just starting out with VBA (like myself) and keeps it easier to audit as well.
    Please ensure you mark your thread as Solved once it is. Click here to see how.
    If a post helps, please don't forget to add to our reputation by clicking the star icon in the bottom left-hand corner of a post.

  3. #3
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Merging 1 worksheet from multiple workbooks into a master workbook

    'WORKBOOKS TO SHEETS
    Here's a base macro for collecting data from all files in a specific folder. This version copies the sheet in as a whole.The parts of the code that need to be edited are colored to draw your attention.
    Last edited by JBeaucaire; 12-27-2019 at 03:55 AM.
    _________________
    Microsoft MVP 2010 - Excel
    Visit: Jerry Beaucaire's Excel Files & Macros

    If you've been given good help, use the icon below to give reputation feedback, it is appreciated.
    Always put your code between code tags. [CODE] your code here [/CODE]

    ?None of us is as good as all of us? - Ray Kroc
    ?Actually, I *am* a rocket scientist.? - JB (little ones count!)

  4. #4
    Registered User
    Join Date
    06-06-2011
    Location
    UK
    MS-Off Ver
    2016
    Posts
    22

    Re: Merging 1 worksheet from multiple workbooks into a master workbook

    This is great thanks Jerry.

    I've tried using your 'Open all files and copy sheet as a whole', however, I'm having issues when renaming the sheet as our files have names over 31 characters long.

    Do you happen to know how I could get around this? Or would we need to make a change in our naming conventions.

    Thanks again for your help!

  5. #5
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Merging 1 worksheet from multiple workbooks into a master workbook

    Yes, let's update the LEFT function to first strip off the extension and then only use the first 29 characters:

        ShtAdd = Left(Left(fname, InStrRev(fname, ".") - 1), 29)

    That should work better. I'll update the code on the site, too.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. [SOLVED] Merging several workbooks into 1 master workbook?
    By WGBarry in forum Excel Programming / VBA / Macros
    Replies: 12
    Last Post: 01-13-2014, 08:10 PM
  2. Merging multiple excel files in a folder into one master worksheet in a new worksheet
    By johnny_canuck in forum Excel Programming / VBA / Macros
    Replies: 13
    Last Post: 08-22-2013, 12:20 PM
  3. Merging multiple workbooks on to one master workbook
    By inkandpaint in forum Excel Programming / VBA / Macros
    Replies: 8
    Last Post: 06-15-2012, 01:22 PM
  4. Merging multiple workbooks (with multiple worksheets) in to one master sheet
    By inkandpaint in forum Excel Programming / VBA / Macros
    Replies: 5
    Last Post: 05-22-2012, 09:46 AM
  5. [SOLVED] Merging multiple workbooks into one master workbook
    By sumichung@gmail.com in forum Excel General
    Replies: 2
    Last Post: 05-26-2006, 01:35 AM

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1