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.
Written by Allen Wyatt (last updated January 8, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Sometimes you need to know the number of unique values in a range of cells. For instance, suppose that an instructor was teaching the following classes:
104-120 104-101 104-119 104-120
In this case there are three unique values. There is no intuitive worksheet function that will return a count of unique values, which makes one think that a user-defined function would be the logical approach. However, you can use aa simple formula to very easily derive the desired information. Follow these two steps:
=SUM(1/COUNTIF(MyRange,MyRange))
The above steps will work just fine if you are using the version of Excel provided with Microsoft 365. If you are using an older version, however, you need to make one change—you need to enter the formula as an array formula. This simply means that you enter it using Ctrl+Shift+Enter instead of just pressing Enter.
With the formula properly entered, the cell contains the number of unique name values in the specified range. This approach is not case-sensitive, so if you have two values that differ only in their capitalization (ThisName vs. THISNAME), they are both counted as a single unique value. In addition, there can be no blank cells in the range. (Having a blank cell returns a #DIV/0 error from the formula.)
If your particular needs require that your list contain blanks (but you don't want them counted) and you want the evaluation to be case-sensitive, then you must turn to a macro. The following macro, CountUnique, will do the trick:
Function CountUnique(ByVal MyRange As Range) As Integer Dim Cell As Range Dim J As Integer Dim iNumCells As Integer Dim iUVals As Integer Dim sUCells() As String iNumCells = MyRange.Count ReDim sUCells(iNumCells) As String iUVals = 0 For Each Cell In MyRange If Cell.Text > "" Then For J = 1 To iUVals If sUCells(J) = Cell.Text Then Exit For End If Next J If J > iUVals Then iUVals = iUVals + 1 sUCells(iUVals) = Cell.Text End If End If Next Cell CountUnique = iUVals End Function
Simply put an equation similar to the following in a cell:
=CountUnique(MyRange)
The value returned is the number of unique values, not counting blanks, in the range. Understand, as well, that as your range (what you defined as MyRange, earlier) becomes larger, the macro takes longer to process. This is understandable; it has to work through all the cells in the range, and if there are a lot of cells it can take a lot of time.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9872) 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.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
If you have a full path designation for the location of a file on your hard drive, you may want a way for Excel to pull ...
Discover MoreIf you have a lot of values in a single row, you might want to pull the last non-zero value from that row. There are a ...
Discover MoreWant to sum the values in the same cell on a range of worksheets? It's not as easy as summing a range on the same ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-01-10 09:28:37
Eric Nordby
Hi Allan - Thank you so much for your Excel Tips! This article on counting unique values, with the new O365 there is one more quick formula way to do it:
=counta(unique(myrange))
the key is that myrange needs to be only real values.
A user could intentionally add blank rows to myrange then subtract 1 knowing there will be a unique "0" that is counted.
Have a great day!
Eric
2022-01-09 09:43:26
Peter Atherton
If the UNIQUE function is not available then the VBA Collection is the way to go. the following short sub list unique values of any type. The following sub asks for an output cell and list the count and items in the collection
Sub t()
'Collection variables
Dim col As New Collection
Dim c As Range, i As Long, counter As Long
'output variables
Dim r As Range, mr As Long, mc As Long
Set r = Application.InputBox("Input 1st cell of output range", Type:=8)
Dim myRow As Long, myCol As Long
myRow = r.Row: myCol = r.Column
On Error Resume Next
For Each c In Selection
col.Add c, c
Next c
Cells(myRow, myCol) = col.count
myRow = myRow + 1
For i = 1 To col.count
Cells(myRow, myCol) = col(i)
myRow = myRow + 1
Next i
End Sub
If you do not want the list delete the loop For i ....
If count is not needed delete the two row after Nect c
2022-01-08 07:48:13
John Schoonover
Is there a similar formula for text fields?
2022-01-08 05:21:34
Andy
=COUNTA(UNIQUE(A1:A4))
This requires Excel 365.
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