Summary

To use the COUNTIFS function with OR logic, you can use an array constant for criteria. In the example shown, the formula in H7 is:

=SUM(COUNTIFS(D5:D16,{"complete","pending"}))

The result is 9 since there are 6 orders that are complete and 3 orders that are pending.

Generic formula

=SUM(COUNTIFS(range,{"red","blue","green"}))

Explanation 

In this example, the goal is to use the COUNTIFS function to count data with "OR logic". The challenge is the COUNTIFS function applies AND logic by default.

COUNTIFS function

The COUNTIFS function returns the count of cells that meet one or more criteria, and supports logical operators (>,<,<>,=) and wildcards (*,?) for partial matching. Conditions are supplied to COUNTIFS in the form of range/criteria pairs — each pair contains one range and the associated criteria for that range:

=COUNTIFS(range1,criteria1)

Count cells in range1 that meet criteria1.

By default, the COUNTIFS function applies AND logic. When you supply multiple conditions, ALL conditions must match in order to generate a count:

=COUNTIFS(range1,criteria1,range1,criteria2)

Count where range1 meets criteria1 AND range1 meets criteria2.

This means if we try to user COUNTIFS like this:

=COUNTIFS(D5:D16,"complete",D5:D16,"pending") // returns 0

The result is zero, since the order status in column D can't be both "complete" and "pending" at the same time. One solution is to supply multiple criteria in an array constant like this:

=COUNTIFS(D5:D16,{"complete","pending"})

This will cause COUNTIFS to return two results: a count for "complete" and a count for "pending" in array like this:

{6,3}

In the current version of Excel, these results will spill onto the worksheet into two cells. To get a final total in one formula, we nest the COUNTIFS formula inside the SUM function like this:

=SUM(COUNTIFS(D5:D16,{"complete","pending"}))

COUNTIFS returns the counts directly to SUM:

=SUM({6,3}) // returns 9

And the SUM function returns the sum of the array as a final result.

Note: this is an array formula but it doesn't require special handling in Legacy Excel when using an array constant as above. If you use a cell reference for criteria instead of an array constant, you will need to enter the formula with Control + Shift + Enter in Legacy Excel.

Adding another OR criteria

You can add one additional criteria to this formula, but you'll need to use a single column array for criteria1 and a single row array for criteria2. So, for example, to count orders that are "Complete" or "Pending", for "Andy Garcia" or "Bob Jones", you can use:

=SUM(COUNTIFS(D4:D16,{"complete","pending"},C4:C16,{"Bob Jones";"Andy Garcia"}))

Note we use a comma in the first array constant for a horizontal array and a semicolon for the second array constant for a vertical array. With this configuration, Excel "pairs" elements in the two array constants, and returns counts in a two dimensional array like this

  Bob Jones Andy Garcia
Complete 1 1
Pending 1 0

The array result from COUNTIFS is returned directly to the SUM function:

=SUM({1,1;1,0}) // returns 3

And SUM returns the final result, which is 3 in this case.

Note: this technique will only handle two range/criteria pairs. If you have more than two criteria, consider a SUMPRODUCT formula as described here.

Cell reference for criteria

As mentioned above, you can use a cell reference for criteria in an array formula like this:

={SUM(COUNTIFS(range,B1:B2))}

Where range is the criteria range, and B1:B2 is an example cell reference that contains criteria. This formula "just works" in the current version of Excel, which supports dynamic array formulas. However, in Legacy Excel, the formula must be entered with Control + Shift + Enter.

Wildcards and double-counting

COUNTIF and COUNTIFS support wildcards, but you need to be careful not to double-count when you have multiple "contains" conditions with OR logic. See this example for more information

Dave Bruns Profile Picture

AuthorMicrosoft Most Valuable Professional Award

Dave Bruns

Hi - I'm Dave Bruns, and I run Exceljet with my wife, Lisa. Our goal is to help you work faster in Excel. We create short videos, and clear examples of formulas, functions, pivot tables, conditional formatting, and charts.