Counting Occurrences of Words

Written by Allen Wyatt (last updated March 22, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


2

Roger has a worksheet column that contains a list of sculptures. He needs a simple way to count up the number of occurrences of "mouse" or "dragonfly," but it's not always the only text in the cell. He can't find any "COUNTIF-CONTAINS" function, and he can do it manually using Find and Replace, but figures there has to be a better way.

There are actually multiple ways you can approach this issue. One easy way is to use filtering to show only the rows that contain the word you want. You can do that by following these steps:

  1. Make sure your data has column headings defined.
  2. Select a cell within your data.
  3. Display the Data tab of the ribbon.
  4. Click the Filter tool in the Sort & Filter group. Excel places a drop-down arrow next to the column headings.
  5. Click the drop-down arrow next to the heading of the column containing the sculpture names. You'll see a number of filtering options displayed.
  6. Hover the mouse pointer over the Text Filters option and then choose Contains from the fly-out menu. Excel displays the Custom AutoFilter dialog box.
  7. Just to the right of the "contains" setting, enter what you want to search for, such as "mouse" (without the quote marks). (See Figure 1.)
  8. Figure 1. The Custom AutoFilter dialog box.

  9. Click OK. Your data is filtered to only display rows that contain the text specified in step 7.

At this point you can, if there are not too many rows, simply count the rows displayed.

If you would rather use an outright formula, you could rely on the COUNTIF function. This approach works because Excel lets you use wildcards in what you search for in the function. Let's say that you put what you are searching for into cell E1 and you want to search for all instances of rows containing "mouse" in column A. This is the formula to use:

=COUNTIF(A:A,E1)

The trick is to put this text into cell E1: *mouse*. The asterisks are the wildcards, which means that COUNTIF will count any rows that contain at least one instance of the letters "mouse" with anything surrounding those characters.

There are other formulas you could use as well, such as the following:

=COUNT(SEARCH(E1,A:A))
=SUMPRODUCT(IF(IFERROR(SEARCH(E1,A:A)>0*1,0),1,0))
=SUM(IF((ISNUMBER(SEARCH(E1,A:A))),1,0))

When using any of these formulas, you don't need the asterisks surrounding the value in E1; they don't use (or need) wildcards. Also be aware that in some versions of Excel you may need to enter these as array formulas, using Ctrl+Shift+Enter. (You don't need to do this if you are using the version of Excel provided with Microsoft 365.)

You should be aware that any of the formulas presented so far (as well as the filtering approach) have two drawbacks. First, they will count "containing words." This simply means that if you are searching for "mouse," then a word containing "mouse" (such as "mousepad") will count as a match. Second, if the cell contains two instances of what you are searching for (such as "My mouse is your mouse"), then it still only counts as one instance.

If you don't want to run into these types of instances, then the best approach is to create your own user-defined function to do the counting for you. Here's one that is compact and can perform the count:

Function HowMany(rSource As Range, sWord As String) As Long
    Dim X As Long
    Dim V As Variant
    Dim Arr As Variant
    Dim sSearch As String
    Const Pat As String = "[!A-Za-z0-9]"

    Arr = rSource.Value
    If VarType(Arr) < 8192 Then Arr = Split(rSource.Value & " ")
    sSearch = Pat & LCase(sWord) & Pat
    For Each V In Arr
        V = " " & LCase(V) & " "
        For X = 2 To Len(V) + 1
            If Mid(V, X - 1, Len(sWord) + 2) Like sSearch Then
                HowMany = HowMany + 1
            End If
        Next
    Next
End Function

In your workbook you would enter the following:

=HowMany(A:A,"mouse")

When using the function on an entire column like this, it can take a while for the function to return. In other words, it can be slow. You would be better served if you specify a range in the function call that contains just the cells you need to search, instead of the entire column.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13837) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Validating Data

When users add information to a Word document, you may want that information to somehow be validated—to make sure ...

Discover More

Large Toolbar Buttons

Do you wish that the buttons on your Excel toolbars were easier to see and use? The answer could be to turn on the large ...

Discover More

Including Weeks in Elapsed Time

When showing how much time has elapsed between two dates, it is sometimes helpful to express the result in terms of ...

Discover More

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!

More ExcelTips (ribbon)

Figuring Out the Low-Score Winner

Need to figure out the lowest score in a range of scores? Here's the formulas to get the information you need.

Discover More

Referencing Every Third External Cell

When you enter references to cells in a worksheet, using the Fill Handle to propagate the formulas to other cells can be ...

Discover More

Making Your Formulas Check for Errors

Want to use a formula to check if there is an error in your formula? (Sounds confusing, but it's not that bad.) You'll ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 8 - 5?

2021-03-23 14:09:08

Willy Vanhaelen

IMHO this issue can only be solved by a User Defined Function. Here is a shorter version:

Function HowMany(Rng As Range, sWord As String) As Long
Dim Cell As Variant, X As Long
For Each Cell In Rng
Cell = Split(Cell)
For X = 0 To UBound(Cell)
If Cell(X) = sWord Then HowMany = HowMany + 1
Next
Next
End Function


2021-03-22 13:46:17

neil

You could just do a FIND ALL (Ctrl+F then click Find All) for the word you want. It will tell you how many cells contain the text you specify. This method also does not need wildcard asterisks and will find "containing words". if the text appears in a cell more than once, the cell will only be counted once. (see Figure 1 below)

Figure 1. Find All


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.