formulas use source row instead of destination row

bar21967

New Member
Joined
May 16, 2011
Messages
8
Office Version
  1. 365
Platform
  1. Windows
The following macro seems to work well except for the formulas copied from source files and pasted to the destination summary file.

Is the formula from source file is T13/U13 it remains the same when pasted to row 43 of the destination workbook instead of changing to T43/U43.

Does anyone have an idea how to make this work?

Code:
Sub MergeAllWorkbooks()
'
' Macro written by Ron de Bruin and adapted by Barbara Oesch 08/28/2011
'
    Dim FirstCell As String
    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
    Dim i As Long
 
Call UnProtectSheets
    ' Change this to the path\folder location of your files.
    MyPath = InputBox("Identify the path to rollup.", "Rollup Path", "C:\Combine\")
    ' 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 & "*.xls")
    If FilesInPath = "" Then
            Call ProtectSheets
        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
    End With
    ' Select Active Sheet in macro file.
    Sheets("Salary Recommendation").Select
    Set BaseWks = ActiveSheet
    rnum = 11
    ' Loop through all files in the myFiles array.
FilesInPath = Dir(MyPath & "*.xls")
    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
                ' Change this range to fit your own needs.
                With mybook.Worksheets("Salary Recommendation")
                   FirstCell = "A11"
                   Set sourceRange = .Range(FirstCell & ":" & RDB_Last(3, .Cells))
                   ' Test if the row of the last cell is equal to or greater than the row of the first cell.
                   If RDB_Last(1, .Cells) < .Range(FirstCell).Row Then
                      Set sourceRange = Nothing
                   End If
                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
                        ' Set the destination range.
                        Set destrange = BaseWks.Range("A" & 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.Formula = sourceRange.Formula
                        rnum = rnum + SourceRcount
                    End If
                End If
                mybook.Close savechanges:=False
            End If
        Next FNum
        BaseWks.Columns.AutoFit
        delRows
    End If
ExitTheSub:
    ' Restore the application properties.
    With Application
        .ScreenUpdating = True
        .EnableEvents = True
        .Calculation = xlCalculationAutomatic
    End With
'
    Sheets("Salary Recommendation").Select
        Form1.Hide
        MsgBox "Rollup Complete"
'
Call ProtectSheets
'
End Sub
 

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.
Try this.

Code:
destrange.FormulaR1C1 = sourceRange.FormulaR1C1

Absolute references will not change. Relative reference will change.
 
Upvote 0
destrange.FormulaR1C1 = sourceRange.FormulaR1C1

Worked like a charm!

Thank you so much for your help.<!-- / message --><!-- sig -->
 
Upvote 0

Forum statistics

Threads
1,203,686
Messages
6,056,736
Members
444,887
Latest member
cvcc_wt

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