Summary

To test a cell for one of many strings, while excluding others, you can use a formula based on the SEARCH, ISNUMBER, and SUMPRODUCT functions. In the example shown the formula in C5 is:

=(SUMPRODUCT(--ISNUMBER(SEARCH(include,B5)))>0)
*(SUMPRODUCT(--ISNUMBER(SEARCH(exclude,B5)))=0)

where "include" is the named range E5:E9, and "exclude" is the named range G5:G6.

Generic formula

=(SUMPRODUCT(--ISNUMBER(SEARCH(include,A1)))>0)
*(SUMPRODUCT(--ISNUMBER(SEARCH(exclude,A1)))=0)

Explanation 

At the core, this formula uses the SEARCH function to look for multiple strings inside a cell. Inside the left SUMPRODUCT, SEARCH looks for all strings in the named range "include".

In the right SUMPRODUCT, SEARCH looks for all strings in the named range "exclude".

In both parts of the formula, SEARCH returns numeric positions when strings are found, and errors when not. The ISNUMBER function converts the numbers to TRUE and errors to FALSE, and the double negative converts the TRUE FALSE values to 1 and 0.

The result at this point looks like this:

=(SUMPRODUCT({1;0;0;0;0})>0)*(SUMPRODUCT({0;0})=0)

Then:

=(1>0)*(0=0)
=TRUE*TRUE
=1

Note: this formula returns either 1 or zero, which are handled like TRUE and FALSE in formulas, conditional formatting, or data validation.

Dave Bruns Profile Picture

AuthorMicrosoft Most Valuable Professional Award

Dave Bruns

Hi - I'm Dave Bruns, and I run Exceljet with my wife, Lisa. Our goal is to help you work faster in Excel. We create short videos, and clear examples of formulas, functions, pivot tables, conditional formatting, and charts.