Hide error values and error indicators in cells

Let's say that your spreadsheet formulas have errors that you anticipate and don't need to correct, but you want to improve the display of your results. There are several ways to hide error values and error indicators in cells.

There are many reasons why formulas can return errors. For example, division by 0 is not allowed, and if you enter the formula =1/0, Excel returns #DIV/0. Error values include #DIV/0!, #N/A, #NAME?, #NULL!, #NUM!, #REF!, and #VALUE!.

What do you want to do?


Format text in cells that contain errors so that the errors don't show

Convert an error to a zero value and then apply a number format that hides the value

The following procedure shows you how to convert error values to a number, such as 0, and then apply a conditional format that hides the value. To complete the following procedure you “nest” a cell’s formula inside the IFERROR function to return a zero (0) value and then apply a custom number format that prevents any number from being displayed in the cell.

For example, if cell A1 contains the formula =B1/C1, and the value of C1 is 0, the formula in A1 returns the #DIV/0! error.

  1. Enter 0 in cell C1, 3 in B1, and the formula =B1/C1 in A1.
    The #DIV/0! error appears in cell A1.
  2. Select A1, and press F2 to edit the formula.
  3. After the equal sign (=), type IFERROR followed by an opening parenthesis.
    IFERROR(
  4. Move the cursor to the end of the formula.
  5. Type ,0) ­– that is, a comma followed by a zero and a closing parenthesis.
    The formula =B1/C1 becomes =IFERROR(B1/C1,0).
  6. Press Enter to complete the formula.
    The contents of the cell should now display 0 instead of the #DIV! error.
  7. With the cell that contains the error selected, click Conditional Formatting on the ribbon (Home tab, Styles group).
  8. Click New Rule.
  9. In the New Formatting Rule dialog box, click Format only cells that contain.
  10. Under Format only cells with, select Cell Value in the first list box, equal to in the second list box, and then type 0 in the text box to the right.
  11. Click the Format button.
  12. Click the Number tab and then, under Category, click Custom.
  13. In the Type box, enter ;;; (three semicolons), and then click OK. Click OK again.
    The 0 in the cell disappears. This happens because the ;;; custom format causes any numbers in a cell to not be displayed. However, the actual value (0) remains in the cell.

Format error values by applying a white font color to the text

Use the following procedure to format cells that contain errors so that the text in those cells is displayed in a white font. This makes the error text in these cells virtually invisible.

  1. Select the range of cells that contain the error value.
  2. On the Home tab, in the Styles group, click the arrow next to Conditional Formatting and then click Manage Rules.
    The Conditional Formatting Rules Manager dialog box appears.
  3. Click New Rule.
    The New Formatting Rule dialog box appears.
  4. Under Select a Rule Type, click Format only cells that contain.
  5. Under Edit the Rule Description, in the Format only cells with list, select Errors.
  6. Click Format, and then click the Font tab.
  7. In the Color box, under Theme Colors, select the check box that contains the white color.

Top of Page Top of Page

Display a dash, #N/A, or NA in place of an error value

There may be times when you do not want error vales to appear in cells, and would prefer that a text string such as “#N/A,” a dash, or the string “NA” appears instead. To do this, you can use the IFERROR and NA functions, as the following example shows.

Example

The example may be easier to understand if you copy it to a blank worksheet. In the example below, select the cell that contains the text “Data” and then drag the cursor to select through the last cell in the “Description (Result)” column. Then, copy the selection and paste it into a new worksheet, beginning at cell A1.

 
1
2
3
A
Data
10
0
Formula Description (Result)
=A2/A3 Results in an error (#DIV/0)
=IFERROR(A2/A3,"NA") Returns NA when the value is an error
=IFERROR(A2/A3,"-") Returns a dash when the value is an error
=IFERROR(A2/A3,NA()) Returns #N/A when the value is an error

Function details

IFERROR     Use this function to determine if a cell contains an error or if the results of a formula will return an error.

NA    Use this function to return the string #N/A in a cell. The function name is followed by a pair of empty parentheses, like this: =NA().

Top of Page Top of Page

Hide error values in a PivotTable report

  1. Click the PivotTable report.
    The PivotTable Tools appear.
  1. On the Options tab, in the PivotTable group, click the arrow next to Options, and then click Options.
  2. Click the Layout & Format tab, and then do one or more of the following:
  • Change error display     Select the For error values show check box under Format. In the box, type the value that you want to display instead of errors. To display errors as blank cells, delete any characters in the box.
  • Change empty cell display     Select the For empty cells show check box. In the box, type the value that you want to display in empty cells. To display blank cells, delete any characters in the box. To display zeros, clear the check box.

Top of Page Top of Page

Hide error indicators in cells

If a cell contains a formula that results in an error, a triangle (an error indicator) appears in the top-left corner of the cell. You can prevent these indicators from being displayed by using the following procedure.


Cell with a formula problem

Cell with a formula problem

  1. Click the File tab, click Options, and then click the Formulas category.
  2. Under Error Checking, clear the Enable background error checking check box.

Top of Page Top of Page

 
 
Applies to:
Excel 2010