Exceljet

Quick, clean, and to the point

Excel SUMIF Function

Excel SUMIF function
Summary 

The Excel SUMIF function returns the sum of cells that meet a single condition. Criteria can be applied to dates, numbers, and text. The SUMIF function supports logical operators (>,<,<>,=) and wildcards (*,?) for partial matching.

Purpose 
Sum numbers in a range that meet supplied criteria
Return value 
The sum of values supplied.
Syntax 
=SUMIF (range, criteria, [sum_range])
Arguments 
  • range - The range of cells that you want to apply the criteria against.
  • criteria - The criteria used to determine which cells to add.
  • sum_range - [optional] The cells to add together. If sum_range is omitted, the cells in range are added together instead.
Usage notes 

The SUMIF function returns the sum of cells in a range that meet a single condition. The first argument is the range to apply criteria to, the second argument is the actual criteria, and the last argument is the range containing values to sum. SUMIF supports logical operators (>,<,<>,=) and wildcards (*,?) for partial matching.  Criteria can use a value from another cell, as explained below.

SUMIF is in a group of eight functions in Excel that split logical criteria into two parts (range + criteria). As a result, the syntax used to construct criteria is different, and SUMIF requires a cell range for the range argument, you can't use an array.

SUMIF only supports a single condition. If you need to apply multiple criteria, use the SUMIFS function. If you need to manipulate values that appear in the range argument (i.e. extract the year from dates to use in criteria) see the SUMPRODUCT and/or FILTER functions.

Example #1 - basic usage

In the worksheet shown, there are three SUMIF examples. In the first example (G6), SUMIF is configured to sum values greater than 100. In the second example (G7), SUMIF returns the sum of values where the color is "red". In the last example (G8), SUMIF is configured to sum values where the state is "CA" (California).

=SUMIF(D6:D10,">100") // values > 100
=SUMIF(B6:B10,"Jim",D6:D10) // Rep = Jim
=SUMIF(C6:C10,"ca",D6:D10) // State = CA

Notice the equals sign (=) is not required when constructing "is equal to" criteria. Also notice SUMIF is not case-sensitive.  You can sum values where the Rep is Jim using "jim" or "Jim".

Example #2 - criteria from another cell

A value from another cell can be included in criteria using concatenation. In the example below, SUMIF will return the sum all sales over the value in G4.  Notice the greater than operator (>), which is text, must be enclosed in quotes. The formula in G5 is:

=SUMIF(D5:D9,">"&G4) // sum if greater than G4

SUMIF with variable criteria

Example #3 - SUMIF not equal to

To express "not equal to" criteria, use the "<>" operator surrounded by double quotes (""):

SUMIF not equal to criteria

=SUMIF(B5:B9,"<>red",C5:C9) // not equal to "red"
=SUMIF(B5:B9,"<>blue",C5:C9) // not equal to "blue"
=SUMIF(B5:B9,"<>"&E7,C5:C9) // not equal to E7

Again notice SUMIF is not case-sensitive.

Example #4 - SUMIF with dates

The best way to use SUMIF with dates is to refer to a valid date in another cell, or use the DATE function. The example below shows both methods:

SUMIF with dates

=SUMIF(B5:B9,"<"&DATE(2019,3,1),C5:C9)
=SUMIF(B5:B9,">="&DATE(2019,4,1),C5:C9)
=SUMIF(B5:B9,">"&E9,C5:C9)

Notice we must concatenate an operator to the date in E9. To use more advanced date criteria (i.e. all dates in a given month, or all dates between two dates) you'll want to switch to the SUMIFS function, which can handle multiple criteria.

Example #5 - SUMIF with wildcards

The SUMIF function supports wildcards, as seen in the example below:

SUMIF with wildcards

=SUMIF(B5:B9,"mi*",C5:C9) // begins with "mi"
=SUMIF(B5:B9,"*ota",C5:C9) // ends with "ota"
=SUMIF(B5:B9,"????",C5:C9) // contains 4 characters

See below for more SUMIF formula examples.

Notes

  • SUMIF only supports one condition. Use the SUMIFS function for multiple criteria.
  • When sum_range is omitted, the cells in range will be summed.
  • Text strings in criteria must be enclosed in double quotes (""), i.e. "apple", ">32", "ja*"
  • Cell references in criteria are not enclosed in quotes, i.e. "<"&A1
  • The wildcard characters ? and * can be used in criteria. A question mark matches any one character and an asterisk matches any sequence of characters (zero or more).
  • To find a literal question mark or asterisk, use a tilde (~) in front question mark or asterisk (i.e. ~?, ~*).
  • SUMIFS requires a range, you can't substitute an array.