Explanation
This formula relies on the AND function to test two conditions at the same time:
- Count of words from named range inc is >0
- Count of words from named range exc is =0
If both conditions are TRUE, the formula returns TRUE. If either condition is FALSE, the formula returns FALSE.
The test for multiple words is done using the SEARCH function with help from COUNT.
When SEARCH receives more than one item to look for, it returns an array of results, one per item. When a match is found, SEARCH returns the position of the match. When no match is found, SEARCH returns the #VALUE error. The COUNT function gets a count of numbers in the array returned by SEARCH. COUNT ignores errors by default.
In the example shown, the formula is solved in steps like this
=AND(COUNT({1;11;#VALUE!})>0,COUNT({#VALUE!;#VALUE!})=0)
=AND(2>0,0=0)
=AND(TRUE,TRUE)
=TRUE
With hard-coded values
There's no requirement that you use a range for your list of things. If you're only looking for a small number of things, you can use a list in array format, which is called an array constant. For example, to test for red, blue, or green, but exclude pink and orange, you can use:
=AND(COUNT(SEARCH({"red","blue","green"},B5))>0,COUNT(SEARCH({"orange","pink"},B5))=0)
This version does not require the control + shift + enter array formula syntax.