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.

Cell reference for criteria

To use a cell reference for criteria, you can use an array formula like this:

={SUM(COUNTIFS(range1,range2))}

Where range1 is the criteria range, and range2 contains criteria.

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

Formulas are the key to getting work done in Excel. In this step-by-step 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. Start building valuable skills with Excel formulas today. Learn more.

Thank you very much. The function is working fantastically. It saved me at least 3 full working days. - Rajesh
Excel foundational video course
Excel Pivot Table video training course
Excel formulas and functions video training course
Excel Shortcuts Video Course
Excel Charts video training course