Conditional Formatting consecutive cells

Venners

New Member
Joined
Jul 12, 2022
Messages
11
Office Version
  1. 365
Platform
  1. MacOS
I'm trying to figure out how to highlight cells where there are 3 or more consecutive occurrences of a number above 85 which would highlight in green and 3 or more consecutive occurrences of a number under 80 which would highlight in red, I imagine there'd be two different conditional formatting rules needed for them. So in the below table, cells A18, B18, C18 and D18 would all be Green as they were consecutively over 85, and E5, F5, G5 would be in red as they're under 80

Book1
ABCDEFGH
1
284.4790.8381.8283.18
374.9481.8278.0181.42
476.5284.2485.6685
577.7879.3277.9
687.1283.4882.0581.1480.68
787.5589.41
883.989.8387.05
980.8384.8186.14
1073.9482.0176.86
1189.1488.64
1283.3284.09
1386.8285.81
1492.739085.9187.17
15
1685.77
1783.41
1880.489.5590.7188.5180.188.5982.95
1987.8392.07
2081.2387.82
2174.2983.7176.8280.6182.02
2280.5688.38
2374.9482.0582.7377.0574.89
2482.5883.4884.85
2582.68
2680.37
2780.880.6482.0580.3881.09
2873.7482.17
29
30
Sheet1
 

Excel Facts

Who is Mr Spreadsheet?
Author John Walkenbach was Mr Spreadsheet until his retirement in June 2019.
Two conditional formatting rules are needed. It might be possible to simplify these.

cells A18, B18, C18 and D18 would all be Green as they were consecutively over 85,
A18 is not over 85.

$scratch.xlsm
ABCDEFG
1
284.4790.8381.8283.18
374.9481.8278.0181.42
476.5284.2485.6685
577.7879.3277.9
687.1283.4882.0581.1480.68
787.5589.41
883.989.8387.05
980.8384.8186.14
1073.9482.0176.86
1189.1488.64
1283.3284.09
1386.8285.81
1492.739085.9187.17
15
1685.77
1783.41
1880.489.5590.7188.5180.188.5982.95
1987.8392.07
2081.2387.82
2174.2983.7176.8280.6182.02
2280.5688.38
2374.9482.0582.7377.0574.89
2482.5883.4884.85
2582.68
2680.37
2780.880.6482.0580.3881.09
2873.7482.17
Consecutive CF
Cells with Conditional Formatting
CellConditionCell FormatStop If True
A1:G28Expression=OR(IFERROR(COUNTIF(OFFSET(A1,0,-2,1,3),"<80")=3,FALSE),IFERROR(COUNTIF(OFFSET(A1,0,-1,1,3),"<80")=3,FALSE),IFERROR(COUNTIF(OFFSET(A1,0,0,1,3),"<80")=3,FALSE))textNO
A1:G28Expression=OR(IFERROR(COUNTIF(OFFSET(A1,0,-2,1,3),">85")=3,FALSE),IFERROR(COUNTIF(OFFSET(A1,0,-1,1,3),">85")=3,FALSE),IFERROR(COUNTIF(OFFSET(A1,0,0,1,3),">85")=3,FALSE))textNO
 
Upvote 0
Solution

Forum statistics

Threads
1,224,824
Messages
6,181,186
Members
453,020
Latest member
Mohamed Magdi Tawfiq Emam

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top