Fastest Way to copy all formulas from one workbook to another

nyconfidential

New Member
Joined
Jul 22, 2015
Messages
49
Office Version
  1. 365
  2. 2016
Hi - I've been tasked with finding a way to copy all of the formulas from one workbook(that has all the correct formulas and links) to another workbook(it's an exact copy of the first workbook, but it contains lots of broken formula links). I'm able to do it using the code below - basically I'm looping through each cell in the clean workbook, copying it's formula, then setting the formula in the accompanying cell in the workbook with the broken formulas. Seems to work ok - but I'd like it to be faster(the Workbooks have 60+ sheets). Is there a faster alternative? Would sticking the formulas in Variant arrays speed things up?

Code:
For Each rCell In rRng.Cells ' Loop through a list of all the Worksheets    
     If SheetExists(rCell.Value) = True Then
            Application.DisplayAlerts = False
            Application.ScreenUpdating = False
            frmlaCnt = ThisWorkbook.Sheets(rCell.Value).Cells.SpecialCells(xlCellTypeFormulas).Count
            If frmlaCnt > 0 Then
                For Each r In ThisWorkbook.Sheets(rCell.Value).Cells.SpecialCells(xlCellTypeFormulas)
                    ActiveWorkbook.Sheets(rCell.Value).Range(r.Address).Formula _
                    = ThisWorkbook.Sheets(rCell.Value).Range(r.Address).Formula
                Next r
            End If
    End If
    Debug.Print rCell.Value & " " & frmlaCnt
    ActiveWorkbook.Sheets(rCell.Value).Calculate
Next rCell
 
Last edited:

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes
Would sticking the formulas in Variant arrays speed things up?
Yes very much so
this code will copy all formula from sheet 1 to sheet 2 of a workbook, this shows you how to do the whole sheet in one action rather than cell by cell.
Code:
inarr = Worksheets("sheet1").UsedRange.Formula

 With Worksheets("Sheet2")
 Range(.Cells(1, 1), .Cells(UBound(inarr, 1), UBound(inarr, 2))) = inarr
 End With
 
Upvote 0

Forum statistics

Threads
1,214,787
Messages
6,121,569
Members
449,038
Latest member
Guest1337

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