Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, and 2013. 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.

Checking for Either of Two Text Values

by Allen Wyatt
(last updated October 26, 2017)

8

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:

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 (9326) applies to Microsoft Excel 2007, 2010, and 2013. You can find a version of this tip for the older menu interface of Excel here: Checking for Either of Two Text Values.

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

Clearing All Tabs in a Document

Need to get rid of all the tab stops in a particular document? It's easy to do when you apply the technique outlined in ...

Discover More

Viewing Your Custom Styles

If you develop a set of preferred styles, you may want to use those styles with a document you receive from someone else. ...

Discover More

Unexpected Error Exporting a PDF

It is common for people to create PDF files from their Word documents. What can you do, though, if your standard way of ...

Discover More

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!

More ExcelTips (ribbon)

Deleting Duplicate Text Values

Got a list of data from which you want to delete duplicates? There are a couple of techniques you can use to get rid of ...

Discover More

Incrementing Numeric Portions of Serial Numbers

If you use serial numbers that include both letters and numbers, you might wonder how you can increment the numeric ...

Discover More

Combinations for Members in Meetings

Got a large group of people listed in a worksheet and you want to make sure that each person has met with every other ...

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}] 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 five minus 0?

2019-02-02 20:00:58

p.nagakumar

is there any way to match the contents in two separate excel sheets...
for example: in one sheet the student name with their details of a class room is given.
in another excel sheet, some names of the same class room are given.
the task is to find the matching of the above two sheets.
so, pls notify me the solution for above task...pls
i am a learner of excel....
p.nagakumar,tamilnadu,india


2016-04-20 03:41:13

Steve

Lu,
As above:
"You can also, if you prefer, use one of Excel's database functions." - read all of the above section then using the example code - enter your criteria in D2:D5 (below the heading in D1)


2016-04-18 13:31:09

lu

Hi, thanks for the info. I am checking for one of any FOUR text values. Any ideas on how I can modify this function to do this (without macros)?


2016-02-22 03:39:37

Ida Eva

I want to find if a cell contains multiple text: BOOK, PENCIL, or ERASER. If the cell contains one of these word, the result will be another formula (in this case: a weighted score: (70%*B1)+(30%*B2) and if the cell doesn't contain any of the word, it would return to B3.

I found formula: =SUMPRODUCT(--ISNUMBER(SEARCH(V281:V285,AP266:AS266)))>0

Note: V281:V285 are the list of text (criteria)
AP266:AS266 are the cell where I want to find whether it contains those 3 texts.

The formula result only TRUE or FALSE. So this formula doesn't solve my problem.

Thanks so much for your help.

Regards,
Ida Eva


2014-07-29 09:13:20

Deb

Yes, this could work!

Thank you so much Glenn for your effort, I really appreciate it.


2014-07-28 16:08:46

Glenn Case

Deb:

OR is a boolean function which will return either True or False, which are not valid for a vlookup. I think you want to do both vlookups and then determine if either one is True.

The following formula checks the value in B5 against the values in B36:B40 and also against the values in D36:D40, and if present in either, reports "Found":

=IF(OR(NOT(ISERROR(VLOOKUP(B5,B36:B40,1,FALSE))),NOT(ISERROR(VLOOKUP(B5,D36:D40,1,FALSE)))),"Found","Not Found")

You can probably use that method to accomplish what you're after.


2014-07-25 05:31:15

Deb

Hi please help.

I am trying to do a lookup based on either criteria met. The look up value is as follows. Either the stock number on the one sheet can match up or the stock number on the other or the invoice number can match up with the invoice number on the other sheet. I want to return the department in column 3.

Basically it would look like this =VLOOKUP(OR(A4=Sheet2!A4,Sheet1!C4=Sheet2!B4),Sheet2!A4:C5,3,FALSE)

I cannot get this to work as vlookup doesn't like an OR statement.

Also tried match and index. No luck. Any ideas.


2014-07-22 21:48:15

Osademe Lawrence

This is awesome.
How do i creat a bio-data sheet using this method?


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.