Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, 2021, 2024, 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 October 9, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, and Excel in Microsoft 365


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 few ways to determine the desired count. If you are using Excel 2021, 2024, or the version of Excel in Microsoft 365, then you can rely on a couple of great new functions. First, you can use the UNIQUE function to get a list of all of the unique company names. Combine it with the SORT function, and you can see the companies in a sorted order that allows you to quickly spot any misspellings:

=SORT(UNIQUE(B2:B50))

Or, if you prefer to have just a count of unique companies (like John wants), then you can use this formula:

=COUNTA(UNIQUE(B2:B50))

You should be aware that if there are any blank cells in the range, then UNIQUE considers the blank to be a valid unique value, so the formula will be off by one. You can expand the formula just a bit to get rid of the blanks:

=COUNTA(UNIQUE(TRIMRANGE(SORT(B2:B50))))

The SORT function sorts the range, which puts blank cells at the end of the array of cells. The TRIMRANGE function then lops off any blank cells, and that culled array of cells is what is worked on by UNIQUE.

If you are using an older version of Excel, then getting the answer you want can be a bit more convoluted. 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.

Finally, you can also use a simple PivotTable to figure out the number of companies. Create the PivotTable based on your data, using the company name column as a row label. This will give you the list of unique company names, which can easily be counted.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (7562) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, 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

Getting Rid of Non-Printing Characters Intelligently

Is your worksheet, imported from an external source, plagued by non-printing characters that show up like small boxes ...

Discover More

Copying Character Formatting

If you are applying character formatting directly to text rather than using a character style, you can copy it from one ...

Discover More

Determining If a Date is between Other Dates

Need to figure out if one date is between two other dates? There are a wide variety of formulaic approaches you could use ...

Discover More

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 365 applications with VBA programming. Written in clear terms and understandable language, the book includes systematic tutorials and contains both intermediate and advanced content for experienced VB developers. Designed to be comprehensive, the book addresses not just one Office application, but the entire Office suite. Check out Mastering VBA for Microsoft Office 365 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

Setting Up Custom AutoFiltering

The filtering capabilities of Excel are very helpful when you are working with large sets of data. You can create a ...

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
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 9 - 1?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


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.