SECOND

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; Range1; Criterion1 [ ; Range2; Criterion2 [;...]]))

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.

Criterion1 โ€“ required argument. A string expression representing a logical condition or a cell reference to such string expression. The expression can contain text, numbers, regular expressions or wildcards (if enabled in calculation options).

Range2 โ€“ Optional. Range2 and all the following mean the same as Range1.

Criterion2 โ€“ Optional. Criterion2 and all the following mean the same as Criterion1.

แƒ’แƒแƒ•แƒ แƒ—แƒฎแƒ˜แƒšแƒ”แƒ‘แƒ˜แƒก แƒฎแƒแƒขแƒฃแƒšแƒ

Func_Range and Range1, Range2... must have the same size, otherwise the function returns err:502 - Invalid argument.


แƒจแƒ”แƒœแƒ˜แƒจแƒ•แƒœแƒ˜แƒก แƒฎแƒแƒขแƒฃแƒšแƒ

The logical relation between criteria can be defined as logical AND (conjunction). In other words, if and only if all given criteria are met, a value from the corresponding cell of the given Func_Range is taken into calculation.


The function can have up to 255 arguments, meaning that you can specify 127 criteria ranges and criteria for them.

แƒ’แƒแƒ•แƒ แƒ—แƒฎแƒ˜แƒšแƒ”แƒ‘แƒ˜แƒก แƒฎแƒแƒขแƒฃแƒšแƒ

If a cell contains TRUE, it is treated as 1, if a cell contains FALSE โ€“ as 0 (zero).


แƒจแƒ”แƒœแƒ˜แƒจแƒ•แƒœแƒ˜แƒก แƒฎแƒแƒขแƒฃแƒšแƒ

This function is part of the Open Document Format for Office Applications (OpenDocument) standard Version 1.2. (ISO/IEC 26300:2-2015)


แƒ›แƒแƒ’แƒแƒšแƒ˜แƒ—แƒ”แƒ‘แƒ˜

Consider the following table

A

B

C

1

Product Name

Sales

Revenue

2

pencil

20

65

3

pen

35

85

4

notebook

20

190

5

book

17

180

6

pencil-case

not

not


แƒ’แƒแƒ•แƒ แƒ—แƒฎแƒ˜แƒšแƒ”แƒ‘แƒ˜แƒก แƒฎแƒแƒขแƒฃแƒšแƒ

In all examples below, ranges for calculation contain the row #6, which is ignored because it contains text.


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.

Open file with example:

AVERAGE, AVERAGEA, AVEDEV, [text/scalc/01/func_averageif.xhp#averageif_head not found].

[text/scalc/01/func_countifs.xhp#countifs_head not found]., MINIFS, MAXIFS, [text/scalc/01/func_averageifs.xhp#averageifs_head not found]., [text/scalc/01/func_sumifs.xhp#sumifs_head not found].

แƒกแƒแƒฌแƒงแƒ˜แƒกแƒ˜ แƒ’แƒแƒ›แƒแƒกแƒแƒฎแƒฃแƒšแƒ”แƒ‘แƒ”แƒ‘แƒ˜แƒก แƒกแƒ˜แƒ