SUMIF function

You use the SUMIF function to sum the values in a range that meet criteria that you specify. For example, suppose that in a column that contains numbers, you want to sum only the values that are larger than 5. You can use the following formula: =SUMIF(B2:B25,">5")

Your browser does not support video. Install Microsoft Silverlight, Adobe Flash Player, or Internet Explorer 9.

This video is part of a training course called Add numbers in Excel 2013.

Tips   If you want, you can apply the criteria to one range and sum the corresponding values in a different range. For example, the formula =SUMIF(B2:B5, "John", C2:C5) sums only the values in the range C2:C5, where the corresponding cells in the range B2:B5 equal "John."

To sum cells based on multiple criteria, see SUMIFS function.

Syntax

SUMIF(range, criteria, [sum_range])

The SUMIF function syntax has the following arguments:

  • range   Required. The range of cells that you want evaluated by criteria. Cells in each range must be numbers or names, arrays, or references that contain numbers. Blank and text values are ignored. The selected range may contain dates in standard Excel format (examples below).

  • criteria   Required. The criteria in the form of a number, expression, a cell reference, text, or a function that defines which cells will be added. For example, criteria can be expressed as 32, ">32", B5, "32", "apples", or TODAY().

    Important   Any text criteria or any criteria that includes logical or mathematical symbols must be enclosed in double quotation marks ("). If the criteria is numeric, double quotation marks are not required.

  • sum_range   Optional. The actual cells to add, if you want to add cells other than those specified in the range argument. If the sum_range argument is omitted, Excel adds the cells that are specified in the range argument (the same cells to which the criteria is applied).

  • You can use the wildcard characters—the question mark (?) and asterisk (*)—as the criteria argument. A question mark matches any single character; an asterisk matches any sequence of characters. If you want to find an actual question mark or asterisk, type a tilde (~) preceding the character.

Remarks

  • The SUMIF function returns incorrect results when you use it to match strings longer than 255 characters or to the string #VALUE!.

  • The sum_range argument does not have to be the same size and shape as the range argument. The actual cells that are added are determined by using the upper leftmost cell in the sum_range argument as the beginning cell, and then including cells that correspond in size and shape to the range argument. For example:

If range is

And sum_range is

Then the actual cells are

A1:A5

B1:B5

B1:B5

A1:A5

B1:B3

B1:B5

A1:B4

C1:D4

C1:D4

A1:B4

C1:C2

C1:D4

However, when the range and sum_range arguments in the SUMIF function do not contain the same number of cells, worksheet recalculation may take longer than expected.

Examples

Example 1

Copy the example data in the following table, and paste it in cell A1 of a new Excel worksheet. For formulas to show results, select them, press F2, and then press Enter. If you need to, you can adjust the column widths to see all the data.

Property Value

Commission

Data

$ 100,000.00

$ 7,000.00

$ 250,000.00

$ 200,000.00

$ 14,000.00

$ 300,000.00

$ 21,000.00

$ 400,000.00

$ 28,000.00

Formula

Description

Result

=SUMIF(A2:A5,">160000",B2:B5)

Sum of the commissions for property values over 160,000.

$ 63,000.00

=SUMIF(A2:A5,">160000")

Sum of the property values over 160,000.

$ 900,000.00

=SUMIF(A2:A5,300000,B2:B5)

Sum of the commissions for property values equal to 300,000.

$ 21,000.00

=SUMIF(A2:A5,">" & C2,B2:B5)

Sum of the commissions for property values greater than the value in C2.

$ 49,000.00

Example 2

Copy the example data in the following table, and paste it in cell A1 of a new Excel worksheet. For formulas to show results, select them, press F2, and then press Enter. If you need to, you can adjust the column widths to see all the data.

Category

Food

Sales

Vegetables

Tomatoes

$ 2,300.00

Vegetables

Celery

$ 5,500.00

Fruits

Oranges

$ 800.00

Butter

$ 400.00

Vegetables

Carrots

$ 4,200.00

Fruits

Apples

$ 1,200.00

Formula

Description

Result

=SUMIF(A2:A7,"Fruits",C2:C7)

Sum of the sales of all foods in the "Fruits" category.

$ 2,000.00

=SUMIF(A2:A7,"Vegetables",C2:C7)

Sum of the sales of all foods in the "Vegetables" category.

$ 12,000.00

=SUMIF(B2:B7,"*es",C2:C7)

Sum of the sales of all foods that end in "es" (Tomatoes, Oranges, and Apples).

$ 4,300.00

=SUMIF(A2:A7,"",C2:C7)

Sum of the sales of all foods that do not have a category specified.

$ 400.00

Top of Page

Example 3: Using dates as the range argument

Note   The SUMIF function does not directly support data or ranges based upon the background color or font color of data cells. Excel supports the definition of User-Defined Functions (UDFs) using the Microsoft Visual Basic for Applications Editor, to support for Excel operations on cells and tables employing color for data marking. (Press Alt+F11 to open the Editor.)

This example illustrates different approaches you can use for SUMIF with date ranges, and with multiple instances of SUMIF in the same formula. In both cases, you calculate totals for a date range. The table below shows example data for mortgage loan closes in a specific month (January 2013), with for different data sets: 100K loans, 200K loans, 300K loans and 400K loans. In all cases the totals are found using a single criteria.

Copy the example data in the following table, and paste it in cell A1 of a new Excel worksheet. If you need to, you can adjust the column widths to see all the data.

Mortgage Loan Closing Dates

100K Loans Closed

200K Loans Closed

300K Loans Closed

400K Loans Closed

1/1/2013

1/2/2013

2

17

10

12

1/3/2013

18

8

14

8

1/4/2013

8

11

16

7

1/5/2013

1/6/2013

1/7/2013

18

8

19

15

1/8/2013

4

6

8

13

1/9/2013

15

8

7

6

1/10/2013

9

19

18

14

1/11/2013

20

5

14

5

1/12/2013

1/13/2013

1/14/2013

15

19

14

5

1/15/2013

20

12

0

4

1/16/2013

2

19

10

2

1/17/2013

18

1

15

10

1/18/2013

6

16

20

11

1/19/2013

1/20/2013

1/21/2013

Martin Luther King Holiday

1/22/2013

12

15

9

16

1/23/2013

5

6

2

8

1/24/2013

9

1

1

20

1/25/2013

15

4

14

10

1/26/2013

1/27/2013

1/28/2013

20

10

19

13

1/29/2013

17

16

11

4

1/30/2013

2

12

0

12

1/31/2013

11

4

16

10

In any cell outside the table, enter or copy and paste the following formula:

=SUMIF(A2:A32,"<="&DATE(2013,1,31),B2:B32)

This formula sums the data in one column against the dates in Column A. The first argument, A2:A32, defines the data set that the criteria is applied to, and the third argument, B2:B32, specifies the dates' corresponding values to sum from a different range. The range A2:A32 could be far greater, spanning years of dates in a column.

Note the use of the DATE function as the criteria argument for filtering data. Although the DATE function's format is different from the date format in Column A of the mortgage loans table (2013,1,14 vs. 1/14/2013), Excel automatically parses and matches the values, and performs the sum.

You can also use cell references that define the date range criteria. For example, if you enter the date 1/31/2013 in cell D1, all cells between B2 and B32 are summed:

=SUMIF(A2:A32,"<="&D1,B2:B32)

Using the "<=" and ">=" operators is inclusive; the contents of Cell A32 are included in the sum calculation. You can use all standard Excel operators in SUMIF functions.

Important   You must enclose math operators such as =, >=, and <= in quotemarks ("") in SUMIF functions. For any non-numeric argument in SUMIF's criteria field, you must use the "&" character to concatenate the criteria value with the mathematical operator, which is "<=" in this example (as in "<="&A32).

For a single month's worth of data, or for summarizing a column from the entire table, this formula works fine; however, what if you want to single out only the third week in the month, and exclude dates before and after the specified week? How about a single month out of a full year's worth of data? You need two criteria arguments, one to define the lower boundary and one to define the upper boundary. A single SUMIF function does not allow for this. Stringing together two SUMIF functions allows you to specify upper and lower boundaries for a range. In the following example, a single week's worth of data is summed by the formula:

=SUMIF(A2:A32,"<="&DATE(2013,1,14),B2:B32)-SUMIF(A2:A32,"<="&DATE(2013,1,21),B2:B32)

The only element of the formula that changes from the first example is that you specify the criteria values in each of the two SUMIF functions, separated by a "-" operator (without quotemarks). The lower boundary is in the first expression and the upper boundary is in the second. Also, instead of modifying the formula every time you want to find another data set, you can use cell references to enter new values for the date range you want to check:

=SUMIF(A2:A32,"<="&H18,15:B32)-SUMIF(A2:A32,"<="&I18,B2:B32)

Using Dates in a SUMIF function

Enter the dates in both reference cells that match within the range in Column A (and that make sense as a date range), and the sum calculations will appear where you place the SUMIFs in the worksheet. SUMIF ignores blank entries and text notes within the table, such as "Martin Luther King holiday," indicating a holiday in that time period.

SUMIF supports named ranges. For example, if you created a named range in the Dates column A, or want to refer to a named range on another worksheet or in another workbook, you can substitute that name for the cell range A2:A32 as follows:

=SUMIF(dates,">="&H18,B2:B32)-SUMIF(dates,">"&I18,B2:B32)

Important   SUMIF is a legacy summing function that supports only a single filtering criteria. To directly use more than one filtering criteria in a single function, use the SUMIFS function.

Applies To: Excel 2016, Excel 2013, Excel 2010, Excel 2007, Excel 2016 for Mac, Excel for Mac 2011, Excel Online, Excel for iPad, Excel for iPhone, Excel for Android tablets, Excel Starter, Excel for Android phones



Was this information helpful?

Yes No

How can we improve it?

255 characters remaining

To protect your privacy, please do not include contact information in your feedback. Review our privacy policy.

Thank you for your feedback!

Change language