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


Round Natural Numbers to the nearest Power of 10


Round Natural Numbers to the nearest Power of 10

Author
Message
hkravitz
hkravitz
SSC Veteran
SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)

Group: General Forum Members
Points: 295 Visits: 225
Comments posted to this topic are about the item Round Natural Numbers to the nearest Power of 10
t.franz
t.franz
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1329 Visits: 297
Why do you not use the build in ROUND function?
It takes three parameters:
- the value
- the rounding length (use negative numbers to round to a power of 10, example for 12345: -1 -> = 12350, -2 -> 12300, -3 = 12000
- optional 0 or 1, while the default 0 rounds, while 1 will cut the numbers off;
ROUND(12345, -1, 0) = 12350
while
ROUND(12345, -1, 1) = 12340


The only benefit of your
function is the easier usage of the direction (up or down), but this could be solved by cutting off the decimals (= rounding down) and adding 10 (or 100 or 1000...) when you want to round up:
ROUND(12345, -1, 1) + 10


PS: Bonus points for using an INLINE TABLE VALUE function instead of a scalar function
Luis Cazares
Luis Cazares
SSC Guru
SSC Guru (65K reputation)SSC Guru (65K reputation)SSC Guru (65K reputation)SSC Guru (65K reputation)SSC Guru (65K reputation)SSC Guru (65K reputation)SSC Guru (65K reputation)SSC Guru (65K reputation)

Group: General Forum Members
Points: 65288 Visits: 20238
Your function has a problem when it's used against negative numbers. I wrote an article some time ago about this options which simulate CEILING and FLOOR. You can read it in here: http://www.sqlservercentral.com/articles/T-SQL/145448/
s
Here's a corrected version for your function

CREATE FUNCTION dbo.udf_RoundNearest
(
@Number bigint, /*Natural Number*/
@RoundNearest float, /*Power of 10, 10^n , 10,100,1000...*/
@Direction int /* 0-> Down , 1 -> Up */
)
RETURNS TABLE AS
RETURN
SELECT CASE WHEN @Direction = 0
THEN ROUND(@Number-(.49*@RoundNearest),-LOG10(@RoundNearest))
ELSE ROUND(@Number+(.49*@RoundNearest),-LOG10(@RoundNearest))
END Number
GO



Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
hkravitz
hkravitz
SSC Veteran
SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)

Group: General Forum Members
Points: 295 Visits: 225
Luis Cazares - Tuesday, May 16, 2017 6:27 AM
Your function has a problem when it's used against negative numbers. I wrote an article some time ago about this options which simulate CEILING and FLOOR. You can read it in here: http://www.sqlservercentral.com/articles/T-SQL/145448/
s
Here's a corrected version for your function

CREATE FUNCTION dbo.udf_RoundNearest
(
@Number bigint, /*Natural Number*/
@RoundNearest float, /*Power of 10, 10^n , 10,100,1000...*/
@Direction int /* 0-> Down , 1 -> Up */
)
RETURNS TABLE AS
RETURN
SELECT CASE WHEN @Direction = 0
THEN ROUND(@Number-(.49*@RoundNearest),-LOG10(@RoundNearest))
ELSE ROUND(@Number+(.49*@RoundNearest),-LOG10(@RoundNearest))
END Number
GO

Thank you for your input!

hkravitz
hkravitz
SSC Veteran
SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)SSC Veteran (295 reputation)

Group: General Forum Members
Points: 295 Visits: 225
t.franz - Tuesday, May 16, 2017 2:56 AM
Why do you not use the build in ROUND function?
It takes three parameters:
- the value
- the rounding length (use negative numbers to round to a power of 10, example for 12345: -1 -> = 12350, -2 -> 12300, -3 = 12000
- optional 0 or 1, while the default 0 rounds, while 1 will cut the numbers off;
ROUND(12345, -1, 0) = 12350
while
ROUND(12345, -1, 1) = 12340


The only benefit of your
function is the easier usage of the direction (up or down), but this could be solved by cutting off the decimals (= rounding down) and adding 10 (or 100 or 1000...) when you want to round up:
ROUND(12345, -1, 1) + 10


PS: Bonus points for using an INLINE TABLE VALUE function instead of a scalar function

Thanks!

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