AVERAGEIF function
Returns the arithmetic mean of all cells in a range that satisfy a given condition. The AVERAGEIF function sums up all the results that match the logical test and divides this sum by the quantity of selected values.
AVERAGEIF(Range; Criterion [; Average_Range ])
Range – required argument. An array, a name of named range or a label of a column or a row containing numbers for averaging or numbers or text for the condition.
Criterion – required argument. A condition in the form of expression or a cell reference with expression that defines what cells should be used to calculate the mean. The expression can contain text, numbers, regular expressions (if enabled in calculation options) or wildcards (if enabled in calculation options).
Average_Range – optional. It is a range of values for calculating the mean.
If the Average_Range is not specified, Range is used for both, the calculation of the mean and the search according to the condition. If Average_Range is specified, the Range is used only for the condition test, while Average_Range is used for the average calculation.
If a cell in a range of values for calculating the mean is empty or contains text, function AVERAGEIF ignores this cell.
If the whole range is empty, contains only text or all values of the range do not satisfy the condition (or any combination of those), the function returns the #DIV/0! error.
In all calculations below, range for average calculation contains the row #6, but it is ignored, because it contains text.
Simple usage
=AVERAGEIF(B2:B6;"<35")
Calculates the average for values of the range B2:B6 that are less than 35. Returns 19, because the second row does not participate in the calculation.
=AVERAGEIF(B2:B6;"<"&MAX(B2:B6))
Calculates the average for values of the same range that are less than the maximum value of this range. Returns 19, because the largest value (the second row) does not participate in the calculation.
=AVERAGEIF(B2:B6;">"&SMALL(B2:B6;1))
Calculates the average for values of the same range that are greater than the first smallest value of this range. Returns 25, because the first smallest value (the fourth row) does not participate in the calculation.
Using the Average_Range
=AVERAGEIF(B2:B6;"<35";C2:C6)
The function searches what values are less than 35 in the B2:B6 range, and calculates the average of corresponding values from the C2:C6 range. Returns 145, because the second row does not participate in the calculation.
=AVERAGEIF(B2:B6;">"&MIN(B2:B6);C2:C6)
The function searches what values from the range B2:B6 are greater than the least value in the B2:B6 range, and calculates the average of corresponding values from the C2:C6 range. Returns 113.3, because the fourth row (where there is the least value in the range B2:B6) does not participate in the calculation.
=AVERAGEIF(B2:B6;"<"&LARGE(B2:B6;2);C2:C6)
The function searches what values from the range B2:B6 are less than the second large value in the B2:B6 range, and calculates the average of corresponding values from the C2:C6 range. Returns 180, because only the fourth row participates in the calculation.
Using regular expressions
=AVERAGEIF(A2:A6;"pen";B2:B6)
The function searches what cells from the range A2:A6 contain only the word “pen”, and calculates the average of corresponding values from the B2:B6 range. Returns 35, because only the second row participates in the calculation. The search is performed in the A2:A6 range, but the values are returned from the B2:B6 range.
=AVERAGEIF(A2:A6;"pen.*";B2:B6)
The function searches what cells from the range A2:A6 begin with “pen” ending with any quantity of other characters, and calculates the average of corresponding values from the B2:B6 range. Returns 27.5, because now also “pencil” satisfies the condition, and both, first and second rows participate in the calculation.
=AVERAGEIF(A2:A6;".*book.*";B2:B6)
The function searches what cells from the range A2:A6 contain “book” starting and ending with any quantity of other characters, and calculates the average of corresponding values from the B2:B6 range. Returns 18.5, because only third and fourth rows participate in the calculation.
Reference to a cell as a criterion
If you need to change a criterion easily, you may want to specify it in a separate cell and use a reference to this cell in the condition of AVERAGEIF function.
=AVERAGEIF(A2:A6;".*"&E2&".*";B2:B6)
The function searches what cells from the range A2:A6 contain a combination of characters specified in E2 starting and ending with any quantity of other characters, and calculates the average of corresponding values from the B2:B6 range. If E2 = book, the function returns 18.5.
=AVERAGEIF(B2:B6;"<"&E2;C2:C6)
The function searches what cells from the range B2:B6 are less than the value specified in E2, and calculates the average of corresponding values from the C2:C6 range. If E2 = 35, the function returns 145.