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.

note

SUMIF can only apply a single criterion to a range. Use SUMIFS if you need to apply multiple criteria.


Syntax

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:

The search supports wildcards or regular expressions. With regular expressions enabled, you can enter "all.*", for example to find the first location of "all" followed by any characters. If you want to search for a text that is also a regular expression, you must either precede every regular expression metacharacter or operator with a "\" character, or enclose the text into \Q...\E. You can switch the automatic evaluation of wildcards or regular expression on and off in - LibreOffice Calc - Calculate.

warning

When using functions where one or more arguments are search criteria strings that represents a regular expression, the first attempt is to convert the string criteria to numbers. For example, ".0" will convert to 0.0 and so on. If successful, the match will not be a regular expression match but a numeric match. However, when switching to a locale where the decimal separator is not the dot makes the regular expression conversion work. To force the evaluation of the regular expression instead of a numeric expression, use some expression that can not be misread as numeric, such as ".[0]" or ".\0" or "(?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.

note

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


Examples

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

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

Please support us!