COUNTIFS function /text/scalc/01/func_countifs.xhp
COUNTIFS function counting row;satisfying criteria counting column;satisfying criteria

COUNTIFS function

Returns the count of cells that meet criteria in multiple ranges.
COUNTIFS(Range1; Criterion1[; Range2; Criterion2][; ... ; [Range127; Criterion127]]) Range1, Range2, ... and Criterion1, Criterion2, ... must have the same size, otherwise the function returns err:502 - Invalid argument.

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

For these examples to work as described, make sure that Enable regular expressions in formulas is selected in %PRODUCTNAME - PreferencesTools - Options - $[officename] Calc - Calculate. =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.
, , , , , , ,