T-SQL DATEDIFF problem

  • Hi Guys can you please help me on this.

    If I use like:

    PRINT DATEDIFF(month,'2010-06-07 00:00:00.000','2010-07-01 00:00:00.000')

    then it gives me a result 1, which is not correct becase the date range does not exactly complete a month till 2010-07-07.

    Can this effect be achieved with T-SQL.....?

    Any help is greatly appreciated.......

  • Interesting... For as often as I used datediff, I'm surprised I haven't run into this. Your results did surprise me. It appears the key phrase in BOL is:

    Is the part of startdate and enddate that specifies the type of boundary crossed. The following table lists all valid datepart arguments. User-defined variable equivalents are not valid.

    The URL is http://msdn.microsoft.com/en-us/library/ms189794.aspx

    I ran these two queries with different results. The first query returned a 1 as the month crossed the boundary. The second did not and returned zero.

    select DATEDIFF(mm,'2010-06-30','2010-07-03')

    go

    select DATEDIFF(mm,'2010-07-01','2010-07-03')

    go

    You may want to use "dd" instead, then see if the result is greater than xx days, but that's tricky since the various months have different number of days in them. Sorry I couldn't be more help.

    Cindy

  • DateDiff, as already mentioned, only counts date boundaries crossed.

    You'll get 1 if you query the datediff(year) for 1 second before midnight, on 31 Dec, and midnight, 1 Jan, because the year will be different by one. And so on for months, days, weeks, et al.

    There are a couple of ways to have T-SQL determine if a full month has passed or not.

    You can use variations on this:

    DECLARE @StartDate DATETIME, @EndDate DATETIME;

    SELECT @StartDate = '11/1/10', @EndDate = '12/7/10';

    SELECT

    CASE

    WHEN DATEDIFF(MONTH, @StartDate, @EndDate) >= 1 AND DATEPART(DAY, @EndDate) >= DATEPART(DAY, @StartDate) THEN DATEDIFF(MONTH, @StartDate, @EndDate)

    WHEN DATEDIFF(MONTH, @StartDate, @EndDate) >=1 AND DATEPART(DAY, @EndDate) < DATEPART(DAY, @StartDate) THEN DATEDIFF(MONTH, @StartDate, @EndDate) - 1

    END;

    If you have a Calendar table (a table with a list of dates and pre-calculated parts for them), you can write a version of this that will perform much better, since it won't have to do as many complex calculations on-the-fly.

    Note that this version won't work if the End Date is earlier than the Start Date. For that, you'd need to add more conditions to the Case statement.

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

  • THANKS A BUNCH GUYS..........

    AND SSCrazy Your one works fine for me..........

    THANKS AGAIN

    🙂

  • You're welcome.

    (By the way, "SSCrazy Eights" is a title based on the number of posts I have. The screen-name is above that, in bold. Same as yours.)

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

Viewing 5 posts - 1 through 4 (of 4 total)

You must be logged in to reply to this topic. Login to reply