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 Commas in a Selection.
Written by Allen Wyatt (last updated September 11, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
At work, Mark regularly needs to count the number of commas in a range of selected cells. He can't find an Excel function to do this type of task, and is wondering if a macro might be able to do the trick.
While there is no worksheet function that will produce the desired count, there is a formula or two you can use. If you just want to know the number of cells that have at least one comma in them, the following formula will work just fine:
=COUNTIF(A1:A10,"*,*")
If you, instead, need to figure out the number of commas in the range when there could be multiple commas per cell, then you need to use a different formula:
=SUM(LEN(A1:A10))-SUM(LEN(SUBSTITUTE(A1:A10,",","")))
This formula should be entered as an array formula, which means that you should use Ctrl+Shift+Enter to enter the formula. If you need to derive the count for a different range, just change the range in two places in the formula.
If you prefer, you could also create a user-defined function to count the number of commas. There are multiple ways to approach such a task; the following is just one example.
Function CountComma(rng As Range) Dim iCount As Integer Dim rCell As Range Dim sTemp As String Application.Volatile iCount = 0 For Each rCell In rng sTemp = Replace(rCell.Value, ",", "") iCount = iCount + _ (Len(rCell.Value) - Len(sTemp)) Next CountComma = iCount Set rCell = Nothing Set rng = Nothing End Function
In order to use the function in the worksheet, enter the following into a cell:
=CountComma(A1:A10)
All of these methods described so far will count commas that are actually in the cell. They will not count commas that appear to be in the cell because of formatting. For instance, if a number appears as "1,234" in a cell, chances are good that the comma is there because of the way that the cell is formatted; it is not really in the cell itself. Such commas are not counted.
Of course, if all you need to do is know the number of commas and you don't need the value in your worksheet, you can bypass the use of formulas and macros all together. Follow these general steps:
Excel does the replacement and displays a dialog box that shows how many replacements were made.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11029) 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 Commas in a Selection.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
Need to select a range of cells in a column? This tip can help, as it shows how to select from a specific cell all the ...
Discover MoreMacros can be used to change the formatting of your worksheet, if desired. One change you might want to make is to the ...
Discover MoreNeed to run a DOS command from within one of your macros? The answer is the Shell command, described in this tip.
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-09-11 09:02:08
Willy Vanhaelen
I like to make my macros as compact as possible. Here is my version of this tip's one:
Function CountComma(R As Range)
Dim Cel As Range, X As Integer
For Each Cel In R
X = X + Len(Cel) - Len(Replace(Cel, ",", ""))
Next
CountComma = X
End Function
Here is even a one-liner with the vba implementation of this tip's array formula:
Function CountComma(R As Range)
CountComma=Evaluate("SUM(LEN("&R.Address &"))-SUM(LEN(SUBSTITUTE("&R.Address &","","","""")))")
End Function
Syntax: =CountComma(your_range).
Since this UDF itself is not an array formula, enter it simply with Enter (instead of Ctrl+Shift+Enter).
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