Any suggestions on how I could convert all array formulas on a worksheet to
standard formulas?
Using the copy of the workbook, put this code into a regular code module and
run it. It may take a while depending on the number of sheets in the
workbook and the number of cells used on each one, because it's going to
examine every cell on every sheet that was ever used!
Here's the code: to put it into the workbook, open the workbook, then press
[Alt]+[F11] to enter the VB Editor (VBE). Copy and paste the code into the
module. At that point you can actually place the cursor anywhere within the
code and just press the [F5] key to run it right then and there.
Sub KillArrayFormulas()
Dim anySheet As Worksheet
Dim sheetUsedRange As Range
Dim anyCell As Range
For Each anySheet In ThisWorkbook.Worksheets
Set sheetUsedRange = anySheet.UsedRange
For Each anyCell In sheetUsedRange
If anyCell.HasFormula Then
anyCell.Formula = anyCell.Formula
End If
Next
Next
'some housekeeping
Set sheetUsedRange = Nothing
Set anySheet=Nothing
MsgBox"Formula Rewrites Completed"
End Sub
Any editing of an array formula requires that you again commit it by using
the 3-key combination, but if you just hit [Enter] it turns into a non-array
formula.
Any ideas how to work around this?
-Dom
Thanks.
select any one cell within the array formula, press F2 to edit, press
CTRL+SHIFT+ENTER, this will help u to select all the cells within the
array formula,
then press F2 again, press CTRL+ENTER, this will split the array
formula into standard formula in each cell.
this might be what u'r looking for.