Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. 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: Avoiding Rounding Errors in Formula Results.
Written by Allen Wyatt (last updated August 26, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Nick notes that the formula "=0.28*100-INT(0.28*100)=0" returns False even though it is obviously true. He believes the issue has to do with rounding and how the computer uses binary arithmetic, etc. Nick is using the formula as a part of a larger IF statement, and he assumes there are other rounding errors in Excel that can reach out and bite him. He wonders if there is a simple way to avoid formula pitfalls such as this.
Before looking at simple ways to avoid this type of problem, it is important to understand why the problem exists. As Nick notes, it really has to do with binary arithmetic and the fact that Excel rounds information. Behind the scenes, Excel always rounds information to 15 digits. Consider the calculation that Nick is working with:
=0.28*100-INT(0.28*100)=0
When Excel first calculates this, the precedence followed by Excel calculates it in this manner:
=(0.28*100-INT(0.28*100))=0
Note the extra set of parentheses. The result of everything to the left of that final equal sign is 3.55E-15, which means that you end up with this (longhand) formula:
=0.00000000000000355=0
This is obviously not true, which is why you get the value False returned. There are several ways to "fix" this situation. In this case, perhaps the easiest is to simply change your formula to remove the need to compare to zero:
=0.28*100=INT(0.28*100)
This formula returns True, as you would expect. This may not work for all your needs, however. So, a better rule of thumb to avoid problems is to never rely on Excel's rounding. You do this by implementing your own explicit rounding, as shown with these formulas:
=INT(0.28*100)-INT(0.28*100)=0 =ROUND(0.28*100,0)-INT(0.28*100)=0 =ROUND(0.28*100,5)-ROUND(0.28*100,5)=0
Note that you are, in these instances, not allowing Excel to perform calculations to its full precision since that can cause some unexpected results when you are comparing to a specific value, such as zero. Instead, you are forcing Excel to round the values—all the values you are working with—to whatever level of precision you need for your comparison.
Another approach is to not do the comparison to an exact value, like zero. Instead, allow for some "fudge factor" in the comparison, which allows for rounding issues. For instance, you may determine that you only care if the comparison is accurate to one one-hundredth of whatever units you are assuming. In that case, the original formula could be modified in this manner:
=0.28*100-INT(0.28*100)<0.01
This returns True, as one would expect.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8145) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Avoiding Rounding Errors in Formula Results.
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!
Need to round values up to the next value that ends in 9? There are a number of ways you can accomplish the task through ...
Discover MoreIf you want to round a value to some multiple of a whole number, you'll want to become familiar with the MROUND function. ...
Discover MoreNeed to round the time in a cell to a certain value? There are a couple of ways you can do this with a formula.
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-08-26 10:48:43
David J Bonin
The last formula happens to use the value 0.28:
=0.28*100-INT(0.28*100)<0.01
Many times, the "0.28" value is in a cell, say B17, and the result may be positive or negative.
This is more robust:
=ABS(B17*100-INT(B17*100))<0.01
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