Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 General SQL Server Forums
 Script Library
 Rounding to NEAREST X.XX

Author  Topic 

ccscowboy
Starting Member

1 Post

Posted - 2010-12-15 : 10:34:50
we have always had an issue with our customers to round to nearest 1.99 or 5.99 or 0.99 things like that... myself and Glenn a coworker wrote the following Scalar function to solve it,

1 = up, 2 = down, and 3 - nearest

-- SQLACTION:RELEASE
-- =============================================
-- Author: Andy Stapleton
-- Create date: 2010-12-15
-- Description: RoundNumber to Nearest up or down.
-- =============================================
CREATE FUNCTION DBO.GET_RoundVal_FN(@Amt Decimal(19,6),@RoundTo Decimal(19,6),@RoundType int )
RETURNS Decimal(19,6)
AS
BEGIN
-- Declare the return variable here
declare @rp int,
@rb int,
@RetVal Decimal(19,6),
@Dir Varchar(5)


set @rp = convert(int,@RoundTo-1)
IF @rp < 0
set @rp = 0
--end

IF @rp <> 0
set @rp = len(convert(varchar(25),@rp))
set @rb = POWER(10,@rp) -- Base as a power, results in a 1, 10, 100, 1000, etc.


set @RetVal = (convert(int,(@Amt / @rb)) * @rb) + @RoundTo

IF @RoundType = 1 and @RetVal < @Amt --up
set @RetVal = @RetVal + @rb
--END

IF @RoundType = 2 and @RetVal > @Amt -- down
set @RetVal = @RetVal - @rb
--END

IF @RoundType = 3 and abs(@RetVal - @Amt) > abs((@RetVal-@rb) - @Amt)
set @RetVal = @RetVal - @rb
--end
IF @RetVal < 0
set @RetVal = @RetVal + @rb
--END

RETURN isNull(@RetVal,0)

END
GO


--Select DBO.GET_NearestNo_FN(136.10,0.99,3)


Andy <<cowboy>> Stapleton

SwePeso
Patron Saint of Lost Yaks

30421 Posts

Posted - 2011-02-10 : 15:24:04
This seems easier to me
CREATE FUNCTION dbo.fnGetRoundVal
(
@Amt DECIMAL(19, 6),
@RoundTo DECIMAL(19, 6),
@RoundType TINYINT
)
RETURNS DECIMAL(19, 6)
AS
BEGIN
RETURN (
SELECT CASE
WHEN @RoundType = 1 THEN @Amt + Up
WHEN @RoundType = 2 THEN @Amt - Down
WHEN Down < Up THEN @Amt - Down
ELSE @Amt + Up
END
FROM (
SELECT @Amt % CEILING(@RoundTo) - @RoundTo + CEILING(@RoundTo) AS Down,
@RoundTo - @Amt % CEILING(@RoundTo) AS Up
) AS d
)
END



N 56°04'39.26"
E 12°55'05.63"
Go to Top of Page
   

- Advertisement -