Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. 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: Getting a Count of Unique Names.

Getting a Count of Unique Names

Written by Allen Wyatt (last updated November 10, 2018)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


8

John has a worksheet that he uses for registration of attendees at a conference. Column A has a list of each person attending, and column B has the company represented by each attendee. Each company can have multiple people attend. John can easily figure out how many individuals are coming to the conference; it is simply the number of rows in column A (minus any header rows). The more difficult task is to determine how many companies are going to be represented at the conference.

There are a couple of ways to determine the desired count. First, if there are no blank cells in column B, you can use an array formula (entered by Ctrl+Shift+Enter) such as the following:

=SUM(1/COUNTIF(B2:B50,B2:B50))

If there are blanks in the range (B2:B50 in this case), then the array formula will return a #DIV/0! error. If that is the case, the array formula needs to be changed to the following:

=SUM(IF(FREQUENCY(IF(LEN(B2:B50)>0,MATCH(B2:B50,B1:B50,0),
""),IF(LEN(B2:B50)>0,MATCH(B2:B50,B2:B50,0),""))>0,1))

If you prefer to not use an array formula, you can add regular formulas to column C to do the count. First, sort the table of data by the contents of column B. That way the data will be in company order. Then add a formula such as the following to cell C2 (assuming you have a header in row 1):

=IF(B2<>B3,1,0)

Copy the formula down through all the rest of the cells in column C, and then do a sum on the column. The sum represents the number of unique companies attending, since a 1 only appears in column C when the company name changes.

Of course, if you need to find the names of all the companies represented at the conference, you can use Excel's filtering capabilities. Follow these steps:

  1. Sort the data by column B, the company names.
  2. Select all the cells containing data (including the header cell) in column B.
  3. Display the Data tab of the ribbon.
  4. Click the Advanced tool, in the Sort & Filter group. Excel displays the Advanced Filter dialog box. (See Figure 1.)
  5. Figure 1. The Advanced Filter dialog box.

  6. Make sure the Copy to Another Location radio button is selected.
  7. Make sure the Unique Records Only check box is selected.
  8. With the insertion point in the Copy To box, click on a blank cell, such as E1. (This is where the list of companies will be copied to.)
  9. Click OK. Excel copies the unique company names from the original list to column E.

You now can easily see how many companies are being represented, along with who those companies are.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (7562) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Getting a Count of Unique Names.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Shading Rows with Conditional Formatting

If you need to shade alternating rows in a data table, you'll want to examine how you can accomplish the task with ...

Discover More

Multiple Indexes in a Document

Adding a single index to a document is fairly easy. What if you want to add multiple indexes, however? And what if you ...

Discover More

Generating Random Strings of Characters

If you need to generate a random sequence of characters, of a fixed length, then you'll appreciate the discussion in this ...

Discover More

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!

More ExcelTips (ribbon)

Using AutoFiltering

Excel's AutoFilter tool is a great way to make a long list of items much more manageable. This tip explains how to set up ...

Discover More

Dealing with Text Length Limits and AutoFilter Drop-Down Lists

Excel has some built-in limits on what you can do with the program. When you run into those limits, it can be frustrating ...

Discover More

Toggling AutoFilter

Want a tool that will help you toggle AutoFilter on and off? Excel provides some tools you can use, but you need to be ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is eight minus 0?

2018-11-12 11:39:08

Andy

Or you could make a quick throwaway pivot table, highlight the (unique) entries in the pivot table results column, and look for the total count in the status bar at the bottom of the screen?


2018-11-12 09:03:54

Steven Bastian

I suppose we will need to throw Allen in the water and see if he floats.


2018-11-12 08:45:55

Ken Copenhaver

Another way to get a count would be to create a pivot table with the Company Name column as a row label, then determine the number of rows. (I call this the "no thinking required" method.)


2018-11-11 13:17:04

Fanny Ennever

I use the advance filter all the time to get a list of unique entries in a column. I'd like to suggest you add to this tip that you can get a count of how many times each unique entry appears in the original data. If the original data are in column A, the filtered, unique list is in column B, then put the following formula in cell C2: =COUNTIF(A:A,B2) and copy down for all the values in column B.


2018-11-10 12:53:03

Willy Vanhaelen

For clarity, here I go again:

If you dont like array formulas you can use:
=SUMPRODUCT(1/COUNTIF(B2:B50,B2:B50))

If there may be blanks in the range (for example B2:B50) there are much shorter solutions:

array formula:
=SUM((B2:B50<>"")/COUNTIF(B2:B50,B2:B50&""))

non-array variant:
=SUMPRODUCT((B2:B50<>"")/COUNTIF(B2:B50,B2:B50&""))

There are lots of sites on the internet who explain how they work, just google for "count unique values excel".


2018-11-10 12:34:43

Willy Vanhaelen

Oops! Little mistake: the formulas must be:

=SUMPRODUCT(1/COUNTIF(B2:B50,B2:B50))
=SUM((B2:B50<>"")/COUNTIF(B2:B50,B2:B50&""))
=SUMPRODUCT((B2:B50<>"")/COUNTIF(B2:B50,B2:B50&""))


2018-11-10 12:03:13

Willy Vanhaelen

If you dont like array formulas you can use:
=SUMPRODUCT(1/COUNTIF(B2:B50,B2:B50)))

If there may be blanks in the range (for example B2:B50) there are much shorter solutions:

array formula:
=SUM((B2:B50,B2:B50)<>"")/COUNTIF(B2:B50,B2:B50),B2:B50,B2:B50)&""))

non-array variant:
=SUMPRODUCT((B2:B50,B2:B50)<>"")/COUNTIF(B2:B50,B2:B50),B2:B50,B2:B50)&""))

There are lots of sites on the internet who explain how they work, just google for "count unique values excel".


2018-11-10 06:32:18

Jo

I do not believe it!

Before this email arrived this morning, I wanted to count the unique values in a column. It didn't take long to make me give up.

Are you prescient? People used to be called witches for doing things like this!

Thanks


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.