Written by Allen Wyatt (last updated February 1, 2021)
This tip applies to Excel 2007, 2010, 2013, and 2016
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 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))
This approach—using the FREQUENCY function—is fully recounted in the Microsoft Knowledge Base:
http://support.microsoft.com/?kbid=100122
If you prefer to not use array formulas (for whatever reason), then 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, 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.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11708) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Counting Unique Values with Functions.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
Given a range of cells containing values, you may have a need to find the first value in the range that is unique. This ...
Discover MoreDo you need to total all the cells that are a particular color, such as yellow? This tip looks at three different ways ...
Discover MoreWhen processing some text data, you may need to perform some esoteric function, such as adding dashes between letters. ...
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:45:25
Willy Vanhaelen
In the first 2 formulas 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:53:03
Willy Vanhaelen
If you have no objection to use a UDF (User Defined Function) you can use this VBA implementation of the second array formula that works even with blank cells in the range:
Function Unique(R As Range)
Unique = Evaluate(Replace("SUM((@<>"""")/(COUNTIF(@,@)+(@="""")))", "@", 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).
2016-02-25 18:26:56
Raymond Spence
I use a simpler version of your last solution:
=IF(ISNA(VLOOKUP(A2,$A$1:A1,1,)),1,0)
I work from the sorted list in Col A and write this formula in Col B:
=A2=A1
When this is copied down to the end of the data, the Uniq Values calculate to FALSE.
I use this a lot.
Thanks
2016-02-23 07:33:48
Michael (Micky) Avidan
@Wouter Steegh'
No one was offended - on the conterary.
Beginners/infrequent users should get a "push" as how to become professionals.
This site provides a stage for all the spectrum of Excel users (Experts & Novices) to help the novices to become Experts.
--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL
2016-02-23 07:26:27
Michael (Micky) Avidan
@CJ,
Well..., the resolution seems to be that we both will face a disagreeing state.
There are very rare cases (especially when I teach students the secrets of "Excel" Where I "break" a complicated formula to its segments and put them into several columns.
BUT(!) after they all understand the essence & idea - I ask them to wrap all up and end with one cell only.
--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL
2016-02-22 14:20:36
Wouter Steegh
@ Micky Avidan: I was not aware that this site was exclusively for experts. My comments were aimed at the many beginners/infrequent users out there. I'm sorry if that offends anyone's expertise.
2016-02-22 10:34:39
RKeev
Why don't you simply use a subtotal formula at the bottom then select Conditional Formats and click the duplicate values, check unique from the dropdown then filter by color?
2016-02-22 09:19:53
CJ
@Micky, my issue with using those formulas is, although they are relatively short, they are not intuitive. In many cases, Data/Remove Duplicates suffices nicely.
I'd also respectfully state that using helper columns or copy/paste does not necessarily make one a non-specialist. That seems a bit elitist.
2016-02-22 00:06:18
Bill McNair
So the COUNTIFS formula I carelessly mentioned in an earlier post would not work to get to a "count" of unique values. In fact it would not help at all get to an answer to the original issue of distinct values at all, except if used as mentioned by Michael. Sorry.
The "FastExcel v3" Excel add-in provides a "COUNTDISTINCTS" formula that will do the job. It does not need to be array entered.
Also, the DAX function is actually called "DISTINCTCOUNT" as opposed to the COUNT(DISTINCT row) function used in SQL.
2016-02-21 14:50:49
Dennis Taylor
One of these days it would be great if Excel had a function like:
=UNIQUE(D2:D99)
that would give us the number of unique entries in a range.
2016-02-21 09:46:58
Bill McNair
I find that I am using 0,1 truth columns more and more to get at complex filtered dependencies. In this case, a COUNTIFS formula (if count > 1, =1 else =0) would probably work. These truth columns usually perform very well on data tables of less than 50,000 or so rows.
If data set goes over 100,000 rows or so, throwing the data table into Power Pivot and using the DAX COUNTDISTINCT formula would be good alternative.
2016-02-20 16:05:24
Michael (Micky) Avidan
@Wouter Steegh,
You really mean that the following SIMPLE formuala is complicated ?
=SUM(1/COUNTIF(A1:A50,A1:A50))
You can replace the SUM with SUMPRODUCT and the formula becomes regular simple.
Excel specialists DO NOT like to use COPY/PASTE and/or Helper Column(s).
--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL
2016-02-20 05:13:40
Wouter Steegh
Why use these complicated array formulas, when you can just copy the range to a different location, go to Data - Remove duplicates and have the answer? Takes just a few seconds.
Alternatively you could sort the range, put =(A2<>A1)*1 in B2, copy for the whole range (by double clicking the fill handle), and put =SUM(B2:B100) in B1. This is also very quickly done.
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 © 2023 Sharon Parq Associates, Inc.
Comments