Exceljet

Quick, clean, and to the point

Count unique values with criteria

Excel formula: Count unique values with criteria
Generic formula 
=SUM(--(LEN(UNIQUE(FILTER(range,criteria,"")))>0))
Summary 

To count unique values with one or more conditions, you can use a formula based on UNIQUE and FILTER. In the example shown, the formula in H7 is:

=SUM(--(LEN(UNIQUE(FILTER(B6:B15,C6:C15=H6,"")))>0))

which returns 3, since there are three unique names in B6:B15 associated with the Omega project.

Note: this formula requires Dynamic Array Formulas, available only in Excel 365. With an older version of Excel, you can use more complex alternative formulas.

Explanation 

At the core, this formula uses the UNIQUE function to extract unique values, and the FILTER function apply criteria.

Working from the inside out, the FILTER function is used to apply criteria and extract only names that are associated with the "Omega" project:

FILTER(B6:B15,C6:C15=H6) // Omega names only

The result from FILTER is an array like this:

{"Jim";"Jim";"Carl";"Sue";"Carl"}

Next, the UNIQUE function is used to remove duplicates:

UNIQUE({"Jim";"Jim";"Carl";"Sue";"Carl"})

which results in a new array like this:

{"Jim";"Carl";"Sue"} // after UNIQUE

At this point, we have a unique list of names associated with Omega, and we just need to count them. For reasons explained below, we do this with the LEN function  and the SUM function. To makes things clear, we'll first rewrite the formula to include the unique list:

=SUM(--(LEN({"Jim";"Carl";"Sue"})>0))

The LEN function gets the length of each item in the list, and returns an array of lengths:

LEN({"Jim";"Carl";"Sue"}) // returns {3;4;3}

Next, we check if lengths are greater than zero:

LEN({3;4;3)>0 // returns {TRUE;TRUE;TRUE}

And use a double negative to coerce the TRUE and FALSE values to 1s and 0s:

--({TRUE;TRUE;TRUE}) // returns {1;1;1}

Finally, we add up the results with the SUM function:

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

This array is delivered directly to the COUNTA function, which returns a final count:

=COUNTA({"Jim";"Carl";"Sue"}) // returns 3

Note that because we are checking the length of each item returned by UNIQUE, blank or empty cells that meet criteria are ignored. This formula is dynamic and will recalculate immediately if source data is changed.

Count unique with multiple criteria

To count unique values based on multiple criteria, can extend the "include" logic inside FILTER. For example, to count unique names for the Omega project in June only, use:

=SUM(--(LEN(UNIQUE(FILTER(B6:B15,(C6:C15=H6)*(D6:D15="june"))))>0))

This is an example of using boolean logic to apply more than one condition. The approach is explained in more detail here.

For more details, see this training video: How to filter with multiple criteria.

COUNTA

It is possible to write a simpler formula that replies on the COUNTA function. However an important caveat is that that COUNTA will return 1 when there are no matching values. This is because the FILTER function returns an error when no data matches criteria, and this error ends up being counted by the COUNTA function. The basic COUNTA formula looks like this: 

=COUNTA(UNIQUE(FILTER(B6:B15,C6:C15=H6)))

Again, this formula will return 1 when there is no matching data. It will also include empty cells that meet criteria. The formula based on LEN and SUM is a better option.

No dynamic arrays

If you are using an older version of Excel without dynamic array support, you can use a more complex formula. For a more general discussion of dynamic array alternatives, see: Alternatives to Dynamic Array Formulas.

Dynamic Array Formulas are available in Office 365 only.
Author 
Dave Bruns

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.

Download 100+ Important Excel Functions

Get over 100 Excel Functions you should know in one handy PDF.