Highlight records containing text strings (AND Logic)
The picture above shows you how to highlight rows containing text strings using conditional formatting.
Example, continents criterion (cell B3) is only searched in column Continents (B7:B28). Color criterion is searched for in column Color, and so on.
Conditional formatting formula:
The formula is not case sensitive. Replace SEARCH function with FIND to make it case sensitive.
How to apply conditional formatting formula
Make sure you adjust cell references to your excel sheet.
- Select cells B6:E27
- Press with left mouse button on "Home" tab
- Press with left mouse button on "Conditional Formatting" button
- Press with left mouse button on "New Rule.."
- Press with left mouse button on "Use a formula to determine which cells to format"
- Type above formula in "Format values where this formula is TRUE" window.
- Press with left mouse button on "Format.." button
- Press with left mouse button on "Fill" tab
- Select a color for highlighted cells.
- Press with left mouse button on "Ok"
- Press with left mouse button on "Ok"
- Press with left mouse button on "Ok"
How the conditional formatting formula works in cell B12
Note, the explanation below is for cell B12. Cell B12 is chosen because it is highlighted by the conditional formatting formula.
Step 1 - Understand relative and absolute cell references
A cell reference may or may not have dollar signs in front of the reference, it indicates the cell reference is fixed meaning it won't change when the cell is copied to other cells.
Example, cell reference $D3 is fixed to column D (absolute cell reference), however, row number 3 changes (relative cell reference) when the cell is copied to another cell.
Step 2 - Search cells to see if criteria are found
The SEARCH function returns the number of the character at which a specific character or text string is found reading left to right (not case-sensitive).
=COUNT(SEARCH($B$3, $B7)+1/($B7<>""))*COUNT(SEARCH($C$3, $C7)+1/($C7<>""))*COUNT(SEARCH($D$3, $D7)+1/($D7<>""))*COUNT(SEARCH($E$3, $E7)+1/($E7<>""))
becomes
=COUNT(SEARCH("am", $B12)+1/($B12<>""))*COUNT(SEARCH("b", $C12)+1/($C12<>""))*COUNT(SEARCH("4", $D12)+1/($D12<>""))*COUNT(SEARCH("LA", $E12)+1/($E12<>""))
becomes
=COUNT(SEARCH("am", "America")+1/("America"<>""))*COUNT(SEARCH("b", "blue")+1/("blue"<>""))*COUNT(SEARCH("4", "Product 4")+1/("Product 4"<>""))*COUNT(SEARCH("LA", "Large")+1/("Large"<>""))
becomes
=COUNT(1+1/("America"<>""))*COUNT(1+1/("blue"<>""))*COUNT(9+1/("Product 4"<>""))*COUNT(1+1/("Large"<>""))
Step 3 - Identify empty criteria and return TRUE or FALSE
The COUNT function counts all numerical values in an argument.
=COUNT(1+1/("America"<>""))*COUNT(1+1/("blue"<>""))*COUNT(9+1/("Product 4"<>""))*COUNT(1+1/("Large"<>""))
becomes
=COUNT(1+1/(TRUE))*COUNT(1+1/(TRUE))*COUNT(9+1/(TRUE))*COUNT(1+1/(TRUE))
becomes
=COUNT(1+1)*COUNT(1+1)*COUNT(9+1)*COUNT(1+1)
becomes
=COUNT(2)*COUNT(2)*COUNT(10)*COUNT(2)
and returns 1 (TRUE). Row 12 is highlighted
Cf search category
In this article, I will demonstrate how to search a table using conditional formatting. The criteria highlight matching column and […]
The image above shows you how to highlight rows with multiple criteria using OR logic. The criteria are found in […]
The picture above shows you conditional formatting formula that highlights matching records based on criteria in row 3 and 4. […]
Conditional formatting category
This article explains how to count cells highlighted with Conditional Formatting (CF). The image above shows data in cell range […]
The image above demonstrates a conditional formatting formula that colors a record if there is at least one record that […]
adam asks: Hi, I have a situation where I want to count if this value is duplicate and if it […]
Functions in this article
More than 1300 Excel formulas
Conditional Formatting categories
Excel categories
One Response to “Highlight records containing text strings (AND Logic)”
Leave a Reply
How to comment
How to add a formula to your comment
<code>Insert your formula here.</code>
Convert less than and larger than signs
Use html character entities instead of less than and larger than signs.
< becomes < and > becomes >
How to add VBA code to your comment
[vb 1="vbnet" language=","]
Put your VBA code here.
[/vb]
How to add a picture to your comment:
Upload picture to postimage.org or imgur
Paste image link to your comment.
Hi
very useful post as usual
I have a question regarding the highlighting.
When I do not enter any criteria in the cell, all cells are highlighted.
is there a way to select nothing when no criterias are given?