Explanation
This example uses the UNIQUE function to extract unique values. When UNIQUE is provided with the range B5:B16, which contains 12 values, it returns the 7 unique values seen in D5:D11. These are returned directly to the COUNTA function as an array like this:
=COUNTA({"red";"amber";"green";"blue";"purple";"pink";"gray"})
Unlike the COUNT function, which counts only numbers, COUNTA counts both text and numbers. Since there are seven items in array, COUNTA returns 7. This formula is dynamic and will recalculate immediately when source data is changed.
With a cell reference
You can also refer to a list of unique values already extracted to the worksheet with the UNIQUE function using a special kind of cell reference. The formula in D5 is:
=UNIQUE(B5:B16)
which returns the seven values seen in D5:D11. To count these values with a dynamic reference, you can use a formula like this:
=COUNTA(D5#)
The hash character (#) tells Excel to refer to the spill range created by UNIQUE. Like the all-in-one formula above, this formula is dynamic and will adapt when data is added or removed from the original range.
Count unique ignore blanks
To count unique values while ignoring blank cells, you can add the FILTER function like this:
=COUNTA(UNIQUE(FILTER(data,data<>"")))
This approach is explained in more detail here. You can also filter unique values with criteria.
No data
One limitation of this formula is that it will incorrectly return 1 if there aren't any values in the data range. This alternative will count all values returned by UNIQUE that have a length greater than zero. In other words, it will count all values with at least one character:
=SUM(--(LEN(UNIQUE(B5:B16))>0))
Here, the LEN function is used to check the length of results from UNIQUE. The lengths are then checked to see if they are greater than zero, and results are counted with the SUM function. This is an example of boolean logic. This formula will also exclude empty cells from results.
Dynamic source range
UNIQUE won't automatically change the source range if data is added or deleted. To give UNIQUE a dynamic range that will automatically resize as needed, you can use an Excel Table, or create a dynamic named range with a formula.
No dynamic arrays
If you are using an older version of Excel without dynamic array support, here are some alternatives.