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 Asterisks.

Counting Asterisks

Written by Allen Wyatt (last updated June 17, 2023)
This tip applies to Excel 97, 2000, 2002, and 2003


David needs to count the number of asterisks that appear in a range of cells. He notes that COUNTIF appears to assume that * is a wild card character, so it doesn't return the proper count.

There are a number of ways to get results, based upon what it is you actually want to get. Let's assume that you have the following values in cells A3:A8:

  • 1234
  • abcd
  • ab*cd
  • ab*c*d
  • *
  • ***

In these six cells there are a total of seven asterisks. To determine the number of asterisks appearing within the range, you'll need to rely upon an array formula, such as this one:

=SUM(LEN(A3:A8)-LEN(SUBSTITUTE(A3:A8,"*","")))

Remember to enter the formula with Ctrl+Shift+Enter.

Of course, you might want to count the number of cells in the range that contain a single asterisk instead of the number of actual asterisks. In this case you can actually use the COUNTIF function, provided you know how to put the formula together. First, try this formula:

=COUNTIF(A3:A8,"*")

With the data shown at the beginning of this tip, this formula returns the value 5. This, of course, is wrong. The reason it returns this result is because COUNTIF uses * as a wildcard that means "any text in the cell." Since there are five cells in the range that contain text (non-numeric values), that is the answer returned by the formula.

You might think that if you searched for the ANSI character of the asterisk, instead of the asterisk itself, you could get the correct result. This formula shows this approach:

=COUNTIF(A3:A8,CHAR(42))

This formula also returns the incorrect answer (5). It appears that Excel sees no difference, in application, between searching for * and searching for CHAR(42). Both are still treated as a wildcard.

The solution to this is to remember that you can force Excel to treat the asterisk as an actual character by preceding it with a tilde, character, in this manner:

=COUNTIF(A3:A8,"~*")

This returns a result of 1, which may be surprising. Excel is very literal, however, and your formula asked for a count of all the cells which contain a single asterisk. The correct answer is that only one cell (A7) contains what you asked for. If you want to count all the cells that contain an asterisk anywhere within the cell, then you need to surround the formula with wildcard characters, in this manner:

=COUNTIF(A3:A8,"*~**")

This returns "any text" followed by a literal asterisk followed by "any text." The result is 4, which is the number of cells that contain at least one asterisk.

The concept of using tildes to counteract wildcards is covered in this Knowledge Base article:

http://support.microsoft.com/kb/214138

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9482) 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 Asterisks.

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

Displaying Toolbars

Toolbars allow you to access common tasks quickly and easily. Excel provides a wide variety of toolbars, and you can even ...

Discover More

Specifying a Print Tray for a Worksheet

If you need to modify where a worksheet is printed (meaning, which paper tray it should use), Excel doesn't provide a lot ...

Discover More

Filtering Columns

The filtering tools provided in Excel make it easy to filter a data list so that only certain rows are displayed. What if ...

Discover More

Program Successfully in Excel! This guide will provide you with all the information you need to automate any task in Excel and save time and effort. Learn how to extend Excel's functionality with VBA to create solutions not possible with the standard features. Includes latest information for Excel 2024 and Microsoft 365. Check out Mastering Excel VBA Programming today!

More ExcelTips (menu)

Counting Odds and Evens

If you have a series of values in a range of cells, you may wonder how many of those values are even and how many are ...

Discover More

Finding the Smallest Even Value

When processing data in a worksheet, you may have a need to know what the smallest (lowest) even value in a range is. You ...

Discover More

Using a Formula to Replace Spaces with Dashes

If you need a formula to change spaces to some other character, the SUBSTITUTE function fits the bill. Here's how to use it.

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 two less than 5?

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 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.

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.