Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Determining If a Value is Out of Limits.
Written by Allen Wyatt (last updated June 12, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Jennifer has two numbers that she needs to compare in a formula. If the second number is within 5% (plus or minus) of the first number, it is considered within limits. If the second number is outside of this range, then she needs the formula to return something such as "out of limits."
There are a number of different ways you could approach your formula. Let's assume that your first number is in cell A1 and that the number you want to compare to it is in cell B1. One method is to use the IF function to do your testing:
=IF((A1-B1)>(A1*0.05),"out of limits", IF((B1-A1)>(A1*0.05),"out of limits", "within limits"))
This works fine, but the formula is a bit long. You can add the OR function to your formula to make it quite a bit shorter:
=IF(OR(B1<A1*0.95,B1>A1*1.05),"out of limits","within limits")
You could make the formula shorter still by skipping the OR function and simply doing a comparison on the absolute difference between the values:
=IF(ABS((B1-A1)/A1)<=0.05,"within limits","out of limits")
Since there is division happening in this formula, it is possible that you could get an error if the value in A1 is 0. To avoid this potential problem, the formula should be modified slightly:
=IF(A1=0,"unknown",IF(ABS((B1-A1)/A1)<=0.05, "within limits","out of limits"))
If the requirement is for the values to be "within 5% of each other," the calculation is slightly more complex:
=IF(ABS(B1-A1)/MAX(ABS(B1),ABS(A1))>0.05, "out of limits","within limits")
In this case, the MAX function is used to determine the larger of the two values in A1 and B1. It must test the absolute values of A1 and B1 because the MAX function returns the value nearest to zero if both numbers are negative.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11116) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Determining If a Value is Out of Limits.
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!
If you have a list of names in a column, and you want to know how many times those names appear in a larger list of data, ...
Discover MoreIf you have a bunch of ZIP Codes or part numbers in a list, you may want to "condense" the list so that sequential series ...
Discover MoreText placed in cells can either be lowercase, uppercase, or a mixture of the two. If you want to count the cells based ...
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 © 2025 Sharon Parq Associates, Inc.
Comments