Excel: Ignoring Zero Values in the AVERAGE Function

Last reviewed: August 20, 1995
Article ID: Q78195
The information in this article applies to:
  • Microsoft Excel for Windows, versions 2.x, 3.x, 4.x, 5.0, 5.0c
  • Microsoft Excel for the Macintosh, versions 1.x, 2.x, 3.0, 4.0, 5.0, 5.0a
  • Microsoft Excel for Windows NT, version 5.0
  • Microsoft Excel for Windows 95, version 7.0

SUMMARY

In Microsoft Excel, when you use the AVERAGE function with a range of values that includes zero values, the zero values are calculated in the result. However, empty (blank) cells are ignored. You can modify either of these behaviors by using the methods shown below.

MORE INFORMATION

Example 1

On your worksheet, enter the following data:

   A1:  2
   A2:  3
   A3:  2
   A4:  0
   A5:  3
   A6:  =AVERAGE(A1:A5)

The number 2 is returned in cell A6.

To use the AVERAGE function on the range and ignore the zero value, enter the following formula in cell A6:

   {=AVERAGE(If(A1:A5<>0,A1:A5,""))}

Do not enter the curly brackets manually. To enter the formula as an array formula, press CTRL+SHIFT+ENTER simultaneously and the brackets are automatically entered. The value 2.5 is returned.

Example 2

There may be times when you would like to have the AVERAGE function treat blank cells as zeros.

On your worksheet, enter the following data:

   A1:  2
   A2:  3
   A3:  2
   A4:
   A5:  3
   A6: =AVERAGE(A1:A5) will return the value 2.5.

To have the blank cell treated as a zero, change the formula in cell A6 to the following:

   {=AVERAGE(IF(ISBLANK(A1:A5),0,A1:A5))}

Again, enter the curly brackets by pressing CTRL+SHIFT+ENTER simultaneously. Do not attempt to type them in. This formula now returns the value 2.

The techniques described above may be used with any Microsoft Excel function that treats blanks in a range of cells differently from zeros.

REFERENCES

"Function Reference," version 4.0, page 31 "Function Reference," version 3.0, page 20 "Functions and Macros," version 2.1, pages 30-31


KBCategory: kbusage
KBSubcategory:

Additional reference words: 7.00 2.00 2.01 2.10 2.20 2.21 3.00 4.00 5.00
IRR NPV MEDIAN COUNT COUNTA MAX MIN STDEV STDEVP VAR VARP


THE INFORMATION PROVIDED IN THE MICROSOFT KNOWLEDGE BASE IS PROVIDED "AS IS" WITHOUT WARRANTY OF ANY KIND. MICROSOFT DISCLAIMS ALL WARRANTIES, EITHER EXPRESS OR IMPLIED, INCLUDING THE WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. IN NO EVENT SHALL MICROSOFT CORPORATION OR ITS SUPPLIERS BE LIABLE FOR ANY DAMAGES WHATSOEVER INCLUDING DIRECT, INDIRECT, INCIDENTAL, CONSEQUENTIAL, LOSS OF BUSINESS PROFITS OR SPECIAL DAMAGES, EVEN IF MICROSOFT CORPORATION OR ITS SUPPLIERS HAVE BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGES. SOME STATES DO NOT ALLOW THE EXCLUSION OR LIMITATION OF LIABILITY FOR CONSEQUENTIAL OR INCIDENTAL DAMAGES SO THE FOREGOING LIMITATION MAY NOT APPLY.

Last reviewed: August 20, 1995
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.