ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Worksheet Functions (https://www.excelbanter.com/excel-worksheet-functions/)
-   -   Clearing #N/A's in one go? (https://www.excelbanter.com/excel-worksheet-functions/56666-clearing-n-one-go.html)

Lee Harris

Clearing #N/A's in one go?
 
Is there a way, after the fact of selecting a large range, and automatically
clearing the contents of any cell with #N/A as a result of unmatched VLOOKUP
or similar.

tks



Tim C

Clearing #N/A's in one go?
 
F5 Special Formulas [uncheck everything except] Errors Ok Delete

But we can also help you modify your formulas so that the errors don't
appear in the first place.

Tim C

"Lee Harris" wrote in message
...
Is there a way, after the fact of selecting a large range, and
automatically clearing the contents of any cell with #N/A as a result of
unmatched VLOOKUP or similar.

tks




Lee Harris

Clearing #N/A's in one go?
 

"Tim C" wrote in message
...
F5 Special Formulas [uncheck everything except] Errors Ok Delete

But we can also help you modify your formulas so that the errors don't
appear in the first place.

Tim C



thanks, I think I am OK using the ISNA wrapper in my formulas, but when
you've typed out a long, complex formula sometimes I can't be bothered to
put it in - your tip will be a great time saver thanks!



Gord Dibben

Clearing #N/A's in one go?
 
Lee

To add the ISNA wrapper to all VLOOKUP formulas after the fact....

Sub NATrapAdd()
Dim myStr As String
Dim cel As Range
For Each cel In Selection
If cel.HasFormula = True Then
If Not cel.Formula Like "=IF(ISNA*" Then
myStr = Right(cel.Formula, Len(cel.Formula) - 1)
cel.Value = "=IF(ISNA(" & myStr & "),""""," & myStr & ")"
End If
End If
Next
End Sub


Gord Dibben Excel MVP


On Tue, 22 Nov 2005 00:59:05 GMT, "Lee Harris" wrote:


"Tim C" wrote in message
...
F5 Special Formulas [uncheck everything except] Errors Ok Delete

But we can also help you modify your formulas so that the errors don't
appear in the first place.

Tim C



thanks, I think I am OK using the ISNA wrapper in my formulas, but when
you've typed out a long, complex formula sometimes I can't be bothered to
put it in - your tip will be a great time saver thanks!



Lee Harris

Clearing #N/A's in one go?
 

"Gord Dibben" <gorddibbATshawDOTca wrote in message
...
Lee

To add the ISNA wrapper to all VLOOKUP formulas after the fact....

Sub NATrapAdd()
Dim myStr As String
Dim cel As Range
For Each cel In Selection
If cel.HasFormula = True Then
If Not cel.Formula Like "=IF(ISNA*" Then
myStr = Right(cel.Formula, Len(cel.Formula) - 1)
cel.Value = "=IF(ISNA(" & myStr & "),""""," & myStr & ")"
End If
End If
Next
End Sub


Gord Dibben Excel MVP


wow, thanks Gordon!

is that just added to any particular worksheet code with Alt-F11 or?



Gord Dibben

Clearing #N/A's in one go?
 
Lee

ALT + F11 to open VB Editor

Select your workbook/project and right-click and insert module.

Place the code in that general module.

Save workbook.

ALT + Q to return to Excel workbook.

Macro can be run by ALT + F8 to open Macros or assigned to a button or
shortcut key combo.

If you want it to be available for all workbooks, place the Sub in your
Personal.xls.


Gord Dibben Excel MVP

On Tue, 22 Nov 2005 07:57:08 GMT, "Lee Harris" wrote:


"Gord Dibben" <gorddibbATshawDOTca wrote in message
.. .
Lee

To add the ISNA wrapper to all VLOOKUP formulas after the fact....

Sub NATrapAdd()
Dim myStr As String
Dim cel As Range
For Each cel In Selection
If cel.HasFormula = True Then
If Not cel.Formula Like "=IF(ISNA*" Then
myStr = Right(cel.Formula, Len(cel.Formula) - 1)
cel.Value = "=IF(ISNA(" & myStr & "),""""," & myStr & ")"
End If
End If
Next
End Sub


Gord Dibben Excel MVP


wow, thanks Gordon!

is that just added to any particular worksheet code with Alt-F11 or?




All times are GMT +1. The time now is 04:33 AM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
ExcelBanter.com