Answered by:
VBA code for combining multiple workbooks into one workbook with multiple worksheets

Question
-
Hi,
I have the following code for creating one workbook from multiple Excel files, which works fine. But I need to take individual data from each of the workbooks and add them to different worksheets in one workbook. Below is the code I have already but I'm unable to code for it to take another line of data from the Excel files and add it to a different worksheet in the same workbook.
Hope this makes sense. Can anyone please help? Thanks
Sub MergeAllWorkbooks() 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 ' Create a new workbook and set a variable to the first sheet. Set SummarySheet = Workbooks.Add(xlWBATWorksheet).Worksheets(1) ' Modify this folder path to point to the files you want to use. FolderPath = "C:\Filepath\" ' NRow keeps track of where to insert new rows in the destination workbook. NRow = 1 ' Call Dir the first time, pointing it to all Excel files in the folder path. FileName = Dir(FolderPath & "*.xls*") ' Loop until Dir returns an empty string. Do While FileName <> "" ' Open a workbook in the folder Set WorkBk = Workbooks.Open(FolderPath & FileName) ' Set the source range. Set SourceRange = WorkBk.Worksheets("DR02").Range("E20:M20") ' Set the destination range to start at column B and ' be the same size as the source range. Set DestRange = SummarySheet.Range("B" & NRow) Set DestRange = DestRange.Resize(SourceRange.Rows.Count, _ SourceRange.Columns.Count) ' Copy over the values from the source to the destination. DestRange.Value = SourceRange.Value ' Increase NRow so that we know where to copy data next. NRow = NRow + DestRange.Rows.Count ' 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 End Sub
Thursday, April 23, 2015 10:42 AM
Answers
-
This code will work for two sheets - hope you see the pattern: Option Explicit Sub MergeAllWorkbooks2() Dim wbSummary As Workbook Dim SummarySheet As Worksheet Dim OtherSheet As Worksheet Dim FolderPath As String Dim NRow As Long Dim NRow2 As Long Dim FileName As String Dim WorkBk As Workbook Dim SourceRange As Range Dim DestRange As Range ' Create a new workbook and set a variable to the first sheet. Set wbSummary = Workbooks.Add(xlWBATWorksheet) Set SummarySheet = wbSummary.Worksheets(1) SummarySheet.Name = "Summary Sheet" Set OtherSheet = wbSummary.Worksheets.Add(after:=SummarySheet) OtherSheet.Name = "Other Sheet" wbSummary.SaveAs ThisWorkbook.Path & "\Summary.xlsx", FileFormat:=51 ' Modify this folder path to point to the files you want to use. FolderPath = "C:\Filepath\" ' NRow keeps track of where to insert new rows in the destination workbook. NRow = 1 NRow2 = 1 ' Call Dir the first time, pointing it to all Excel files in the folder path. FileName = Dir(FolderPath & "*.xls*") ' Loop until Dir returns an empty string. Do While FileName <> "" ' Open a workbook in the folder If FileName <> ThisWorkbook.Name And FileName <> "Summary.xlsx" Then Set WorkBk = Workbooks.Open(FolderPath & FileName) 'Block of code to copy one range to the summary sheet ' Set the source range for the first copy. Set SourceRange = WorkBk.Worksheets("DR02").Range("E20:M20") ' Set the destination range to start at column B and ' be the same size as the source range. Set DestRange = SummarySheet.Range("B" & NRow) Set DestRange = DestRange.Resize(SourceRange.Rows.Count, _ SourceRange.Columns.Count) ' Copy over the values from the source to the destination. DestRange.Value = SourceRange.Value ' Increase NRow so that we know where to copy data next. NRow = NRow + DestRange.Rows.Count 'Block of code to copy the second range to the other sheet ' Set the source range for the second copy. Set SourceRange = WorkBk.Worksheets("DR02").Range("E21:M21") ' Set the destination range to start at column B and ' be the same size as the source range. Set DestRange = OtherSheet.Range("B" & NRow2) Set DestRange = DestRange.Resize(SourceRange.Rows.Count, _ SourceRange.Columns.Count) ' Copy over the values from the source to the destination. DestRange.Value = SourceRange.Value ' Increase NRow so that we know where to copy data next. NRow2 = NRow2 + DestRange.Rows.Count ' Close the source workbook without saving changes. WorkBk.Close savechanges:=False ' Use Dir to get the next file name. End If FileName = Dir() Loop ' Call AutoFit on the destination sheet so that all ' data is readable. SummarySheet.Columns.AutoFit OtherSheet.Columns.AutoFit End Sub
- Edited by Bernie Deitrick, Excel MVP 2000-2010 Thursday, April 23, 2015 1:32 PM
- Marked as answer by Verity26 Thursday, April 23, 2015 2:38 PM
Thursday, April 23, 2015 1:29 PM
All replies
-
This code will work for two sheets - hope you see the pattern: Option Explicit Sub MergeAllWorkbooks2() Dim wbSummary As Workbook Dim SummarySheet As Worksheet Dim OtherSheet As Worksheet Dim FolderPath As String Dim NRow As Long Dim NRow2 As Long Dim FileName As String Dim WorkBk As Workbook Dim SourceRange As Range Dim DestRange As Range ' Create a new workbook and set a variable to the first sheet. Set wbSummary = Workbooks.Add(xlWBATWorksheet) Set SummarySheet = wbSummary.Worksheets(1) SummarySheet.Name = "Summary Sheet" Set OtherSheet = wbSummary.Worksheets.Add(after:=SummarySheet) OtherSheet.Name = "Other Sheet" wbSummary.SaveAs ThisWorkbook.Path & "\Summary.xlsx", FileFormat:=51 ' Modify this folder path to point to the files you want to use. FolderPath = "C:\Filepath\" ' NRow keeps track of where to insert new rows in the destination workbook. NRow = 1 NRow2 = 1 ' Call Dir the first time, pointing it to all Excel files in the folder path. FileName = Dir(FolderPath & "*.xls*") ' Loop until Dir returns an empty string. Do While FileName <> "" ' Open a workbook in the folder If FileName <> ThisWorkbook.Name And FileName <> "Summary.xlsx" Then Set WorkBk = Workbooks.Open(FolderPath & FileName) 'Block of code to copy one range to the summary sheet ' Set the source range for the first copy. Set SourceRange = WorkBk.Worksheets("DR02").Range("E20:M20") ' Set the destination range to start at column B and ' be the same size as the source range. Set DestRange = SummarySheet.Range("B" & NRow) Set DestRange = DestRange.Resize(SourceRange.Rows.Count, _ SourceRange.Columns.Count) ' Copy over the values from the source to the destination. DestRange.Value = SourceRange.Value ' Increase NRow so that we know where to copy data next. NRow = NRow + DestRange.Rows.Count 'Block of code to copy the second range to the other sheet ' Set the source range for the second copy. Set SourceRange = WorkBk.Worksheets("DR02").Range("E21:M21") ' Set the destination range to start at column B and ' be the same size as the source range. Set DestRange = OtherSheet.Range("B" & NRow2) Set DestRange = DestRange.Resize(SourceRange.Rows.Count, _ SourceRange.Columns.Count) ' Copy over the values from the source to the destination. DestRange.Value = SourceRange.Value ' Increase NRow so that we know where to copy data next. NRow2 = NRow2 + DestRange.Rows.Count ' Close the source workbook without saving changes. WorkBk.Close savechanges:=False ' Use Dir to get the next file name. End If FileName = Dir() Loop ' Call AutoFit on the destination sheet so that all ' data is readable. SummarySheet.Columns.AutoFit OtherSheet.Columns.AutoFit End Sub
- Edited by Bernie Deitrick, Excel MVP 2000-2010 Thursday, April 23, 2015 1:32 PM
- Marked as answer by Verity26 Thursday, April 23, 2015 2:38 PM
Thursday, April 23, 2015 1:29 PM -
Great thanks that worked perfectlyThursday, April 23, 2015 2:38 PM