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 sum.
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)
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
In all examples below, ranges for calculation contain the row #6, which is ignored because it contains text.
Simple usage
=SUMIFS(B2:B6;B2:B6;">=20")
Calculates the sum of values of the range B2:B6 that are greater than or equal to 20. Returns 75, because the fifth row does not meet the criterion.
=SUMIFS(C2:C6;B2:B6;">=20";C2:C6;">70")
Calculates the sum of values of the range C2:C6 that are greater than 70 and correspond to cells of the B2:B6 range with values greater than or equal to 20. Returns 275, because the second and the fifth rows do not meet at least one criterion.
Calculates the sum of values of the range C2:C6 that correspond to all values of the range B2:B6 except its minimum and maximum. Returns 255, because the third and the fifth rows do not meet at least one criterion.
=SUMIFS(C2:C6;A2:A6;"pen.*";B2:B6;"<"&MAX(B2:B6))
Calculates the sum of 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 the SUMIFS function. For example, the above function can be rewritten as follows:
=SUMIFS(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.