SUMIF
Determines which values in a range of cells meet a specified criterion, then returns the sum of the matching values. Alternatively the function can determine which values in one range of cells meet a criterion, then return the sum of values in the corresponding cells in a second range of cells.
SUMIF can only apply a single criterion to a range. Use SUMIFS if you need to apply multiple criteria.
SUMIF(Range; Criterion [;SumRange])
Range: The range of cells to which the criterion is applied.
SUMIF supports the reference concatenation operator (~) only in the Range parameter, and only if the optional SumRange parameter is not given.
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:
-
A number or logical value. A matching cell content equals the number or logical value.
-
A value beginning with a comparator (<, <=, =, >, >=, <>).
For =, if the value is empty it matches empty cells.
For <>, if the value is empty it matches non-empty cells.
For <>, if the value is not empty it matches any cell content except the value, including empty cells.
Note: "=0" does not match empty cells.
For = and <>, if the value is not empty and can not be interpreted as a number type or one of its subtypes and the property Search criteria = and <> must apply to whole cells is checked, comparison is against the entire cell contents, if unchecked, comparison is against any subpart of the field that matches the criteria. For = and <>, if the value is not empty and can not be interpreted as a Number type or one of its subtypes applies.
-
Other Text value. If the property Search criteria = and <> must apply to whole cells is true, the comparison is against the entire cell contents, if false, comparison is against any subpart of the field that matches the criteria. The expression can contain text, numbers, regular expressions or wildcards (if enabled in calculation options).
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 zmóžniś abo znjemóžniś.
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.
SumRange: Optional. The range of cells from which values are summed. If no SumRange is given, the values in the Range are summed.
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
=SUMIF(C2:C6,">=100")
Sums only the values from range C2:C6 that are >=100. Returns 370 because cells C2:C3 do not meet the criterion. The values from Range are summed because no SumRange is given.
=SUMIF(B2:B5,">=20",C2:C6)
Sums values from the range B2:B6 only if the corresponding values in the range A1:A5 are >=20. Returns 340 because the fifth and sixth rows do not meet the criterion.
Using regular expressions
=SUMIF(A2:A6,"pen",C2:C5)
Sums values from the range C2:C6 only if the corresponding range in A2:A6 exactly match the letters "pen". Returns 85 because rows A2 and A4:A6 do not meet the criterion.
=SUMIF(A2:A6,"pen*",C2:C6)
Sums the values from the range C2:C6 only if the corresponding cell in range A2:A6 contains the letters "pen". Returns the value 150 because rows A4:A5 do not meet the criterion.
=SUMIF(ProductName,"pen*",Revenue)
A named range can be given as the Range or SumRange parameter. For example, if the columns in the above table are respectively named "ProductName", "Sales", and "Revenue", the function returns 150. This function will only work as described if you have defined the names of the columns using the Define Names dialog.
Reference to a cell as a criterion
If you need to change a criterion easily, you may specify it in a separate cell and use a reference to this cell in the condition of the SUMIF function. For example:
=SUMIF(A2:A6,E2,C2:C6)
If E2 = pen, the function returns 85 because the link to the cell is substituted with its contents.