Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Checking for Either of Two Text Values.
Chris wants to count cells that contain text value A or text value B, anywhere in the cell's text. If the cell contains both A and B, she wants to count it, but only once. For instance, Chris has three cells containing "apple seed", "apple tree", and "peach seed" and she wants to know the number of cells containing either "apple" or "seed". (The proper answer that should be returned is 3.)
There are many ways that this can be approached. In considering solutions, I examined only those solutions that avoid intermediate answers, which occupy additional columns. The first solution involves using the COUNTIF function in this manner:
=COUNTIF(A1:A9,"*apple*")+COUNTIF(A1:A9,"*seed*") -COUNTIF(A1:A9,"*seed*apple*")-COUNTIF(A1:A9,"*apple*seed*")
The formula counts all the cells that contain either "apple" or "seed" and then subtracts all the cells that contain "seed" followed by "apple" (both words are in the cell) or "apple" followed by "seed" (the same words in reverse order).
Another solution, this one a bit shorter, relies on the COUNTA and FIND functions, as shown here:
=COUNTA(A1:A9)-SUMPRODUCT(--(ISERROR(FIND("apple",A1:A9))) *--ISERROR(FIND("seed",A1:A9)))
The formula counts the cells containing values and then subtracts all those cells that don't contain either "apple" or "seed". Note that the FIND function is case sensitive, meaning that only "apple" is found and not "Apple" or "APPLE". If you need something that is case insensitive, replace FIND with SEARCH.
You can also, if you prefer, use one of Excel's database functions. Provided you have a column heading for your original phrases, this is not that difficult to do and it results in the shortest formula. All you need to do is set up a corresponding criteria table. For instance, let's say your data is in A1:A9, and the first cell in the column contains a header such as "My Phrases". In another column you should put the same header and then, in the two cells directly under it, place these two formulas:
*apple* *seed*
The criteria specify that you want to match any cells that contain "apple" or "seed" within the cell. With this set up (I'm assuming you placed the criteria table in D1:D3), you can use the following formula:
=DCOUNTA(A1:A9,1,D1:D3)
Of course, you could also use an array formula (entered by pressing Ctrl+Shift+Enter) to get your answer. The following is one such formula that relies, again, on the phrases being checked to be in A1:A9:
=SUM(--((ISNUMBER(FIND("apple",A1:A9))+ISNUMBER(FIND("seed",A1:A9)))>0))
If you lean more towards working with macros, you could create a user-defined function that returns the count for you. The following is an example of one that will work:
Function FindTwoStrings(rng As Range, s1 As String, _ s2 As String) As Integer Application.Volatile If TypeName(rng) <> "Range" Then Exit Function Dim cell As Range For Each cell In rng.Cells If (InStr(1, UCase(cell.Value), UCase(s1), _ vbTextCompare) > 0) Or (InStr(1, UCase(cell.Value), _ UCase(s2), vbTextCompare) > 0) Then _ FindTwoStrings = FindTwoStrings + 1 Next cell End Function
To use the function you could use this formula in a cell:
=FindTwoStrings(A1:A9,"apple","seed")
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9325) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Checking for Either of Two Text Values.
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!
When you discover that there is an invalid reference in a workbook, you can have a bear of a time tracking down the ...
Discover MoreWhen using an Excel worksheet to store data (such as names and phone numbers), you may need a way to easily look up a ...
Discover MoreISBN numbers are used to denote a unique identifier for a published book. If you remove the dashes included in an ISBN, ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments