VBA macro to add IF(isna( and/or If(iserror( to existing formula

Diffus

New Member
Joined
Dec 11, 2015
Messages
20
I'm sure this has been addressed before, but my Google Fu fails me.

Sometimes I'll be merrily copying formulae around and notice that some of them return N/A or #DIV/0.

I can revise the cells so that the formulae include =if(isna or if(iserror(, as appropriate, but sometimes it's not practical to do that, and it's cumbersome to type the necessary characters, copy the formula, add a trailing parenthesis, add ,0, then paste the formula and add another trailing parenthesis. What I'd like is a macro I can execute from that would change this

Cell Formula

to

=if(isna(Cell Formula)),0,Cell Formula).

Surely it's been done before. Can someone enlighten me?
 

Excel Facts

What did Pito Salas invent?
Pito Salas, working for Lotus, popularized what would become to be pivot tables. It was released as Lotus Improv in 1989.
Instead of ISNA, why not use IFERROR :
Code:
Sub Formula_Add_IFERROR()
Dim rng As Range, cell As Range, fmla As String
If TypeName(Selection) <> "Range" Then
    MsgBox "Select one or more worksheet cells."
    Exit Sub
End If
On Error Resume Next
Set rng = Intersect(Selection, Selection.SpecialCells(xlCellTypeFormulas, 23))
On Error GoTo 0
If Not rng Is Nothing Then
    For Each cell In rng
        If Left(cell.Formula, 8) <> "=IF(ISNA" _
            And Left(cell.Formula, 8) <> "=IF(ISER" _
            And Left(cell.Formula, 8) <> "=IFERROR" Then
            fmla = Right(cell.Formula, Len(cell.Formula) - 1)
            If Len(cell.Formula) > 255 Then
                MsgBox cell.Address(0, 0) & " contains " & _
                "a formula consisting of more than 255 " & _
                "characters and has to be amended manually."
            ElseIf cell.HasArray Then
                cell.FormulaArray = "=iferror(" & fmla & ", 0)"
            Else
                cell.Formula = "=iferror(" & fmla & ", 0)"
            End If
        End If
    Next
End If
End Sub
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,903
Messages
6,175,284
Members
452,630
Latest member
OdubiYouth

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