September 13, 2013 at 2:08 pm
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?
September 13, 2013 at 2:28 pm
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/[/url]
_______________________________________________________________
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 http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
September 13, 2013 at 3:08 pm
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/
September 13, 2013 at 3:26 pm
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?
September 13, 2013 at 3:40 pm
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/
September 16, 2013 at 8:02 am
Edited my code...but the edit was incorrect. 😀
_______________________________________________________________
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 http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
September 16, 2013 at 4:19 pm
Thanks for the replies guy! I used your combined logic and got it to work! Thanks again - love this site!
September 16, 2013 at 6:06 pm
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
Change is inevitable... Change for the better is not.
September 18, 2013 at 5:52 pm
select ceiling(floor(@somevalue) / 5.0) * 5.0
September 18, 2013 at 6:06 pm
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/
Viewing 10 posts - 1 through 9 (of 9 total)
You must be logged in to reply to this topic. Login to reply