Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Counting Unique Values with Functions.
Written by Allen Wyatt (last updated July 6, 2019)
This tip applies to Excel 97, 2000, 2002, and 2003
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))
This should be entered as an array formula, by pressing Ctrl+Shift+Enter. If the list contains blank cells, then the formula becomes a bit more complex. The following long array formula will work if there are blanks:
=SUM(IF(FREQUENCY(IF(LEN(Countries)>0,MATCH (Countries,Countries,0),""), IF(LEN(Countries) >0,MATCH(Countries,Countries,0),""))>0,1))
This approach—using the FREQUENCY function—is fully recounted in the Microsoft Knowledge Base:
http://support.microsoft.com/kb/100122
If you prefer to not use array formulas (for whatever reason), you can 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, 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.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2167) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Counting Unique Values with Functions.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
Excel allows you to easily convert values from decimal to other numbering systems, such as hexadecimal. This tip explains ...
Discover MoreDoes your data require that you perform calculations using circular references? If so, then you'll want to be aware of ...
Discover MoreWhen working with data in a macro, there are two broad categories you can manipulate: numbers and text. Sometimes you ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2019-08-04 10:48:35
Willy Vanhaelen
In the first formula you can replace =SUM with =SUMPRODUCT.
The only difference is that, =SUMPRODUCT being an array formula by itself, you enter it normally without holding down the Ctrl+Shift keys which is easier.
=SUM is intrinsically not an array formula and to force it to act like one you must enter it by holding down the Ctrl+Shift keys.
2019-08-02 11:58:25
Willy Vanhaelen
Here is an UDF that also works if there are blanks in the range:
Function Unique(R As Range)
Unique = Evaluate(Replace("SUM((@<>"""")/(COUNTIF(@,@)+(@="""")))", "@", R.Address))
End Function
2019-08-02 10:41:19
Willy Vanhaelen
If you have no objection to use a UDF (User Defined Function) you can use this VBA implementation of the first array formula:
Function Unique(R As Range)
Unique = Evaluate("SUM(1/COUNTIF(" & R.Address & "," & R.Address & "))")
End Function
The avantage is that you can use this very simple formula:
=Unique(range)
and that you are rid of having to hold down Ctrl+Shift while entering it.
You can either use a standard range e.g.
=Unique(A1:A100)
or a named range such as
=Unique(Countries).
2019-08-01 18:03:02
Jay Bingham
The description seems to imply that the FREQUENCY function requires a named range. It works just fine with a standard range designation, e.g. A1:A100.
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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