Combine specific rows from multiple workbook in to one workbook

mattf731

New Member
Joined
Oct 25, 2017
Messages
4
Hi all,

I have a listing of approximately 150 workbooks where I'd like to combine a set of rows (non-consecutive rows) from each workbook into a new summary workbook. I'm able to combine consecutive rows, but when I try to separate the rows needed, thus far I am only able to merge in the first row into my new workbook. I know I'm close, but I just can't seem to figure out the final steps (my apologies as I'm fairly new to VBA).

Sub MergeAllWorkbooks()
Dim MyValue As Variant
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


MyValue = InputBox("Input file path where all forms are saved")
MyPath = MyValue


' 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
.DisplayAlerts = False

End With


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


' 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


' This is where I'm having trouble - it is only copying row 21 from each workbook.
With mybook.Worksheets(1)
Set sourceRange = .Range("A21:Z21,A41:Z41,A45:Z45,A57:Z57,A61:Z61,A70:Z70")
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
.DisplayAlerts = True

End With
End Sub
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
How about
Code:
Sub MergeAllWorkbooks()

    Dim MyPath As String, FilesInPath As String
    Dim mybook As Workbook, BaseWks As Worksheet
    Dim destrange As Range
    Dim rnum As Long, CalcMode As Long
    Dim SrcAr As Areas
    Dim Rng As Range
    
    ' Set various application properties.
    With Application
        CalcMode = .Calculation
        .Calculation = xlCalculationManual
        .ScreenUpdating = False
        .EnableEvents = False
        .DisplayAlerts = False
    End With
    
    MyPath = InputBox("Input file path where all forms are saved")
    
    ' 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
    
    Set BaseWks = Workbooks.Add(xlWBATWorksheet).Worksheets(1)
    rnum = 1

    ' Fill the myFiles array with the list of Excel files
    ' in the search folder.
    Do While FilesInPath <> ""
        Set mybook = Nothing
        Set mybook = Workbooks.Open(FilesInPath)
        With mybook.Worksheets(1)
            Set SrcAr = .Range("A21:Z21,A41:Z41,A45:Z45,A57:Z57,A61:Z61,A70:Z70").Areas
        End With
        
        Set destrange = BaseWks.Range("B" & rnum)
        
        For Each Rng In SrcAr
            destrange.Offset(rnum - 1).Resize(, 26).Value = Rng.Value
            rnum = rnum + 1
        Next Rng
        
        Application.DisplayAlerts = False
        mybook.Close , False
        Application.DisplayAlerts = True
        
        FilesInPath = Dir()
        
        If rnum > BaseWks.Range("B" & Rows.Count).Row - 6 Then
            MsgBox "Process stopped, insufficient space left in sheet"
            Exit Do
        End If
    Loop
    
    BaseWks.Columns.AutoFit
    
    ' Restore the application properties.
    With Application
    .ScreenUpdating = True
    .EnableEvents = True
    .Calculation = CalcMode
    .DisplayAlerts = True
    End With
    
End Sub
 
Last edited:
Upvote 0
Thanks! I was able to get this to work after a couple attempts. At first, I kept getting an error that the file path could not be found for the first excel file within the folder (thus was not able to run for the remaining files). I opened up the file to verify that I was able to get in, closed the file (without saving), and re-ran the macro and it worked like a charm.

I'm not sure why the error occurred on the first attempt, but it all ended up working out.

Thanks for your help and quick response!
Matt
 
Upvote 0
Glad you got it sorted & thanks for the feedback
 
Upvote 0

Forum statistics

Threads
1,223,238
Messages
6,170,939
Members
452,368
Latest member
jayp2104

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