Macro Clear all items containing #N/A

howard

Well-known Member
Joined
Jun 26, 2006
Messages
5,701
Office Version
  1. 2019
Platform
  1. Windows
I would like a macro to clear all items in Col E containing #N/A

your assistance in this regard is most appreciated
 

Some videos you may like

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce

sky1in5

Active Member
Joined
Dec 24, 2012
Messages
396
Code:
sub test()
Dim LastRow,i as Long
LastRow = activesheet.range("E" & rows.count).end(xlup).row
for i = 1 to lastrow
if iserror(activesheet.range("E" & i)) = true then
activesheet.range("E" & i).clear
end if
next
end sub
 

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
36,720
Office Version
  1. 2010
Platform
  1. Windows
I would like a macro to clear all items in Col E containing #N/A
There may be a fast, non-looping way to do this, but a couple of questions first...

1) These #N/A values in Column E are all generated by formulas, correct?

2) Can there ever be any other errors in Column E besides #N/A errors?
 

howard

Well-known Member
Joined
Jun 26, 2006
Messages
5,701
Office Version
  1. 2019
Platform
  1. Windows
Thanks for the help, much appreciated

Rick, with regard to your question

1) These #N/A values in Column E are all generated by formulas

2) There are never any other errors in Column E besides #N/A errors


Regards

Howard
 

kevatarvind

Well-known Member
Joined
Mar 3, 2013
Messages
1,047

ADVERTISEMENT

simple way just replace using macro try below code

Code:
Sub Replace()

    Columns("E:E").Select
    Selection.Replace What:="#N/A", Replacement:="", LookAt:=xlPart, _
        SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
        ReplaceFormat:=False
    
End Sub
 

VoG

Legend
Joined
Jun 19, 2002
Messages
63,650
Or

Code:
Sub test()
Columns("E").SpecialCells(xlCellTypeFormulas, xlErrors).ClearContents
End Sub
 

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
36,720
Office Version
  1. 2010
Platform
  1. Windows

ADVERTISEMENT

Or

Code:
Sub test()
Columns("E").SpecialCells(xlCellTypeFormulas, xlErrors).ClearContents
End Sub
Yep... that's the one I was aiming for with my questions.
 

nuked

Well-known Member
Joined
Mar 20, 2013
Messages
883
Or you could add error handlers to the formulas, if you want to maintain the spreadsheet structure for future data.

Code:
Option Explicit
Sub AddIFERROR()
    Application.ScreenUpdating = False
    Application.Calculation = xlCalculationManual
    Dim xCell As Range
    Dim xFormula As String
    For Each xCell In Selection
        If xCell.HasFormula Then
            xFormula = Right(xCell.Formula, Len(xCell.Formula) - 1)
            xCell.Formula = "=IFERROR(" & xFormula & ","""")"
        End If
    Next xCell
    Application.Calculation = xlCalculationAutomatic
    Application.ScreenUpdating = True
End Sub
 

howard

Well-known Member
Joined
Jun 26, 2006
Messages
5,701
Office Version
  1. 2019
Platform
  1. Windows
Hi Guys

Thanks for all the input, much appreciated
 

Watch MrExcel Video

Forum statistics

Threads
1,123,473
Messages
5,601,863
Members
414,479
Latest member
Beau the dog

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
Top