SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


datetime difference and display in years


datetime difference and display in years

Author
Message
scottichrosaviakosmos
scottichrosaviakosmos
SSC-Enthusiastic
SSC-Enthusiastic (142 reputation)SSC-Enthusiastic (142 reputation)SSC-Enthusiastic (142 reputation)SSC-Enthusiastic (142 reputation)SSC-Enthusiastic (142 reputation)SSC-Enthusiastic (142 reputation)SSC-Enthusiastic (142 reputation)SSC-Enthusiastic (142 reputation)

Group: General Forum Members
Points: 142 Visits: 678
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.
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16145 Visits: 19538
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
Exploring Recursive CTEs by Example Dwain Camps
scott.pletcher
scott.pletcher
SSC-Addicted
SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)

Group: General Forum Members
Points: 460 Visits: 473
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
bitbucket-25253
bitbucket-25253
SSCertifiable
SSCertifiable (7.8K reputation)SSCertifiable (7.8K reputation)SSCertifiable (7.8K reputation)SSCertifiable (7.8K reputation)SSCertifiable (7.8K reputation)SSCertifiable (7.8K reputation)SSCertifiable (7.8K reputation)SSCertifiable (7.8K reputation)

Group: General Forum Members
Points: 7795 Visits: 25280
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:
Id   Start                      End                 Years
1 2007-02-01 00:00:00.000 2010-01-31 00:00:00.000 4
2 2007-02-01 00:00:00.000 2010-02-01 00:00:00.000 3
3 2007-02-01 00:00:00.000 2010-01-15 00:00:00.000 4



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



Id   Start                      End                 Years
1 2007-02-01 00:00:00.000 2010-01-31 00:00:00.000 3
2 2007-02-01 00:00:00.000 2010-02-01 00:00:00.000 4
3 2007-02-01 00:00:00.000 2010-01-15 00:00:00.000 3



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

Ron

Please help us, help you -before posting a question please read

Before posting a performance problem please read
scott.pletcher
scott.pletcher
SSC-Addicted
SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)SSC-Addicted (460 reputation)

Group: General Forum Members
Points: 460 Visits: 473
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
Lynn Pettis
Lynn Pettis
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39129 Visits: 38518
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



Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)

Group: General Forum Members
Points: 85426 Visits: 41078
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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Lynn Pettis
Lynn Pettis
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39129 Visits: 38518
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.

Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)

Group: General Forum Members
Points: 85426 Visits: 41078
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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search