datetime difference and display in years

  • i want to get date difference like a start date and end date and find difference in years but i want like if for example one date is 2007 and end date is 1 jan 2010 then the difference is of 3 years and one day so sql is showing 3 year .. but i want it to show 4 years. i.e even one day is extra should add that also.

  • scottichrosaviakosmos (6/29/2010)


    i want to get date difference like a start date and end date and find difference in years but i want like if for example one date is 2007 and end date is 1 jan 2010 then the difference is of 3 years and one day so sql is showing 3 year .. but i want it to show 4 years. i.e even one day is extra should add that also.

    The year count increments with year boundaries;

    SELECT DATEDIFF(dd, '31-12-2009', '01-01-2010') -- 1 day

    SELECT DATEDIFF(yy, '31-12-2009', '01-01-2010') -- 1 year

    It might be more useful for you to count months instead:

    set dateformat dmy

    SELECT DATEDIFF(mm, '31-12-2006', '31-12-2009') -- 36

    SELECT DATEDIFF(mm, '31-12-2006', '01-01-2010') -- 37

    SELECT DATEDIFF(mm, '01-01-2009', '31-12-2009') -- 11

    SELECT DATEDIFF(mm, '01-11-2009', '31-01-2010') -- 2

    โ€œWrite the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.โ€ - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • Add 1 to the DATEDIFF() unless the dates are equivalent.

    SELECT DATEDIFF(YEAR, date1, date2) + CASE WHEN CONVERT(CHAR(5), date1, 1) = CONVERT(CHAR(5), date2, 1) THEN 0 ELSE 1 END

    You have to decide if/how you want to handle Feb 28 vs Feb 29.

    For example:

    + CASE WHEN CONVERT(CHAR(5), DATEADD(DAY, 1, date1), 1) = CONVERT(CHAR(5), DATEADD(DAY, 1, date2), 1) THEN 0 ELSE 1 END

    would consider Feb 28 and Feb 29 as the "same day" for your calculation purposes.

    Scott Pletcher, SQL Server MVP 2008-2010

  • scott.pletcher

    CREATE TABLE #T(Id INT,Date1 DATETIME,Date2 DATETIME)

    INSERT INTO #T

    SELECT 1,'2/1/2007','1/31/2010' UNION ALL

    SELECT 2,'2/1/2007','2/1/2010' UNION ALL

    SELECT 3, '2/1/2007','1/15/2010'

    SELECT Id, Date1 AS 'Start', Date2 AS 'End', DATEDIFF(YEAR, date1, date2)

    + CASE WHEN CONVERT(CHAR(5), date1, 1) = CONVERT(CHAR(5), date2, 1)

    THEN 0 ELSE 1 END Years

    FROM #T

    Yields:

    IdStart End Years

    12007-02-01 00:00:00.0002010-01-31 00:00:00.0004

    22007-02-01 00:00:00.0002010-02-01 00:00:00.0003

    32007-02-01 00:00:00.0002010-01-15 00:00:00.0004

    I think what you meant to write:

    SELECT Id, Date1 AS 'Start', Date2 AS 'End', DATEDIFF(YEAR, date1, date2)

    + CASE WHEN CONVERT(CHAR(5), date1, 1) = CONVERT(CHAR(5), date2, 1)

    THEN 1 ELSE 0 END Years

    FROM #T

    IdStart End Years

    12007-02-01 00:00:00.0002010-01-31 00:00:00.0003

    22007-02-01 00:00:00.0002010-02-01 00:00:00.0004

    32007-02-01 00:00:00.0002010-01-15 00:00:00.0003

    If everything seems to be going well, you have obviously overlooked something.

    Ron

    Please help us, help you -before posting a question please read[/url]
    Before posting a performance problem please read[/url]

  • Actually, no, if the result was an exact number of years, I kinda' figured he wouldn't add one to that. But that was just my own best guess, of course ๐Ÿ™‚

    Scott Pletcher, SQL Server MVP 2008-2010

  • Or is it more like this:

    CREATE TABLE #T(Id INT,date1 DATETIME,date2 DATETIME)

    INSERT INTO #T

    SELECT 1,'2/1/2007','1/31/2010' UNION ALL

    SELECT 2,'2/1/2007','2/1/2010' UNION ALL

    SELECT 3, '2/1/2007','1/15/2010' UNION ALL

    SELECT 4, '2/1/2007','2/2/2010'

    SELECT

    Id,

    date1 AS 'Start',

    date2 AS 'End',

    DATEDIFF(YEAR, date1, date2) + CASE WHEN DATEADD(yy, -1 * DATEDIFF(YEAR, date1, date2), date2) > date1

    THEN 1 ELSE 0

    END Years

    FROM #T

    DROP TABLE #T

  • I forget who I got this one from but I've never found anything simpler for correctly calculating age in years. Using Lynn's good test harness...

    CREATE TABLE #T(Id INT,date1 DATETIME,date2 DATETIME)

    INSERT INTO #T

    SELECT 1,'2/1/2007','1/31/2010' UNION ALL

    SELECT 2,'2/1/2007','2/1/2010' UNION ALL

    SELECT 3, '2/1/2007','1/15/2010' UNION ALL

    SELECT 4, '2/1/2007','2/2/2010'

    SELECT

    Id,

    date1 AS 'Start',

    date2 AS 'End',

    YEAR(date2 - DATEPART(dy, date1) + 1) - YEAR(date1)

    FROM #T

    DROP TABLE #T

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • What would really help is for the OP to come back and tell us what is really needed or if any of the code snippets provided actually solve the problem.

  • Agreed.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 9 posts - 1 through 8 (of 8 total)

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