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: Checking for Either of Two Text Values.
Written by Allen Wyatt (last updated January 11, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
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".
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 (9326) 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: Checking for Either of Two Text Values.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
When working with names or a different series of words, you may need to pull the initial letters from each word in the ...
Discover MoreFormulas are the heart of using Excel, and formulas often refer to ranges of cells. How you insert cells into the ...
Discover MoreAutoFill is a great feature. It can detect patterns and adjust cell contents as you drag a selection on-screen. It ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2020-03-15 05:39:40
Alex B
The 1st Example with the Countif will be slightly shorter and easier to read if you throw the newer Countifs into the mix. Making the 2nd line where you deduct 1 for each double up this:-
-COUNTIFS(A1:A9,"*apple*",A1:A9,"*seed*")
2020-03-14 16:29:53
Tim
It’s always nice to see a variety of a methods! I think the first “countif” method could even serve as an illustration in my data management math class, teaching about counting non-mutually exclusive events with Venn diagrams. I wrote a complicated PoerApps function that accepts Any number of search terms (comma delimited), since I found this search functionality missing from Excel. I like the DCOUNTA method. I haven’t used that before! It cones the closest to working for n search terms.
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