Exceljet

Quick, clean, and to the point

COUNTIFS with multiple criteria and OR logic

Excel formula: COUNTIFS with multiple criteria and OR logic
Generic formula 
=SUM(COUNTIFS(range,{"red","blue","green"}))
Explanation 

To count based on multiple criteria using OR logic, you can use the COUNTIFS function with an array constant.

In the example shown, the formula in H6 is:

=SUM(COUNTIFS(D4:D11,{"complete","pending"}))

How this formula works

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

One solution is to supply multiple criteria in an array constant like this:

{"complete","pending"}

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

{4,2}

To get a final total, we wrap COUNTIFS inside SUM. The SUM function then sums all items in the array and returns the result.

Be careful not to double-count

Whenever you use multiple criteria with OR logic, be careful not to double-count. In this example, the two criteria are mutually exclusive, but in other scenarios it is easy to accidentally double count by applying criteria that are too loose.
 

Author 
Dave Bruns

Excel Formula Training

Learn Excel formulas and functions with concise, clear videos. Master absolute/relative addresses, dates, text, named ranges, and tools for troubleshooting. Each video comes with a practice worksheet and audio transcript. Instant access and complete 100% guarantee. Start today!

See details.

This is probably the best explanation I've ever read of an excel function, and I've read a lot! Thank you for making it so clear and easy to understand!!! :) - Marie
Excel foundational video course
Excel Pivot Table video training course
Excel conditional formatting video course
Excel formulas and functions video training course
Excel Shortcuts Video Course