Struggling To Amend Code

BeBop9236

New Member
Joined
Jun 24, 2019
Messages
1
I'm new to using VBA, but I found the code shown below on the internet which allows you to select specific files that you choose and copy the data into a new file which is used as a summary.

Firstly, I need to amend the code so that rather than create a new file it pastes the data into a sheet in the current file called sheet11.

Secondly, the range that is being copied needs to be dynamic, the number of columns will remain the same, however the number of rows will change between files.

Thanks in advance

Sub MergeSpecificWorkbooks()
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

Dim GetBook As String

GetBook = ActiveWorkbook.Name




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


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


FName = Application.GetOpenFilename(filefilter:="Excel Files (*.csv*), *.csv*", _
MultiSelect:=True)
If IsArray(FName) Then


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




'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(1)
Set sourceRange = .Range("A1:F1000")
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("A" & 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
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
something like this:
Code:
Option Explicit


Sub MergeSpecificWorkbooks()
    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
    Dim GetBook As String
    Const WshName = "Sheet11"
    Dim wbk As Workbook
    
    Set wbk = ActiveWorkbook
    
    GetBook = ActiveWorkbook.Name
    
    'Change ScreenUpdating, Calculation and EnableEvents
    With Application
        CalcMode = .Calculation
        .Calculation = xlCalculationManual
        .ScreenUpdating = False
        .EnableEvents = False
    End With
    
    SaveDriveDir = CurDir
    ChDir "C:\Users\test"
    
    FName = Application.GetOpenFilename(filefilter:="Excel Files (*.csv*), *.csv*", MultiSelect:=True)
    If IsArray(FName) Then
''        'Add a new workbook with one sheet
''        Set BaseWks = Workbooks.Add(xlWBATWorksheet).Worksheets(1)
        On Error Resume Next
        Set BaseWks = wbk.Worksheets(WshName)
        If BaseWks Is Nothing Then
            Set BaseWks = wbk.Worksheets.Add
            BaseWks.Name = WshName
        End If
        rnum = 1
        
        '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))
            
            If Not mybook Is Nothing Then
                With mybook.Worksheets(1)
                    Set sourceRange = Intersect(.Range("A:F"), .UsedRange)
                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("A" & rnum)
                        
                        'we copy the values from the sourceRange to the destrange
                        With sourceRange
''                            Set destrange = destrange.Resize(.Rows.Count, .Columns.Count)
                            Set destrange = destrange.Resize(SourceRcount, .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
    ChDir SaveDriveDir
End Sub
you can set wbk to ThisWorkbook instead of ActiveWorkbook.

I replaced ChDirNet with ChDir.
However If you are using Chdir across drives you have to combine it with ChDrive.
 
Upvote 0

Forum statistics

Threads
1,224,829
Messages
6,181,222
Members
453,024
Latest member
Wingit77

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