Exceljet

Quick, clean, and to the point

Excel SUMIF Function

Excel SUMIF function
Summary 

The Excel SUMIF function returns the sum of cells that supplied criteria. Criteria can be applied to dates, numbers, and text using 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 based on supplied criteria. 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. If you need to apply more than one criteria, use the SUMIFS function.

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 - SUMIF with variable criteria

To set up SUMIF with variable criteria from another cell, concatenate the appropriate operator and the cell in the criteria with the ampersand character (&). For example, to sum all sales over the value in G4, 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 need to 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

  • When sum_range is omitted, the cells in range will be summed.
  • Text criteria, or criteria that includes math symbols, must be enclosed in double quotation marks (").
  • Numeric criteria can be supplied without quotation marks.
  • The wildcard characters ? and * can be used in criteria. A question mark matches any one character and an asterisk matches any sequence of characters.
  • To find a literal question mark or asterisk, use a tilde (~) in front question mark or asterisk (i.e. ~?, ~*).

Excel Formula Training

Formulas are the key to getting things done in Excel. In this accelerated training, you'll learn how to use formulas to manipulate text, work with dates and times, lookup values with VLOOKUP and INDEX & MATCH, count and sum with criteria, dynamically rank values, and create dynamic ranges. You'll also learn how to troubleshoot, trace errors, and fix problems. Instant access. See details here.