Kevin
Have forgotten where I found this code so cannot give attribution to rightful
creator.
Sub CopyFormulasExact()
Dim rngCopyFrom As Range
Dim rngCopyTo As Range
Dim intColCount As Integer
Dim intRowCount As Integer
' Check that a range is selected
If Not TypeName(Selection) = "Range" Then End
' check that the range has only one area
If Not Selection.Areas.Count = 1 Then
MsgBox "Multiple Selections Not Allowed", vbExclamation
End
End If
' Assign selection to object variable
Set rngCopyFrom = Selection
If Not Selection.HasFormula Then
MsgBox "Cells do not contain formulas"
End
End If
' This is required in case cancel is clicked.
' Type 8 input box returns a range object if OK is
' clicked or False if cancel is clicked. I do not
' know of a way to test for both cases without
' using error trapping
On Error GoTo UserCancelled
' Assign object variable to user-selected cell
Set rngCopyTo = Application.InputBox( _
prompt:="Select the UPPER LEFT CELL of the " _
& "range to which you wish to paste", _
Title:="Copy Range Formulae", Type:=8).Cells(1, 1)
On Error GoTo 0
' Loop through source range assigning any formulae found
' to the equivalent cell of the destination range.
For intColCount = 1 To rngCopyFrom.Columns.Count
For intRowCount = 1 To rngCopyFrom.Rows.Count
If rngCopyFrom.Cells(intRowCount, _
intColCount).HasFormula Then
rngCopyT

ffset(intRowCount - 1, _
intColCount - 1).Formula = _
rngCopyFrom.Cells(intRowCount, _
intColCount).Formula
End If
Next intRowCount
Next intColCount
UserCancelled:
End Sub
Gord
Hi,
Thanks for the info re: apostrophe.
I'm cutting and pasting many cells (with formula's) at one time, so putting
apostrophe's would work but it would be very time consuming.
Can you post the Macro code to handle an entire worksheet?
Thanks Gord!!!
Gord Dibben said:
Kevin
Several methods.....
1. F2 to Edit. Precede the formula with an apostrophe then copy and paste to
new workbook. Delete the apostrophe from both cells.
2. F2 to Edit. Copy the formula from the formula bar. Switch to new
workbook and paste into the formula bar(not into the cell).
3. Use a macro to copy the formula(s) as is.
If you want to try 3. post back and I can post the code.
Gord Dibben Excel MVP
Hi, I regularly cut/paste Worksheet cells (with formula's) into a different
Workbook.
I want to keep the formulas "as is" and NOT have the linked workbook name
included in the formula.
Incorrect: ='[MasterFile.xls]Show Approval'!L111
Correct: ='Show Approval'!L111
Is there a paste feature to NO include the linked path in the formula?