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.

tip

Toś ta funkcija jo wót LibreOffice 4.0 k dispoziciji.


Syntax

AVERAGEIFS(Func_Range; Range1; Criterion[; Range2; Criterion2][; … ; [Range127; Criterion127]])

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.

Range1 – required argument. It is a range of cells, a name of a named range, or a label of a column or a row, to which the corresponding criterion is to be applied.

Criterion: A criterion is a single cell Reference, Number or Text. It is used in comparisons with cell contents.

A reference to an empty cell is interpreted as the numeric value 0.

A matching expression can be:

Range2 – Optional. Range2 and all the following mean the same as Range1.

Criterion2 – Optional. Criterion2 and all the following mean the same as Criterion.

Pytanje zastupujuce symbole abo regularne wuraze pódpěra. Ze zmóžnjonymi regularnymi wurazami móžośo „all.*“ zapódaś, aby na pśikład prědne wustupowanje „all“, slědowane wót někakich znamuškow, namakał. Jolic cośo tekst pytaś, kótaryž jo teke regularny wuraz, musyśo pak pśed kužde metaznamuško abo operator regularnego wuraza znamuško „\“ stajiś pak tekst z \Q…\E wobdaś. Móžośo awtomatiske wugódnośenje zastupujucych symbolow abo regularnych wurazow w – LibreOffice Calc – Wulicyś zmóžniś abo znjemóžniś.

warning

Gaž funkcije wužywaśo, źož se jaden argument wužywa abo někotare argumenty wužywaju, kótarež su znamjenjowe rjeśazki pytańskich kriterijow, kótarež regularny wuraz reprezentěruju, prědny wopyt jo, kriterije znamjenjowego rjeśazka do licbow pśetwóriś. „.0“ se na pśikład do 0.0 pśetwórja a tak dalej. Jolic to jo wuspěšne, njebuźo wótpowědnik wótpowědnik regularnego wuraza, ale buźo numeriski wótpowědnik. Gaž pak narodnu šemu wužywaś, źož decimalne źěleńske znamje njejo dypk, buźo pśetwórjenje regularnego wuraza funkcioněrowaś. Aby wugódnośenje regularnego wuraza město numeriskego wuraza wunuzkał, wužywajśo někaki wuraz, kótaryž njedajo se wopak ako numeriski rozměś, na pśikład „.[0]“ abo „.\0“ abo „(?i).0.


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

note

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).

note

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


Example

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


warning

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.

Dataju z pśikładom wócyniś:

Pšosym pódprějśo nas!