AVERAGEIFS function /text/scalc/01/func_averageifs.xhp
AVERAGEIFS function arithmetic mean;satisfying conditions

AVERAGEIFS function

Returns the arithmetic mean of all cells in a range that satisfy given multiple criteria. The AVERAGEIFS function sums up all the results that match the logical tests and divides this sum by the quantity of selected values.
AVERAGEIFS() Func_range – required argument. It is a range of cells, a name of a named range or a label of a column or a row containing values for calculating the mean.

Simple usage

=AVERAGEIFS(B2:B6;B2:B6;">=20") Calculates the average for values of the range B2:B6 that are greater than or equal to 20. Returns 25, because the fifth row does not meet the criterion. =AVERAGEIFS(C2:C6;B2:B6;">=20";C2:C6;">70") Calculates the average for values of the range C2:C6 that are greater than 70 and correspond to cells of B2:B6 with values greater than or equal to 20. Returns 137.5, because the second and fifth rows do not meet at least one criterion.

Using regular expressions and nested functions

=AVERAGEIFS(C2:C6;B2:B6;">"&MIN(B2:B6);B2:B6;"<"&MAX(B2:B6)) Calculates the average for values of the range C2:C6 that correspond to all values of the range B2:B6 except its minimum and maximum. Returns 127.5, because the third and fifth rows do not meet at least one criterion. =AVERAGEIFS(C2:C6;A2:A6;"pen.*";B2:B6;"<"&MAX(B2:B6)) Calculates the average for values of the range C2:C6 that correspond to all cells of the A2:A6 range starting with "pen" and to all cells of the B2:B6 range except its maximum. Returns 65, because only second row meets all criteria.

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 AVERAGEIFS function. For example, the above function can be rewritten as follows: =AVERAGEIFS(C2:C6;A2:A6;E2&".*";B2:B6;"<"&MAX(B2:B6)) If E2 = pen, the function returns 65, because the link to the cell is substituted with its content.
, , , , , , ,