AVERAGEIF function

Returns the average (arithmetic mean) of all the cells in a range that meet a given criteria.

Syntax

AVERAGEIF(range,criteria,average_range)

Range    is one or more cells to average, including numbers or names, arrays, or references that contain numbers.

Criteria    is the criteria in the form of a number, expression, cell reference, or text that defines which cells are averaged. For example, criteria can be expressed as 32, "32", ">32", "apples", or B4.

Average_range    is the actual set of cells to average. If omitted, range is used.

Remarks

  • Cells in range that contain TRUE or FALSE are ignored.
  • If a cell in average_range is an empty cell, AVERAGEIF ignores it.
  • If range is a blank or text value, AVERAGEIF returns the #DIV0! error value.
  • If a cell in criteria is empty, AVERAGEIF treats it as a 0 value.
  • If no cells in the range meet the criteria, AVERAGEIF returns the #DIV/0! error value.
  • You can use the wildcard characters, question mark (?) and asterisk (*), in criteria. A question mark matches any single character; an asterisk matches any sequence of characters. If you want to find an actual question mark or asterisk, type a tilde (~) before the character.
  • Average_range does not have to be the same size and shape as range. The actual cells that are averaged are determined by using the top, left cell in average_range as the beginning cell, and then including cells that correspond in size and shape to range. For example:
If range is And average_range is Then the actual cells evaluated are
A1:A5 B1:B5 B1:B5
A1:A5 B1:B3 B1:B5
A1:B4 C1:D4 C1:D4
A1:B4 C1:C2 C1:D4

 Note   The AVERAGEIF function measures central tendency, which is the location of the center of a group of numbers in a statistical distribution. The three most common measures of central tendency are:

  • Average     which is the arithmetic mean, and is calculated by adding a group of numbers and then dividing by the count of those numbers. For example, the average of 2, 3, 3, 5, 7, and 10 is 30 divided by 6, which is 5.
  • Median     which is the middle number of a group of numbers; that is, half the numbers have values that are greater than the median, and half the numbers have values that are less than the median. For example, the median of 2, 3, 3, 5, 7, and 10 is 4.
  • Mode     which is the most frequently occurring number in a group of numbers. For example, the mode of 2, 3, 3, 5, 7, and 10 is 3.

For a symmetrical distribution of a group of numbers, these three measures of central tendency are all the same. For a skewed distribution of a group of numbers, they can be different.

Example: Averaging property values and commissions

The example may be easier to understand if you copy it to a blank worksheet.

ShowHow to copy an example

  1. Create a blank workbook or worksheet.
  2. Select the example in the Help topic.

 Note   Do not select the row or column headers.

Selecting an example from Help

Selecting an example from Help
  1. Press CTRL+C.
  2. In the worksheet, select cell A1, and press CTRL+V.
  3. To switch between viewing the results and viewing the formulas that return the results, press CTRL+` (grave accent), or on the Formulas tab, in the Formula Auditing group, click the Show Formulas button.
 
1
2
3
4
5
6
7
8
9
A B
Property Value Commission
100,000 7,000
200,000 14,000
300,000 21,000
400,000 28,000
Formula Description (result)
=AVERAGEIF(B2:B5,"<23000") Average of all commissions less than 23,000 (14,000)
=AVERAGEIF(A2:A5,"<95000") Average of all property values less than 95,000 (#DIV/0!)
=AVERAGEIF(A2:A5,">250000",B2:B5) Average of all commissions with a property value greater than 250,000 (24,500)

Example: Averaging profits from regional offices

The example may be easier to understand if you copy it to a blank worksheet.

ShowHow to copy an example

  1. Create a blank workbook or worksheet.
  2. Select the example in the Help topic.

 Note   Do not select the row or column headers.

Selecting an example from Help

Selecting an example from Help
  1. Press CTRL+C.
  2. In the worksheet, select cell A1, and press CTRL+V.
  3. To switch between viewing the results and viewing the formulas that return the results, press CTRL+` (grave accent), or on the Formulas tab, in the Formula Auditing group, click the Show Formulas button.
 
1
2
3
4
5
6
7
8
9
A B
Region Profits (Thousands)
East 45,678
West 23,789
North -4,789
South (New Office) 0
MidWest 9,678
Formula Description (result)
=AVERAGEIF(A2:A6,"=*West",B2:B6) Average of all profits for the West and MidWest regions (16,733.5)
=AVERAGEIF(A2:A6,"<>*(New Office)",B2:B6) Average of all profits for all regions excluding new offices (18,589)
 
 
Applies to:
Excel 2007