The information in this article applies to:
SUMMARYThis article contains formulas that calculate the following:
MORE INFORMATIONFormula to Count the Number of Occurrences of Text String in a RangeUse 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+ENTER. 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
Formula to Count Number of Occurrences of a Single Character in One CellIf 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 CellUse 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 Number of Occurrences of a Single Character in a RangeIf 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+ENTER. Example 3: Counting the Number of Occurrences of a Character in a RangeUse 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+ENTER. 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 CellThe 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 CellFollow these steps to count the number of words in a cell where the words are separated by a space character:
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, please see the following article in the Microsoft Knowledge Base: Q89794 XL: Counting Occurrence of a Character in Selection Additional query words: XL98
Keywords : kbdta xlformula |
Last Reviewed: February 1, 2000 © 2000 Microsoft Corporation. All rights reserved. Terms of Use. |