Technical Article

UDF to get first date or trim time for Datepart.

,

Not long ago I was in a forum discussion when someone presented another way to get the date with time value of midnight by doing similar to this

DATEADD(dd,DATEDIFF(dd,0,@DATE),0)

Which I find is much cleaner than any other option I have seen or tried myself. Seeing this I realized there are many other dates that can be quickly figured by using this method so I researched each.

Well of course I found this much easier to do and decided to collect them all into a simple UDF to make reuse much easier.

First run the below script in the database you want the function available then call like so.

--Get first Sunday of week
select dbo.DateToPart(GETDATE(),'wk')

The valid @PART options are the same as the standard SQL date functions, however if you place a bad item in the date value will be returned untouched. Using the Millisecond option also does the same due to fact there is nothing to do.

Hope this helps out.

(Sorry I don't work much with UDFs and not sure how to throw a custom error, if anyone knows please pass along.)

CREATE FUNCTION dbo.DateToPart (@DATE datetime, @PART sysname)
RETURNS datetime
AS
BEGIN
DECLARE @DATEOUT datetime

SET @DATEOUT = @DATE
SET @PART = LOWER(@PART) -- In case server is setup case-sensitive.

-- Process to first day of year
IF @PART in ('yy','yyyy','year')
SET @DATEOUT = DATEADD(yyyy,DATEDIFF(yyyy,0,@DATE),0)
-- Process to first day of quater
ELSE IF @PART in ('qq','q','quarter')
SET @DATEOUT = DATEADD(qq,DATEDIFF(qq,0,@DATE),0)
-- Process to first day of month
ELSE IF @PART in ('mm','m','month')
SET @DATEOUT = DATEADD(mm,DATEDIFF(mm,0,@DATE),0)
-- Process to strip time from day Note: day of year, week day and day produce same result.
ELSE IF @PART in ('dd','d','day','dy','y','dayofyear', 'dw', 'weekday')
SET @DATEOUT = DATEADD(dd,DATEDIFF(dd,0,@DATE),0)
-- Process to first Sunday of week Note: 0 represents 1/1/1900 which is a Monday to get Sunday we use -1 instead.
ELSE IF @PART in ('wk','w','week')
SET @DATEOUT = DATEADD(wk,DATEDIFF(wk,-1,@DATE),-1)
-- Process to strip time keeping hour.
ELSE IF @PART in ('hh','hour')
SET @DATEOUT = DATEADD(hh,DATEDIFF(hh,0,@DATE),0)
-- Process to strip time keeping hour and minutes.
ELSE IF @PART in ('mi','n','minute')
SET @DATEOUT = DATEADD(mi,DATEDIFF(mi,0,@DATE),0)
-- Process to strip off Millisecond -- Note: Different since DATEDIFF(ss,0,time) produces a value larger than max int value.
ELSE IF @PART in ('ss','s','second')
SET @DATEOUT = DATEADD(ms,-DATEPART(ms,@DATE),@DATE)
-- Process to do nothing, if not a valid option or millisecond option.
ELSE
-- If you wanted to could set to NULL here if a bad option, 
-- just make sure you handle milliseconds.
SET @DATEOUT = @DATE
RETURN(@DATEOUT)
END

Rate

4 (1)

You rated this post out of 5. Change rating

Share

Share

Rate

4 (1)

You rated this post out of 5. Change rating