SOLVED

changing formulae with find replace

%3CLINGO-SUB%20id%3D%22lingo-sub-2782349%22%20slang%3D%22en-US%22%3Echanging%20formulae%20with%20find%20replace%3C%2FLINGO-SUB%3E%3CLINGO-BODY%20id%3D%22lingo-body-2782349%22%20slang%3D%22en-US%22%3E%3CP%3EI%20would%20like%20to%20change%3C%2FP%3E%3CP%3E%3DGEOMEAN('Rates'!F4684%3AF4687)%3C%2FP%3E%3CP%3Eto%3C%2FP%3E%3CP%3E%3DISERROR(GEOMEAN('Rates'!F4684%3AF4687)%2C%22%22)%26nbsp%3B%3C%2FP%3E%3CP%3Eto%20avoid%20getting%20%23NUM!%20errors.%20If%20I%20use%20Find%20and%20Replace%20I%20get%20formula%20error%20warning%20as%20each%20cell%20(there%20are%20thousands)%20contains%20different%20cell%20references.%3C%2FP%3E%3CP%3ECan%20anyone%20suggest%20a%20solution%3F%3CBR%20%2F%3EMany%20thanks%3C%2FP%3E%3C%2FLINGO-BODY%3E%3CLINGO-LABS%20id%3D%22lingo-labs-2782349%22%20slang%3D%22en-US%22%3E%3CLINGO-LABEL%3EExcel%3C%2FLINGO-LABEL%3E%3CLINGO-LABEL%3EFormulas%20and%20Functions%3C%2FLINGO-LABEL%3E%3C%2FLINGO-LABS%3E
New Contributor

I would like to change

=GEOMEAN('Rates'!F4684:F4687)

to

=ISERROR(GEOMEAN('Rates'!F4684:F4687),"") 

to avoid getting #NUM! errors. If I use Find and Replace I get formula error warning as each cell (there are thousands) contains different cell references.

Can anyone suggest a solution?
Many thanks

2 Replies
best response confirmed by kered1957 (New Contributor)
Solution

@kered1957 

You could run this macro:

 

Sub FixGeomean()
    Dim rng As Range
    Dim adr As String
    Application.ScreenUpdating = False
    With Cells
        Set rng = .Find(What:="=GEOMEAN(", LookIn:=xlFormulas, LookAt:=xlPart)
        If Not rng Is Nothing Then
            adr = rng.Address
            Do
                rng.Formula = "=IFERROR(" & Mid(rng.Formula, 2) & ","""")"
                Set rng = .FindNext(After:=rng)
                If rng Is Nothing Then Exit Do
            Loop Until rng.Address = adr
        End If
    End With
    Application.ScreenUpdating = True
End Sub

 

You are a superstar, thanks very much.