Written by Allen Wyatt (last updated August 26, 2023)
This tip applies to Excel 2007, 2010, 2013, 2019, Excel in Microsoft 365, and 2021
Bob performs calculations and wants to round the results up to the next value that ends in 9. In other words, to set a target retail price he wants to calculate the various costs and then round the answers up so that they end in 9. Thus, $1.42 rounds to $1.49, $1.49 has no change, $9.01 rounds to $9.09, etc.
There are actually quite a few formulas you can use to adjust your prices as you desire. Excel provides a good number of different rounding functions that can be tried. You might think that you could use a simple ROUNDUP function to do the work, as shown in the following:
=ROUNDUP(A1,1)-0.01
This won't work properly, however, if the value in A1 ends with a zero (1.00, 1.10, 1.20, etc.). In that case the formula simply subtracts 0.01 from the original value, converting 1.00 to 0.99, for instance.
The solution is to add 0.01 to the value in A1 before you do the rounding, in this manner:
=ROUNDUP(A1+0.01,1)-0.01
You can also use the CEILING function in almost the exact same manner as you did the ROUNDUP function:
=CEILING(A1+0.01,0.1)-0.01
A different (and shorter) approach, though, is to use the ROUNDDOWN function to do the rounding, in this manner:
=ROUNDDOWN(A1,1)+0.09
You could also use the straight ROUND function in this manner:
=ROUND(A1+0.05,1)-0.01
Shorter still is a solution that doesn't rely on any of the built-in rounding functions:
=(INT(A1*10)+0.9)/10
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12825) applies to Microsoft Excel 2007, 2010, 2013, 2019, Excel in Microsoft 365, and 2021.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
Rounding is a fact of life when it comes to using formulas in a worksheet. Sometimes that rounding can be a bit ...
Discover MoreSome formulas just don't give the results you expect. Sometimes this is due to the way that Excel handles rounding. ...
Discover MoreHow to round values half way between two boundaries is apparently a topic of contention in some sectors of the ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-08-27 10:37:48
J. Woolley
Malcolm Standage mentioned Precision as Displayed. For more on that subject, see https://excelribbon.tips.net/T013765_Permanently_Turning_On_Set_Precision_As_Displayed.html
Also, see https://excelribbon.tips.net/T009901_Getting_Rid_of_Negative_Zero_Amounts.html
My comment there describes the PrecisionToggleLink function, which has been deleted and replaced by the following function:
=RunMacroLink("TogglePrecision",[Friendly_Name],[Screen_Tip])
See https://sites.google.com/view/MyExcelToolbox
2023-08-26 22:59:06
Malcolm Standage
How about using "Precision as displayed"
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