Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Rounding a number up to the nearest 5 Expand / Collapse
Author
Message
Posted Friday, September 13, 2013 2:08 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Monday, March 24, 2014 10:07 AM
Points: 13, Visits: 70
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?
Post #1494726
Posted Friday, September 13, 2013 2:28 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 2:49 PM
Points: 12,016, Visits: 11,046
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 Moden's 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)
Post #1494732
Posted Friday, September 13, 2013 3:08 PM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Today @ 6:58 PM
Points: 319, Visits: 1,147
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/
Post #1494740
Posted Friday, September 13, 2013 3:26 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Monday, March 24, 2014 10:07 AM
Points: 13, Visits: 70
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?
Post #1494746
Posted Friday, September 13, 2013 3:40 PM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Today @ 6:58 PM
Points: 319, Visits: 1,147
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/
Post #1494750
Posted Monday, September 16, 2013 8:02 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 2:49 PM
Points: 12,016, Visits: 11,046
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 Moden's 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)
Post #1495098
Posted Monday, September 16, 2013 4:19 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Monday, March 24, 2014 10:07 AM
Points: 13, Visits: 70
Thanks for the replies guy! I used your combined logic and got it to work! Thanks again - love this site!
Post #1495321
Posted Monday, September 16, 2013 6:06 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 9:45 PM
Points: 36,013, Visits: 30,300
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."

"Change is inevitable. Change for the better is not." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1495330
Posted Wednesday, September 18, 2013 5:52 PM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Yesterday @ 1:02 AM
Points: 316, Visits: 1,120
select ceiling(floor(@somevalue) / 5.0) * 5.0

allmhuran.com - download the SSMSDeploy addin for SSMS 2008
Blog on sqlservercentral
Post #1496177
Posted Wednesday, September 18, 2013 6:06 PM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Today @ 6:58 PM
Points: 319, Visits: 1,147
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/
Post #1496179
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse