Conditionally Highlighting a Milestone Cell

Written by Allen Wyatt (last updated February 10, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365


3

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, 2021, and Excel in Microsoft 365.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Automatically Loading Add-ins

Want to load a particular add-in for use with a specific worksheet? Here's a quick way to do it using macros.

Discover More

Converting Numeric Values to Times

If you have a bunch of times entered into cells without the colon between the hours and minutes, chances are good that ...

Discover More

Determining the Current Directory

When you use a macro to do file operations, it works (by default) within the current directory. If you want to know which ...

Discover More

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 365 applications with VBA programming. Written in clear terms and understandable language, the book includes systematic tutorials and contains both intermediate and advanced content for experienced VB developers. Designed to be comprehensive, the book addresses not just one Office application, but the entire Office suite. Check out Mastering VBA for Microsoft Office 365 today!

More ExcelTips (ribbon)

Returning a Value Based on Text Color

Conditional formatting rules can be used to adjust the way in which information is displayed in Excel, such as the text ...

Discover More

Conditional Format that Checks for Data Type

Conditional formatting can be used to highlight cells that contain the improper type of data for your needs. This tip ...

Discover More

Shading Based on Odds and Evens

You can use conditional formatting to add shading to various cells in your worksheet. This tip shows how you can shade ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 9 + 1?

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.


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.