Rounding Up to a Value Ending in 9

by Allen Wyatt
(last updated June 23, 2018)

4

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, and Excel in Office 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

Using InputBox to Get Data

Need your macro to get some input from a user? The standard way to do this is with the InputBox function, described in ...

Discover More

Jumping to a Relative Endnote

Endnotes are easy enough to add and accumulate in a document. For this reason, Word makes it easy to jump from one ...

Discover More

Creating a Year-to-Date Comparison Chart

Excel is an excellent tool for keeping track of data over time. If you have information you are keeping by year, you may ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

More ExcelTips (ribbon)

Rounding to the Nearest $50

When preparing financial reports, it may make your data easier to understand if you round it to the nearest multiple, ...

Discover More

Rounding Up to the Next Half

When processing data it is not unusual to need to round that data in some way. For instance, you may need to round a ...

Discover More

Rounding to Two Significant Digits

Excel provides a variety of functions you can use to round values in any number of ways. It does not, however, provide a ...

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}] 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 2 + 9?

2018-06-26 15:33:48

Willy Vanhaelen

@Neill
Your question was a little fuzzy and by re-reading it carefully I realised that you probably meant a sequence of 5th, 15th and 25th. If so, the UDF i posted earlier will not meat your requirements. This UDF then will:

Function FormatDate(X As Date)
If Day(X) > 25 Then
FormatDate = Application.EoMonth(X, 0) + 5
Else
FormatDate=DateSerial(Year(X),Month(X),Application.RoundUp(Day(X)+ 5,-1)- 5)
End If
End Function

If you entrer =FormatDate("6/6/2018) this UDF will return 15 Jun 2018.


2018-06-26 12:18:09

Willy Vanhaelen

@Neill
This User Defined Function should do the job:

Function FormatDate(X As Date)
If Day(X) > 25 Then
FormatDate = Application.EoMonth(X, 0) + 5
Else
FormatDate=DateSerial(Year(X),Month(X),Application.Ceiling(Day(X),5))
End If
End Function

Place this macro in a module.
For the 6th of June for example, enter: =FormatDate("6/6/2018")
The result is: 10 Jun 2018.

Let me know if this meets your requirement.


2018-06-25 02:39:35

Neill

How would you roundup to the nearest x5th of each month (5th (for 26th of prior month through to 5th of current month), 15th, 25th) ?


2018-06-23 14:19:02

Erik

This also works:
=TRUNC(A1*10)/10+0.09


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.