MORE INFORMATION
Formula to count the number of occurrences of a text string in a range
Use the following formula to count the number of occurrences of a text
string in a range:
=SUM(LEN(<range>)-LEN(SUBSTITUTE(<range>,"text","")))/LEN("text")
where <range> is the cell range in question and "text" is replaced by the
specific text string you want to count.
Note The above formula must be entered as an array formula. To enter a
formula as an array formula, press COMMAND+RETURN.
The formula must be divided by the length of the text string because the
sum of the character length of the range is decreased by a multiple of each
occurrence of the text string. This formula can replace all later formulas
in this article except the formula to count the number of words in a cell.
Example 1: Counting the number of occurrences of a text string in a range
- Start Microsoft Excel and open a new workbook.
- Type the following on sheet1:
A1: Fruit
A2: apple,apple
A3: orange
A4: apple,orange
A5: grape
A6: orange,grape
A7: grape, apple
A8: =SUM(LEN(A2:A7)-LEN(SUBSTITUTE(A2:A7,"apple","")))/LEN("apple")
NOTE: The above formula must be entered as an array formula. To enter a
formula as an array formula, press COMMAND+RETURN.
The value of cell A8 is 4 because the text "apple" appears four times in
the range.
Formula to count the number of occurrences of a single character in one cell
If you are concerned about searching for a single character in a single
cell, the formula is simplified to:
=LEN(<range>)-LEN(SUBSTITUTE(<range>,"a",""))
where <range> is the cell range in question and "a" is replaced by the
character you want to count.
NOTE: This formula does not need to be entered as an array formula.
Example 2: Counting the number of occurrences of a character in one cell
Use the same data from the preceding example; assume you want to count the
number of occurrences or the character "p" in A7. Type the following
formula in cell A9:
A9: =LEN(A7)-LEN(SUBSTITUTE(A7,"p",""))
The value of cell A9 is 3 because the character "p" appears three times in
A7.
Formula to count the number of occurrences of a single character in a range
If you are concerned about searching for a single character in a range, the
formula is simplified to:
=SUM(LEN(range)-LEN(SUBSTITUTE(range,"a","")))
where <range> is the cell range in question and "a" is replaced by the
character you want to count.
Note The above formula must be entered as an array formula. To enter a
formula as an array formula, press COMMAND+RETURN.
Example 3: Counting the number of occurrences of a character in a range
Use the same data from the preceding example; assume you want to count the
number of occurrences or the character "p" in A2:A7. Type the following
formula in cell A10:
A10: =SUM(LEN(A2:A7)-LEN(SUBSTITUTE(A2:A7,"p","")))
NOTE: The above formula must be entered as an array formula. To enter a
formula as an array formula, press COMMAND+RETURN.
The value of cell A10 is 11 because the character "p" appears eleven times
in A2:A7.
Formula to count the number of words separated by a character in a cell
The following formula counts the number of words in a cell that are
separated by a specific character:
=IF(LEN(TRIM(<cell_ref>))=0,0,LEN(<cell_ref>)-
LEN(SUBSTITUTE(<cell_ref>,<char>,""))+1)
where <cell_ref> is the cell reference and <char> is the character
separating the words.
Note There are no spaces in the above formula; multiple lines are used
only to fit the formula into this document. Do not include any spaces when
you type it into the cell. This formula does not need to be entered as an
array formula.
Example 4: Counting the number of words separated by a space in a cell
Follow these steps to count the number of words in a cell where the words
are separated by a space character:
- Start Microsoft Excel and open a new workbook.
- Type the following on sheet1:
A1: The car drove fast
A2: =IF(LEN(TRIM(A1))=0,0,LEN(TRIM(A1))-LEN(SUBSTITUTE(A1," ",""))+1)
The formula in cell A2 returns a value of 4 to reflect that the string
contains four words separated by spaces. If words are separated by multiple
spaces or if words start or end in a space it doesn't matter. The TRIM
function removes extra space characters and starting and ending space
characters in the text in the cell.
In Microsoft Excel, you can also use a macro to count the occurrences of a
specific character in a cell, or range of cells.
For additional information, click the following article number to view the article in the Microsoft Knowledge Base:
89794
How to use Visual Basic for Applications to count the occurrences of a character in a selection in Excel