Highlight records [AND logic]
The picture above shows you conditional formatting formula that highlights matching records based on criteria in row 3 and 4.
Conditional formatting formula:
How to apply conditional formatting formula
Make sure you adjust cell references to your excel sheet.
- Select cells B7:E28
- Click "Home" tab
- Click "Conditional Formatting" button
- Click "New Rule.."
- Click "Use a formula to determine which cells to format"
- Type the above formula in "Format values where this formula is TRUE" window.
(The formula shown in the image above is not used in this article.) - Click "Format.." button
- Click "Fill" tab
- Select a color for highlighted cells.
- Click "Ok"
- Click "Ok"
- Click "Ok"
How the conditional formatting formula works in cell C8
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 - First criterion, dates
I have bolded the first date criteria below:
=SUMPRODUCT(IF(AND(ISBLANK($B$3:$B$4)), 1, ($B$3<=$B8)*($B$4>=$B8))*(IF(ISBLANK($C$3), 1, $C$3=$C8))*(IF(ISBLANK($D$3), 1, $D$3=$D8))*(IF(AND(ISBLANK($E$3:$E$4)), 1, ($E$3<=$E8)*($E$4>=$E8))))
IF(AND(ISBLANK($B$3:$B$4)), 1, ($B$3<=$B8)*($B$4>=$B8))
becomes
IF(AND(ISBLANK({40554;40568])), 1, (40554<=40574)*(40568>=40574))
becomes
IF(AND({FALSE;FALSE}), 1, (TRUE)*(FALSE))
becomes
IF(FALSE), 1, (TRUE)*(FALSE))
becomes
IF(FALSE), 1,0) returns 0.
Step 3 - Second criterion, color
I have bolded the second criterion below:
=SUMPRODUCT(IF(AND(ISBLANK($B$3:$B$4)), 1, ($B$3<=$B8)*($B$4>=$B8))*(IF(ISBLANK($C$3), 1, $C$3=$C8))*(IF(ISBLANK($D$3), 1, $D$3=$D8))*(IF(AND(ISBLANK($E$3:$E$4)), 1, ($E$3<=$E8)*($E$4>=$E8))))
IF(ISBLANK($C$3), 1, $C$3=$C8)
becomes
IF(ISBLANK("blue"), 1, "blue"="orange")
becomes
IF(FALSE, 1, False) returns FALSE.
Step 4 - Third criterion, products
I have bolded the third criterion below:
=SUMPRODUCT(IF(AND(ISBLANK($B$3:$B$4)), 1, ($B$3<=$B8)*($B$4>=$B8))*(IF(ISBLANK($C$3), 1, $C$3=$C8))*(IF(ISBLANK($D$3), 1, $D$3=$D8))*(IF(AND(ISBLANK($E$3:$E$4)), 1, ($E$3<=$E8)*($E$4>=$E8))))
IF(ISBLANK($D$3), 1, $D$3=$D8)
becomes
IF(ISBLANK("Product 4"), 1, "Product 4"="Product 3")
becomes
IF(FALSE, 1, FALSE) returns FALSE.
Step 5 - Fourth criterion, price
I have bolded the fourth criteria below:
=SUMPRODUCT(IF(AND(ISBLANK($B$3:$B$4)), 1, ($B$3<=$B8)*($B$4>=$B8))*(IF(ISBLANK($C$3), 1, $C$3=$C8))*(IF(ISBLANK($D$3), 1, $D$3=$D8))*(IF(AND(ISBLANK($E$3:$E$4)), 1, ($E$3<=$E8)*($E$4>=$E8))))
IF(AND(ISBLANK($E$3:$E$4)), 1, ($E$3<=$E8)*($E$4>=$E8))
becomes
IF(AND(ISBLANK({15;25})), 1, (15<=67,8)*(25>=67,8))
becomes
IF(AND({FALSE;FALSE}), 1, (TRUE)*(FALSE))
becomes
IF(FALSE, 1, 0) returns 0.
Step 6 - All criteria together
=SUMPRODUCT(IF(AND(ISBLANK($B$3:$B$4)), 1, ($B$3<=$B7)*($B$4>=$B7))*(IF(ISBLANK($C$3), 1, $C$3=$C7))*(IF(ISBLANK($D$3), 1, $D$3=$D7))*(IF(AND(ISBLANK($E$3:$E$4)), 1, ($E$3<=$E7)*($E$4>=$E7))))
becomes
=SUMPRODUCT(0*FALSE*FALSE*0)
becomes
=SUMPRODUCT(0) returns 0. Row 8 is not highlighted.
Final notes
The formula also works if you only have one criterion or two criteria.
Highlight overlapping date ranges using conditional formatting
The image above demonstrates a conditional formatting formula that colors a record if there is at least one record that […]
Count Conditionally Formatted cells
This article explains how to count cells highlighted with Conditional Formatting (CF). The image above shows data in cell range […]
Highlight records based on overlapping date ranges and a condition
adam asks: Hi, I have a situation where I want to count if this value is duplicate and if it […]
Merge two columns with possible blank cells
Question: This article is terrific. Thanks so much for posting this solution! I do have one question: Let's say my […]
Extract unique distinct values A to Z from a range and ignore blanks
This is an answer to a question in this blog post: Extract a unique distinct list sorted from A-Z from […]
How to use the ISBLANK function
The ISBLANK function returns TRUE if the argument is an empty cell, returns FALSE if not. Excel Function Syntax ISBLANK(value) […]
Remove common records between two data sets
This article demonstrates how to filter records occurring in only one out of two Excel defined tables. It also shows […]
Filter shared records from two tables
I will in this blog post demonstrate a formula that extracts common records (shared records) from two data sets in […]
Unique distinct records sorted based on count or frequency
Sara asks: How can you use large with multiple criteria?? Example looking for top 5 of a list based on […]
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.