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:
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.
Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!
When working with text phrases stored in cells, it might be helpful to be able to extract words from the phrase. In this ...
Discover MoreWant to maintain the formatting used in one cell when you use formulas to reference that text in another cell? The answer ...
Discover MoreFormulas are made up of operands that separate a series of terms acted upon by the operands. You may want to know, for ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments