Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Counting Unique Values with Functions.
Written by Allen Wyatt (last updated February 17, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
David has a worksheet in which there is a list of countries. This list, in cells A1:A100, can contain duplicates. David wants to determine the number of unique countries in the list.
There are several ways you can go about deriving a count, without resorting to using a macro. The method you should use depends on the characteristics of the data in the list. A good place to start, however, is to define a named range that represents the list of countries. In the following examples, it is assumed that the range is named Countries. (Catchy name, huh?)
If the list contains only text entries and does not contain any blank cells, then the following will provide a count:
=SUM(1/COUNTIF(Countries,Countries))
If you are using an older version of Excel, then this should be entered as an array formula, by pressing Ctrl+Shift+Enter. (Excel 2021 and Excel in Microsoft 365 don't require this special method of entry.) If the list contains blank cells, then the formula will be a little different. The following long array formula will work if there are blanks:
=SUM((Countries<>"")/(COUNTIF(Countries,Countries)+(Countries="")))
Another array function works, but the formula is a little more complicated:
=SUM(IF(FREQUENCY(IF(LEN(Countries)>0,MATCH (Countries,Countries,0),""), IF(LEN(Countries) >0,MATCH(Countries,Countries,0),""))>0,1))
If you are using Excel 2021 or Excel in Microsoft 365, then there is a much simpler formula you can use to get the desired count:
=COUNTA(UNIQUE(Countries))
The formula relies on the UNIQUE function, which returns an array of unique values in the Countries list. The COUNTA function is then used to determine the number of entries in the array.
Another approach is to utilize a blank column to the right of your list. This column will contain regular formulas that indicate if the value to its left is unique in the list or not. The first time a value appears, the formula returns the number 1. On each subsequent appearance of the same value, the formula returns a 0. Start by sorting your list, and then place the following formula in cell B1:
=IF(ISNA(VLOOKUP(A2,$A$1:A1,1,)),1,0)
Just copy the formula from B1 to the range B2:B100. With these results in place, you can easily sum column B and have a count of the unique values in the list.
One final note: When you are doing counts for data, you need to make sure that your data is both normalized and clean. For instance, if one of your countries is "U.S.," another is "US," and a third is "United States," these will all be counted as three separate countries when, in fact, they aren't. Likewise, if your list includes blanks or countries that have spaces after their names, then this can give fallacious results. You'll want to examine your data to make sure it is in the best possible condition to get valid results.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11708) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Counting Unique Values with Functions.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
With a long list of items in a worksheet, you may want to determine the last time a particular item appeared in the list. ...
Discover MoreWhen converting between measurement systems, you might want to use two cells for each type of measurement. Make a change ...
Discover MoreCells in a worksheet can contain different types of information, such as numbers, text, and formulas. If you want to ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2024-02-28 13:49:54
J. Woolley
In my earliest comment below I said, "A formula that includes an array but returns a single value does not need to be entered using Ctrl+Shift+Enter in any version of Excel." I was wrong. I guess it depends on the formula, but determining which formulas qualify is too confusing. Therefore, for versions prior to Excel 2021 you should use Ctrl+Shift+Enter if the formula involves an array. This conforms to the advice of the current Tip and others like it. I apologize for my previous poor advice regarding this subject.
Excel's array formulas and functions are very useful, but their implementation in older versions is too cumbersome; therefore, I suggest anyone who is serious about Excel should upgrade to Excel 2021 or a newer version.
2024-02-27 04:49:22
Enno
@J. Woolley
Here are the results:
Step 2: 1
Step 3: 8
Step 4: 1
Step 5: 1
All was calculated with a German version of Excel 2019 after translating (SUM --> SUMM, COUNTIF --> ZÄHLENWENN, ,--> ;)
Enno
2024-02-26 11:20:23
J. Woolley
@Enno
Thank you for your reply. This is a subject I have been trying to understand for some time. I only have access to Excel 365, so I am unable to test it properly.
See https://excelribbon.tips.net/T007987
and https://excelribbon.tips.net/T001232
Please try the following examples in Excel 2019 and report your results:
1. Copy the list of countries from your original comment dated 2024-02-19 into cells $A$1:$A$12.
2. Copy this formula into cell B1 and press Enter (NOT Ctrl+Shift+Enter):
=SUM(1/COUNTIF($A$1:$A$12,$A$1:$A$12))
What is your result? (I expect it to be 8.)
3. Copy this formula into cell B2 and press Ctrl+Shift+Enter:
=SUM(1/COUNTIF($A$1:$A$12,$A$1:$A$12))
What is your result? (I expect it to be 8.)
4. Copy this formula into cell B3 and press Enter (NOT Ctrl+Shift+Enter):
=1/COUNTIF($A$1:$A$12,$A$1:$A$12)
What is your result? (I expect it to be 1.)
5. Copy this formula into cell B4 ONLY and press Ctrl+Shift+Enter:
=1/COUNTIF($A$1:$A$12,$A$1:$A$12)
What is your result? (I expect it to be 1.)
Please reply. Thank you for your help.
2024-02-26 04:26:31
Enno
@J. Wolley
In my German Excel 2019 I must press Ctrl+Shift+Enter to get a correct calculation.
If I only press Enter, than Excel only calculates one of the array entries.
EPH
2024-02-25 10:05:51
J. Woolley
The Tip says this formula
=SUM(1/COUNTIF(Countries,Countries))
must be entered "by pressing Ctrl+Shift+Enter" in older versions of Excel. This is incorrect. A formula that includes an array but returns a single value does not need to be entered using Ctrl+Shift+Enter in any version of Excel.
The previous statement has a corollary that is also applicable to any version of Excel. If you select a SINGLE CELL and use Ctrl+Shift+Enter to enter a formula that returns an array like
=1/COUNTIF(Countries,Countries)
the result is a single value which is the first element of the returned array.
In any version of Excel, Ctrl+Shift+Enter is useful only if you pre-select a range equal to the expected number of cells returned by an array formula.
2024-02-21 09:04:29
AndyBLX
Another way, especially useful for checking "normalized and clean" data, is to highlight the range and make a pivot table on a new sheet (non-standard duplicates should be clearer), then count the rows ...
2024-02-19 10:32:49
Enno
@Allen: Thank you for your correction. I (as a German) interpreted the word "unique" as "only one appearance".
Enno
2024-02-19 08:41:25
Allen
@Enno: I'm not sure why you say that 5 is correct for your list. Here are the 8 unique countries in the list you provided:
Germany
USA
France
UK
Italy
Spain
Ireland
Denmark
All four formulas provided in the tip return 8.
-Allen
2024-02-19 03:38:17
Enno
I tried this one with an example list (sorted for better overview):
Germany
USA
France
UK
Italy
Spain
Spain
Ireland
Ireland
Denmark
Denmark
Denmark
The first two formulars provide 8 instead of the correct 5.
Can you explain, how these formulars can provide the correct answer, as I do not unstand how this could work correctly?
EPH
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments