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: Counting Asterisks.
Written by Allen Wyatt (last updated December 8, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
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:
https://support.office.com/en-us/article/find-or-replace-text-and-numbers-on-a-worksheet-0e304ca5-ecef-4808-b90f-fdb42f892e90
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9483) 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: Counting Asterisks.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
If you need to evaluate a row of values to meet specific criteria, then you'll appreciate the discussion in this tip. It ...
Discover MoreSometimes it is helpful to have a cell contain the maximum value that has ever occurred within changing data. This tip ...
Discover MoreCells in a worksheet can contain different types of information, such as numbers, text, and formulas. If you want to ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-07-19 14:30:29
Ricardo
Exactly what I was looking for. Many thanks.
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