SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Rounding a number up to the nearest 5


Rounding a number up to the nearest 5

Author
Message
smrobin
smrobin
Valued Member
Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)

Group: General Forum Members
Points: 72 Visits: 136
So I am attempting to mimic some legacy code on an old server at my work. It has a calculation to determine cost. What I need to do is round the number up to the nearest 5th.

For example:
1.0 -> 5 (everything less than 5 gets rounded to give)
5-> 5
5.75->5
8->10
11->15
86.5->90

so any number that has a 5 in it before the decimal - will stay rounded to 5. Example - 75.65 -> 75.

I have the following code:
declare @mon numeric(10,2)
set @mon = 86.5
select case when (round(@mon/5,0)*5) < 5 then 5
else (round(@mon/5,0)*5)
end

However - when I run it - 86.5 gets rounded to 85. I need it to round to 90.

Any suggestions?
Sean Lange
Sean Lange
One Orange Chip
One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)

Group: General Forum Members
Points: 26664 Visits: 17557
You can use a tally for this pretty easily.

Here is the code to create a tally table view. This is super fast!!!


create View [dbo].[Tally] as

WITH
E1(N) AS (select 1 from (values (1),(1),(1),(1),(1),(1),(1),(1),(1),(1))dt(n)),
E2(N) AS (SELECT 1 FROM E1 a, E1 b), --10E+2 or 100 rows
E4(N) AS (SELECT 1 FROM E2 a, E2 b), --10E+4 or 10,000 rows max
cteTally(N) AS
(
SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) FROM E4
)
select N from cteTally
GO



Now we just need to create your query. Please note that I used a cte here because we didn't have a table of data to work with.


with MyData (MyValue, Target) as
(
select 1.0, 5 union all
select 5, 5 union all
select 5.75, 5 union all
select 8, 10 union all
select 11, 15 union all
select 86.5, 90
)

select *
from MyData d
cross apply
(
select top 1 * from Tally
where N >= d.MyValue
and N % 5 = 0
order by N
) x



--EDIT--

You can read more about tally tables here. http://www.sqlservercentral.com/articles/62867/

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
LinksUp
LinksUp
Ten Centuries
Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)

Group: General Forum Members
Points: 1033 Visits: 4456
Though not as cool a solution as Mr. Lange's tally table, this alternative is more math oriented than set oriented and is very fast. Plus you could easily turn this into a SP passing any value that you want to round to. NOTE: I borrowed Mr. Lange's cte to demo the solution. (Thank-you!)


;with MyData (MyValue, Target) as
(
select 0.5, 5 union all
select 1.0, 5 union all
select 2.0, 5 union all
select 5, 5 union all
select 5.75, 5 union all
select 8, 10 union all
select 11, 15 union all
select 50, 50 union all
select 50.5, 50 union all
select 50.75, 50 union all
select 51, 55 union all
select 54.99, 55 union all
select 86.5, 90
)
Select d.MyValue, d.Target,
case when d.MyValue % 5 < 1 then FLOOR(d.MyValue)
when d.MyValue % 5 < 3 then FLOOR ((d.MyValue + (5.0 / 2.0)) / 5) * 5.0 + 5.0
else FLOOR((d.MyValue + (5.0 / 2.0)) / 5) * 5.0
end as Result
from MyData d




The case statement was required because you are rounding UP to the nearest 5, not just to the nearest 5.

__________________________________________________________________________________________________________
How to Post to get the most: http://www.sqlservercentral.com/articles/Best+Practices/61537/
smrobin
smrobin
Valued Member
Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)

Group: General Forum Members
Points: 72 Visits: 136
Thanks for the reply - the problem I have is that I don't always know what the number will be. I have the rules to which I apply to the numbers.

I was hoping to write a simple case statement to handle everything. Any suggestions on that?
LinksUp
LinksUp
Ten Centuries
Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)

Group: General Forum Members
Points: 1033 Visits: 4456
smrobin (9/13/2013)
Thanks for the reply - the problem I have is that I don't always know what the number will be. I have the rules to which I apply to the numbers.


Not sure who you are talking to!

Since you did not provide any dll or sample data, it had to be made up. Both solutions are generic in that you have to modify either of them to use your table and your column names. Also, both solutions are rounding up whatever is passed to them. There is no "fixed" value.


I was hoping to write a simple case statement to handle everything.


Is that not what I posted?

__________________________________________________________________________________________________________
How to Post to get the most: http://www.sqlservercentral.com/articles/Best+Practices/61537/
Sean Lange
Sean Lange
One Orange Chip
One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)

Group: General Forum Members
Points: 26664 Visits: 17557
Edited my code...but the edit was incorrect. :-D

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
smrobin
smrobin
Valued Member
Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)Valued Member (72 reputation)

Group: General Forum Members
Points: 72 Visits: 136
Thanks for the replies guy! I used your combined logic and got it to work! Thanks again - love this site!
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)

Group: General Forum Members
Points: 88952 Visits: 41136
smrobin (9/16/2013)
Thanks for the replies guy! I used your combined logic and got it to work! Thanks again - love this site!


Two way street here, my friend. Please post what you ended up with. Thanks.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Don Halloran
Don Halloran
Mr or Mrs. 500
Mr or Mrs. 500 (577 reputation)Mr or Mrs. 500 (577 reputation)Mr or Mrs. 500 (577 reputation)Mr or Mrs. 500 (577 reputation)Mr or Mrs. 500 (577 reputation)Mr or Mrs. 500 (577 reputation)Mr or Mrs. 500 (577 reputation)Mr or Mrs. 500 (577 reputation)

Group: General Forum Members
Points: 577 Visits: 1490
select ceiling(floor(@somevalue) / 5.0) * 5.0

Blog on sqlservercentral
LinksUp
LinksUp
Ten Centuries
Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)

Group: General Forum Members
Points: 1033 Visits: 4456
Don Halloran (9/18/2013)
select ceiling(floor(@somevalue) / 5.0) * 5.0


A MUCH better solution!

__________________________________________________________________________________________________________
How to Post to get the most: http://www.sqlservercentral.com/articles/Best+Practices/61537/
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search