Exceljet

Quick, clean, and to the point

Count unique values with criteria

Excel formula: Count unique values with criteria
Generic formula 
=COUNTA(UNIQUE(FILTER(range,criteria)))
Explanation 

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

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

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.

How this formula works

At the core, this formula uses the UNIQUE function to extract unique values and the COUNTA function to count these values. The FILTER function is used to apply criteria. 

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

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

This results in an array of results 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

This array is delivered directly to the COUNTA function, which returns a count of all items in the array:

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

Unlike the COUNT function, which counts only numbers, COUNTA counts both text and numbers. Since there are three items in array, COUNTA returns 3. This formula is dynamic and will recalculate immediately if source data is changed.

Count unique ignore blanks

Blank cells in the name column can cause the unique count to increase because FILTER will include the empty value in the array delivered to the UNIQUE function.  To ignore blank or empty cells in column B, you can adjust the formula above like this:

=COUNTA(UNIQUE(FILTER(B6:B15,(C6:C15=H6)*(B6:B15<>""))))

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

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:

=COUNTA(UNIQUE(FILTER(B6:B15,(C6:C15=H6)*(D6:D15="june"))))

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

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.