Highlighting Values that are 10x a Baseline Value

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


Marissa works for a lab where she uses Excel to prepare client reports showing the results of mold spore sampling. The first sample shown is always the baseline. All subsequent samples on the report need to be highlighted if they are 10x the baseline. Marissa has this figured out if the baseline is greater than 0, but if the baseline is 0, the samples should only be highlighted if they are 10 or more. (In other words, a baseline of 0 and 1 are treated exactly the same for comparison and highlighting purposes.)

Let's assume, for a moment, that the baseline value is in cell A2. Chances are good that Marissa has developed a formula for her conditional formatting rule which compares the sample values (let's say they start in cell A3) with the baseline value, multiplied by 10, like this:

=A3 >= ($A$2 * 10)

This returns True if the value in A3 is greater than or equal to the baseline value in cell A2. The only thing that needs to be done to this formula is to make sure that the baseline value being used is never less than 1. There are any number of adjustments that can be done to the formula. For instance, the following uses an IF statement to evaluate the baseline value. If it is equal to 0, then it returns a modified value of 10.

=A3 >= (IF($A$2 = 0, 10, $A$2 * 10))

You could also use the MAX function, if desired, which returns the largest value from a series of values:

=A3 >= (MAX($A$2,1) * 10)

Note that MAX will return either the baseline value in A2 or the value 1, whichever is greater. In other words, the baseline value will never be less than 1.

Finally, you could avoid worksheet functions in your formula altogether if you simply rely on how Excel handles Boolean logic. Consider this formula:

=A3 >= ($A$2 + ($A$2 = 0)) * 10

This works on the very simple principle that, if the baseline value (cell A2) contains 0, then ($A$2=0) returns the value 1 (the value Excel uses for True); if the baseline value is anything other than 0, then the test ($A$2=0) will return 0 (the value Excel uses for False). This value (1 or 0) will then be added to the baseline and multiplied by 10. In other words, if A2 contains zero, the formula will be tested against 0+1, which equals 1, and so the test will be performed as if A2 contained 1.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13447) 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

Deleting Everything Except Formulas

Need to get rid of everything in a worksheet except the formulas? It's easier to make this huge change than you think it is.

Discover More

Printing a List of Named Ranges

You already know that you can define names that apply to different ranges of cells and other elements such as formulas. ...

Discover More

Understanding Macros

What is a macro? Ever wonder what these are and how to use them? This tip answers the basics of what a macro is used for, ...

Discover More

Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!

More ExcelTips (ribbon)

Highlighting Greater Than Average Dry Durations

If you need to find whether the duration between two dates is greater than the average of all durations, you'll find the ...

Discover More

Diagonal Borders in a Conditional Format

Conditional formatting is a great tool for changing how your data looks based on the data itself. Excel won't allow you ...

Discover More

Coloring Identical Company Names

Want to know where duplicates are in a list of names? There are a couple of ways you can go about identifying the ...

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 seven more than 7?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


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.