Consulting

Page 1 of 2 1 2 LastLast
Results 1 to 20 of 22

Thread: Solved: Merging a specific worksheet from multiple workbooks into one

  1. #1
    VBAX Mentor
    Joined
    May 2010
    Location
    London
    Posts
    307
    Location

    Solved: Merging a specific worksheet from multiple workbooks into one

    Hi All ,

    I need to pull data from 50 xls files into 1. Each workbook has same format and data I need to pull is saved in a specific worksheet in each workbook.

    I've checked Knowledge Base and found the code below. This one combines multiple workbooks into one by adding worksheets separately.

    http://www.vbaexpress.com/forum/showthread.php?t=39604

    What I need is merging a specific worksheet from multiple workbooks into one. Master copy of 50 xls files would be cumulative so data from individual copies needs to be merged to end of the list in master worksheet. I was wondering if there is any written code I could use to do this?

    your help is appreciated.

    Cheers
    Yeliz

  2. #2
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    [vba]

    Public Sub MergeWorkbooks()
    Const ROOT_FOLDER As String = "C:\temp\"
    Dim wbTarget As Workbook
    Dim Filename As String
    Dim filenames As Variant
    Dim numrows As Long
    Dim nextrow As Long

    Set wbTarget = Workbooks.Add

    Filename = Dir(ROOT_FOLDER & "*.xls*")
    ReDim filenames(1 To 1)

    nextrow = 1
    Do While Filename <> ""

    Workbooks.Open Filename
    With ActiveWorkbook

    With .Worksheets(1)

    numrows = .Cells(.Rows.Count, "A").End(xlUp).Row
    .Rows(1).Resize(numrows).Copy wbTarget.Worksheets(1).Cells(nextrow, "A")
    nextrow = nextrow + numrows
    End With

    .Close SaveChanges:=False
    End With

    Filename = Dir
    Loop

    'do something with wbTarget
    End Sub[/vba]
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  3. #3
    VBAX Mentor
    Joined
    May 2010
    Location
    London
    Posts
    307
    Location
    Thanks very much for express response!..

    I guess I don't need to define file names for 50 xls. This code would run for all xls files under specified folder, am I right?

    Each xls file has more than 1 worksheet however the tabs are named same in each workbook. How can I specify the worksheet I need to merge by using this code? do I need to edit this bit?

    With .Worksheets(1)

    Sorry I am vba newbie and taking a course early march so it would make better sense after that :o)

  4. #4
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    You mean that the data from say worksheets ABC gets appended to worksheets ABC, XYZ to XYZ etc.? Do you have a workbook that they get appended to already or do we create a new one dynamically?
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  5. #5
    VBAX Mentor
    Joined
    May 2010
    Location
    London
    Posts
    307
    Location
    hmm I see what you mean..It doesn't need to be dynamic. Let's say each xls file has 3 tabs. called A, B, C. I want to pull the data from worksheet A only from 50 xls files. I guess I need to specify the worksheet as Worksheet(A)..

    sorry if this doesn't make sense :o)

  6. #6
    Administrator
    VP-Knowledge Base
    VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    Put the name in quotes
    [VBA]With .Worksheets("A")[/VBA]
    MVP (Excel 2008-2010)

    Post a workbook with sample data and layout if you want a quicker solution.


    To help indent your macros try Smart Indent

    Please remember to mark threads 'Solved'

  7. #7
    VBAX Mentor
    Joined
    May 2010
    Location
    London
    Posts
    307
    Location
    thanks very much!!

  8. #8
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    So are you sorted now Yeliz?
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  9. #9
    VBAX Mentor
    Joined
    May 2010
    Location
    London
    Posts
    307
    Location
    Quote Originally Posted by xld
    So are you sorted now Yeliz?
    I've run the macro and it just created new workbook which is blank :o)

    I did copy this below code into master file and edited file address and worksheet name. It didn't work. I don't know what went wrong as it didn't give me an error. It just opened a blank workbook.

    [VBA]
    Public Sub MergeWorkbooks()
    Const ROOT_FOLDER As String = "C:\HPOD\Individual Copies"
    Dim wbTarget As Workbook
    Dim Filename As String
    Dim filenames As Variant
    Dim numrows As Long
    Dim nextrow As Long

    Set wbTarget = Workbooks.Add

    Filename = Dir(ROOT_FOLDER & "*.xls*")
    ReDim filenames(1 To 1)

    nextrow = 1
    Do While Filename <> ""

    Workbooks.Open Filename
    With ActiveWorkbook

    With .Worksheets("H - POD")

    numrows = .Cells(.Rows.Count, "A").End(xlUp).Row
    .Rows(1).Resize(numrows).Copy wbTarget.Worksheets(1).Cells(nextrow, "A")
    nextrow = nextrow + numrows
    End With

    .Close SaveChanges:=False
    End With

    Filename = Dir
    Loop

    'do something with wbTarget
    End Sub[/VBA]
    Last edited by Bob Phillips; 02-07-2012 at 08:58 AM. Reason: Added VBA tags

  10. #10
    VBAX Guru mancubus's Avatar
    Joined
    Dec 2010
    Location
    "Where I lay my head is home" :D
    Posts
    2,644
    change
    [VBA]Const ROOT_FOLDER As String = "C:\HPOD\Individual Copies"[/VBA]


    to
    [VBA]Const ROOT_FOLDER As String = "C:\HPOD\Individual Copies\"[/VBA]
    PLS DO NOT PM; OPEN A THREAD INSTEAD!!!

    1) Posting Code
    [CODE]PasteYourCodeHere[/CODE]
    (or paste your code, select it, click # button)

    2) Uploading File(s)
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) (multiple files can be selected while holding Ctrl key) / Upload Files / Done
    Replace company specific / sensitive / confidential data. Include so many rows and sheets etc in the uploaded workbook to enable the helpers visualize the data and table structure. Helpers do not need the entire workbook.

    3) Testing the Codes
    always back up your files before testing the codes.

    4) Marking the Thread as Solved
    from Thread Tools (on the top right corner, above the first message)

  11. #11
    VBAX Mentor
    Joined
    May 2010
    Location
    London
    Posts
    307
    Location
    when I add \ to folder address then it gives run time error 1004 saying ;

    H-POD_S1_v01.t1.xls could not be found. Check the spelling of the file name, and verify that the file location is correct.

    I didn't specify any file name in the code as I thought all xls files would be included under the folder. I don't know what's causing this error :|

  12. #12
    Administrator
    VP-Knowledge Base VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    [VBA]Workbooks.Open ROOT_FOLDER & Filename [/VBA]
    MVP (Excel 2008-2010)

    Post a workbook with sample data and layout if you want a quicker solution.


    To help indent your macros try Smart Indent

    Please remember to mark threads 'Solved'

  13. #13
    VBAX Mentor
    Joined
    May 2010
    Location
    London
    Posts
    307
    Location
    Quote Originally Posted by mdmackillop
    [vba]Workbooks.Open ROOT_FOLDER & Filename [/vba]

    Thanks for your reply. I have 50 xls files to merge so do I need to write all file names in code?

    Cheers
    Yeliz

  14. #14
    VBAX Guru mancubus's Avatar
    Joined
    Dec 2010
    Location
    "Where I lay my head is home" :D
    Posts
    2,644
    "Filename" is a variable for all file names, which is:

    [vba]Filename = Dir(ROOT_FOLDER & "*.xls*")[/vba]

    [vba]Do While Filename <> ""
    [/vba]
    tells excel loop all files in the folder...

    so just change the line in your post to the line in MD's post..
    PLS DO NOT PM; OPEN A THREAD INSTEAD!!!

    1) Posting Code
    [CODE]PasteYourCodeHere[/CODE]
    (or paste your code, select it, click # button)

    2) Uploading File(s)
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) (multiple files can be selected while holding Ctrl key) / Upload Files / Done
    Replace company specific / sensitive / confidential data. Include so many rows and sheets etc in the uploaded workbook to enable the helpers visualize the data and table structure. Helpers do not need the entire workbook.

    3) Testing the Codes
    always back up your files before testing the codes.

    4) Marking the Thread as Solved
    from Thread Tools (on the top right corner, above the first message)

  15. #15
    VBAX Mentor
    Joined
    May 2010
    Location
    London
    Posts
    307
    Location
    mancubus thanks very much for your response and for the explanation as well..

    I did change the line as
    Workbooks.Open ROOT_FOLDER & Filename
    now macro is running but because of format issues it didn't work as I expected. It opens a new workbook and pulls data from first file then stops. I guess I need to verify columns as each worksheet has same format and same formula settings then this causing overlap etc..

    I attached 3 sample files to explain the problem. 1 xlsm file which is master copy, 2 xls to extract data from.

    I appreciate for your patience.

    Cheers
    Yeliz





    Quote Originally Posted by mancubus
    "Filename" is a variable for all file names, which is:

    [vba]Filename = Dir(ROOT_FOLDER & "*.xls*")[/vba]

    [vba]Do While Filename <> ""
    [/vba] tells excel loop all files in the folder...

    so just change the line in your post to the line in MD's post..
    Attached Files Attached Files

  16. #16
    VBAX Guru mancubus's Avatar
    Joined
    Dec 2010
    Location
    "Where I lay my head is home" :D
    Posts
    2,644
    worksheets are protected.
    your tables' topleft cells are not "A1"
    blah blah blah

    so i recommend you use ron de bruin's code below.

    that code will consolidate worksheets "H-POD" of all files that you selected from folder in one worksheet named "Master".

    if you like consolidating in a new blank workbook then delete leading ' (single quote) in the following line
    [vba] 'Set BaseWks = Workbooks.Add(xlWBATWorksheet).Worksheets(1)
    [/vba]
    and add a ' (single quote) in the following lines
    [vba] Set BaseWks = Worksheets.Add
    BaseWks.Name = "Master"
    [/vba]

    tested with your files and that's ok.


    this bit of the code adds workbooks' names in column A.
    [vba]
    'Copy the file name in column A
    With sourceRange
    BaseWks.Cells(rnum, "A"). _
    Resize(.Rows.Count).Value = FName(FNum)
    End With
    [/vba]
    you may delete this bit if you don't want file names...

    in this case change "B" to "A" in this line:
    [vba]
    'Set the destrange
    Set destrange = BaseWks.Range("B" & rnum)
    [/vba]


    (copy the header row manually...)



    [vba]
    Sub MergeSpecificWorkbooks()
    'http://www.rondebruin.nl/copy3.htm

    Dim MyPath 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 SaveDriveDir As String
    Dim FName As Variant

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

    ' SaveDriveDir = CurDir
    ' ChDirNet "C:\Users\Ron\test"

    FName = Application.GetOpenFilename(filefilter:="Excel Files (*.xl*), *.xl*", _
    MultiSelect:=True)
    If IsArray(FName) Then
    'Add a new workbook with one sheet
    'Set BaseWks = Workbooks.Add(xlWBATWorksheet).Worksheets(1)
    Set BaseWks = Worksheets.Add
    BaseWks.Name = "Master"
    rnum = 2

    'Loop through all files in the array(myFiles)
    For FNum = LBound(FName) To UBound(FName)
    Set mybook = Nothing
    On Error Resume Next
    Set mybook = Workbooks.Open(FName(FNum))
    On Error GoTo 0
    If Not mybook Is Nothing Then
    On Error Resume Next
    With mybook.Worksheets("H-POD")
    .Unprotect
    LC = .Cells(.Rows.Count, "C").End(xlUp).Row
    Set sourceRange = .Range("B10:M" & LC)
    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 = FName(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

    ' ChDirNet SaveDriveDir

    End Sub
    [/vba]
    PLS DO NOT PM; OPEN A THREAD INSTEAD!!!

    1) Posting Code
    [CODE]PasteYourCodeHere[/CODE]
    (or paste your code, select it, click # button)

    2) Uploading File(s)
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) (multiple files can be selected while holding Ctrl key) / Upload Files / Done
    Replace company specific / sensitive / confidential data. Include so many rows and sheets etc in the uploaded workbook to enable the helpers visualize the data and table structure. Helpers do not need the entire workbook.

    3) Testing the Codes
    always back up your files before testing the codes.

    4) Marking the Thread as Solved
    from Thread Tools (on the top right corner, above the first message)

  17. #17
    VBAX Mentor
    Joined
    May 2010
    Location
    London
    Posts
    307
    Location
    Thank you so much mancubus!! This is exactly what I was looking for. It's working perfect..

    I'll be more careful next time about table format..

    Cheers
    Yeliz

  18. #18
    VBAX Guru mancubus's Avatar
    Joined
    Dec 2010
    Location
    "Where I lay my head is home" :D
    Posts
    2,644
    you're wellcome.

    but i just copied the code and adopted a few lines of it to your table structure.
    PLS DO NOT PM; OPEN A THREAD INSTEAD!!!

    1) Posting Code
    [CODE]PasteYourCodeHere[/CODE]
    (or paste your code, select it, click # button)

    2) Uploading File(s)
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) (multiple files can be selected while holding Ctrl key) / Upload Files / Done
    Replace company specific / sensitive / confidential data. Include so many rows and sheets etc in the uploaded workbook to enable the helpers visualize the data and table structure. Helpers do not need the entire workbook.

    3) Testing the Codes
    always back up your files before testing the codes.

    4) Marking the Thread as Solved
    from Thread Tools (on the top right corner, above the first message)

  19. #19
    VBAX Guru mancubus's Avatar
    Joined
    Dec 2010
    Location
    "Where I lay my head is home" :D
    Posts
    2,644
    re to pm:

    it worked with 15 sample files... three of them contain only headers...

    for any updates, just select the new files after running the macro... the code adds new records from to the bottom of "Master" sheet.

    keep worksheet H-POD in master.xlsm, from which the code retrieves the headers...

    the code checks the existence of records from column C and row 10.
    Attached Files Attached Files
    PLS DO NOT PM; OPEN A THREAD INSTEAD!!!

    1) Posting Code
    [CODE]PasteYourCodeHere[/CODE]
    (or paste your code, select it, click # button)

    2) Uploading File(s)
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) (multiple files can be selected while holding Ctrl key) / Upload Files / Done
    Replace company specific / sensitive / confidential data. Include so many rows and sheets etc in the uploaded workbook to enable the helpers visualize the data and table structure. Helpers do not need the entire workbook.

    3) Testing the Codes
    always back up your files before testing the codes.

    4) Marking the Thread as Solved
    from Thread Tools (on the top right corner, above the first message)

  20. #20
    VBAX Mentor
    Joined
    May 2010
    Location
    London
    Posts
    307
    Location
    It worked with 51 xls. Brilliant! Thanks again for your time, much appreciated.
    Sub Learning VBA()

    Do
    Practice Most Useful VBA Examples
    Loop Until Become an Expert in VBA

    End Sub

Posting Permissions

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