Written by Allen Wyatt (last updated June 10, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
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, Excel in Microsoft 365, and 2021.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
There are many times when you are creating a worksheet that you need to analyze dates within that worksheet. Once such ...
Discover MoreAfter you've applied a conditional format to a cell, you may have a need to later delete that format so that the cell is ...
Discover MoreConditional formatting can be easily set up to check data on the current worksheet. If you want to check data on the ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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