COUNTIFS function

Returns the count of cells that meet criteria in multiple ranges.

Syntax

COUNTIFS(Range1; Criterion1 [; Range2; Criterion2 [; ...]])

Range1 – 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 counting and finding the corresponding criterion.

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.

Warning Icon

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


Note Icon

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.

Warning Icon

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


Note Icon

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 Icon

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


Simple usage

=COUNTIFS(B2:B6;">=20")

Counts the amount of rows of the range B2:B6 with values greater than or equal to 20. Returns 3, because the fifth and the sixth rows do not meet the criterion.

=COUNTIFS(B2:B6;">=20";C2:C6;">70")

Counts the amount of rows that contain simultaneously values greater than 70 in the C2:C6 range and values greater than or equal to 20 in the B2:B6 range. Returns 2, because the second, the fifth and the sixth rows do not meet at least one criterion.

Using regular expressions and nested functions

=COUNTIFS(B2:B6;"[:alpha:]*")

Counts the amount of rows of the B2:B6 range that contain only alphabet symbols. Returns 1, because only sixth row meets the criterion.

=COUNTIFS(B2:B6;">"&MIN(B2:B6);B2:B6;"<"&MAX(B2:B6))

Counts the amount of rows of the B2:B6 range excluding rows with minimum and maximum values of this range. Returns 2, because the third, the fifth and the sixth rows do not meet at least one criterion.

=COUNTIFS(A2:A6;"pen.*";B2:B6;"<"&MAX(B2:B6))

Counts the amount of rows that correspond to all cells of the A2:A6 range starting with "pen" and to all cells of the B2:B6 range with exception of its maximum. Returns 1, 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 the COUNTIFS function. For example, the above function can be rewritten as follows:

=COUNTIFS(A2:A6;E2&".*";B2:B6;"<"&MAX(B2:B6))

If E2 = pen, the function returns 1, because the link to the cell is substituted with its content and it works as a function above.

Open file with example: