-- to get resutl like Oct2007-May2009 from two dates
-- use below function like this
select dbo.frommonthyeartomonthyear('10/09/2007','05/03/2009') create function FromMonthYearToMonthYear(@FromDate datetime,@ToDate datetime) returns nvarchar(15) begin return left(DATENAME(month, @FromDate),3)+''+ convert(nvarchar(4), year(@FromDate)) +'-'+left(DATENAME(month, @ToDate),3)+''+ convert(nvarchar(4), year(@ToDate)) end create function DateOnly(@DateTime DateTime) -- Returns @DateTime at midnight; i.e., it removes the time portion of a DateTime value. returns datetime as begin return dateadd(dd,0, datediff(dd,0,@DateTime)) end go create function Date(@Year int, @Month int, @Day int) -- returns a datetime value for the specified year, month and day returns datetime as begin return dateadd(month,((@Year-1900)*12)+@Month-1,@Day-1) end go create function Time(@Hour int, @Minute int, @Second int) -- Returns a datetime value for the specified time at the "base" date (1/1/1900) returns datetime as begin return dateadd(ss,(@Hour*3600)+(@Minute*60)+@Second,0) end go create function TimeOnly(@DateTime DateTime) -- returns only the time portion of a DateTime, at the "base" date (1/1/1900) returns datetime as begin return dateadd(day, -datediff(day, 0, @datetime), @datetime) end go create function DateTime(@Year int, @Month int, @Day int, @Hour int, @Minute int, @Second int) -- returns a dateTime value for the date and time specified. returns datetime as begin return dbo.Date(@Year,@Month,@Day) + dbo.Time(@Hour, @Minute,@Second) end goRemember that you must prefix UDFs with the owner (usually dbo) when calling them.
Usage Examples:
where TransactionDate >= dbo.Date(2005,1,2) -- no formatting or implicit string conversions needed for date literals select dbo.Date(year(getdate()), 1,1) -- returns the first day of the year for the current year. select dbo.DateOnly(getdate()) -- returns only the date portion of the current day. if dbo.TimeOnly(SomeDate) = dbo.Time(5,30,0) -- check to see if the time for a given date is at 5:30 AM select dbo.Date(year(getdate()), month(getdate()),1) -- returns the first day of the current month. select dbo.Date(year(getdate()), month(getdate())+1,0) -- returns the last day of the current month. where SomeDate >= dbo.DateOnly(getdate()) and SomeDate < dbo.DateOnly(getDate())+1 -- a simple way to get all transactions that occurred on the current date select dbo.DateOnly(getdate()) + 1 + dbo.Time(14,30,0) -- returns tomorrow at 2:30 PM. and so on ....Part II: Introducing TimeSpans to SQL Server With those functions in place, we can add two more that will give us further flexibility when working with dates and times: The concept of a "TimeSpan", very similar to what is available in the .NET framework. -- to get time only with AM/PM and no date
create function TimeOnlyNODate(@DateTime DateTime) returns char(26) as begin return LTRIM(RIGHT(CONVERT(CHAR(26),@DateTime,109),14)) end select dbo.timeonlynodate(getdate()) select LTRIM(RIGHT(CONVERT(CHAR(26),GETDATE(),109),14)) create function TimeSpan(@Days int, @Hours int, @Minutes int, @Seconds int) -- returns a datetime the specified # of days/hours/minutes/seconds from the "base" date of 1/1/1900 (a "TimeSpan") returns datetime as begin return dbo.Time(@Hours,@Minutes,@Seconds) + @Days end create function TimeSpanUnits(@Unit char(1), @TimeSpan datetime) -- returns the # of units specified in the TimeSpan. -- The Unit parameter can be: "d" = days, "h" = hours, "m" = minutes, "s" = seconds returns int as begin return case @Unit when 'd' then datediff(day, 0, @TimeSpan) when 'h' then datediff(hour, 0, @TimeSpan) when 'm' then datediff(minute, 0, @TimeSpan) when 's' then datediff(second, 0, @TimeSpan) else Null end endHere, a TimeSpan is just a datetime offset from the "base" date of 1/1/1900. Creating one is the same as creating a Time using the Time() function, but we have added a parameter for Days to give more flexibility. The TimeSpanUnits() function works similar to standard T-SQL DatePart() function, but it returns the total # of units in the given time span. So, if you create a time span of 1 day and 2 hours, then TimeSpanUnits("d") will return 1 and TimeSpanUnits("h") will return 26. Negative values can be returned as well. You also may wish to implement the TimeSpanUnits() function as multiple functions, one per unit (e.g., TimeSpanHours(), TimeSpanDays(), etc) depending on your preference. Of course, a simple way to create a TimeSpan is to simply subtract two standard T-SQL DateTimes. Also please note that we can add and subtract Dates, Times, and TimeSpans all together using standard + and - operators and everything will work as expected. We can also add integers to our Dates and Times which will add entire days to the values. Here's a TimeSpan usage example:
declare @Deadline datetime -- remember, we still use standard datetimes for everything, include TimeSpans set @Deadline = dbo.TimeSpan(2,0,0,0) -- the deadline is two days declare @CreateDate datetime declare @ResponseDate datetime set @CreateDate = dbo.DateTime(2006,1,3,8,30,0) -- Jan 3, 2006, 8:30 AM set @ResponseDate = getdate() -- today -- See if the response date is past the deadline: select case when @ResponseDate > @CreateDate + @Deadline then 'overdue.' else 'on time.' end as Result -- Find out how many total hours it took to respond: declare @TimeToRepond datetime set @TimeToRespond = @ResponseDate - @CreateDate select dbo.TimeSpanUnits('h', @TimeToRespond) as ResponseTotalHours -- Return the response time as # of days, # of hours, # of minutes: select dbo.TimeSpanUnits('d',@TimeToRespond) as Days, DatePart(hour, @TimeToRespond) as Hours, DatePart(minute, @TimeToRespond) as Minutes -- Return two days and two hours from now: select getdate() + dbo.TimeSpan(2,2,0,0)
2 comments:
Hai, this is really very good collection of SQL DateTime Functions..
I don't know whether it's just me or if perhaps everyone else experiencing issues with your blog.
It looks like some of the text on your content are running off the screen. Can someone else
please provide feedback and let me know if
this is happening to them too? This could be a issue with my web
browser because I've had this happen before. Kudos
Post a Comment