Written by Allen Wyatt (last updated February 10, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Steve has a worksheet that he uses to track his walking steps and distance. He has daily totals and a cumulative column. Using a conditional formatting rule, Steve would like to highlight "milestone" cells—for instance, when the cumulative total reaches or exceeds 100,000 steps. He wonders how to pinpoint that the target has been reached and highlight just the single cell, not all the cells that follow the milestone.
In setting up your conditional formatting rule, you'll need to do so using a formula. First, select all the cells in your cumulative column to which you want the conditional format applied. (In my case, I selected cells in column B, starting with cell B2, which I assume is where the cumulative values are.) Then, create a conditional formatting rule that uses any of the following formulas:
=B2=MIN(FILTER(B:B,B:B>=100000)) =B2=MINIFS(B:B,B:B,">=100000") =AND(B2>=100000,B1<100000) =IF(B1<100000,IF(B2>=100000,TRUE,FALSE),FALSE) =COUNTIF($B$2:B2,">=100000")=1
Which should you choose? It doesn't really matter; they all do essentially the same thing—to return True if the threshold is met. The key is to make sure you select the range to which it should be applied and modify the formulas to reflect the selected cell in the range (B2 in all of these).
These formulas will highlight only the first cell after the threshold (100,000). If you want to, instead, highlight the cells after each threshold crossing (100,000, 200,000, 300,000, etc.), then you should use a different formula. Any of the following will work just fine:
=FLOOR(B2,100000)<>FLOOR(B1,100000) =(MOD(B2,100000)-MOD(B1,100000))<=0 =MOD(B2,100000)Remember to change the formatting in your conditional formatting rule to reflect how you want the appropriate value (the one after the threshold) to be highlighted.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11470) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
Conditional formatting is a great tool. You may need to use this tool to tell the difference between cells that are empty ...
Discover MoreIf you need to shade alternating rows in a data table, you'll want to examine how you can accomplish the task with ...
Discover MoreConditional formatting rules can be used to adjust the way in which information is displayed in Excel, such as the text ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2024-02-12 09:50:13
J. Woolley
@Enno
I'm curious. Excel's documents say FILTER is in Excel 2019 for Windows and MINIFS is in Excel 2019 for Windows or Mac. Please confirm you are using Excel 2019 for Windows and cannot apply those functions.
See https://support.microsoft.com/en-us/office/filter-function-f4f7cb66-82eb-4767-8f7c-4877ad80c759
and https://support.microsoft.com/en-us/office/minifs-function-6ca1ddaa-079b-4e74-80cc-72eef32e6599
2024-02-12 02:55:29
Enno
"This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021"
This is not correct, because my Excel 2019 do not know FILTER and MINIFS.
EPH
2024-02-11 10:18:25
J. Woolley
If you want to apply the rule to all of column B ($B:$B) instead of $B2:$B??, the Tip's first 5 formulas must be modified as follows:
=B1=MIN(FILTER(B:B,B:B>=100000))
=B1=MINIFS(B:B,B:B,">=100000")
=AND(B1>=100000,OFFSET(B1,-1,0)<100000)
=IF(OFFSET(B1,-1,0)<100000,IF(B1>=100000,TRUE,FALSE),FALSE)
=COUNTIF($B$1:B1,">=100000")=1
The first 2 formulas using FILTER and MINIFS require Excel 2019 or later.
Curiously the two formulas with OFFSET(B1,-1,0) should produce a #REF! error because there is no cell B0, but Excel's conditional formatting logic seems to ignore that.
Here are the corresponding modifications for the Tip's final 3 formulas:
=FLOOR(B1,100000)<>FLOOR(OFFSET(B1,-1,0),100000)
=(MOD(B1,100000)-MOD(OFFSET(B1,-1,0),100000))<=0
=MOD(B1,100000)=0
(Notice there is an error in the Tip's final formula.) Unfortunately, these 3 formulas also highlight blank cells.
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments