SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 General SQL Server Forums
 Script Library
 Rounding to NEAREST X.XX
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

ccscowboy
Starting Member

USA
1 Posts

Posted - 12/15/2010 :  10:34:50  Show Profile  Reply with Quote
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

Sweden
30277 Posts

Posted - 02/10/2011 :  15:24:04  Show Profile  Visit SwePeso's Homepage  Reply with Quote
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
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.05 seconds. Powered By: Snitz Forums 2000