Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

datetime difference and display in years Expand / Collapse
Author
Message
Posted Tuesday, June 29, 2010 7:04 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Thursday, April 17, 2014 8:53 AM
Points: 102, Visits: 450
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.
Post #944608
Posted Tuesday, June 29, 2010 7:31 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Thursday, April 17, 2014 9:33 AM
Points: 6,754, Visits: 12,854
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
Post #944634
Posted Tuesday, June 29, 2010 3:41 PM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Friday, December 31, 2010 9:46 AM
Points: 274, 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
Post #945081
Posted Tuesday, June 29, 2010 5:12 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 10:17 AM
Points: 5,472, Visits: 23,533
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
Post #945111
Posted Tuesday, June 29, 2010 5:57 PM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Friday, December 31, 2010 9:46 AM
Points: 274, 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
Post #945125
Posted Tuesday, June 29, 2010 10:03 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 10:24 AM
Points: 22,507, Visits: 30,225
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




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)
Post #945183
Posted Wednesday, June 30, 2010 5:05 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 4:00 PM
Points: 35,967, Visits: 30,258
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." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #945856
Posted Wednesday, June 30, 2010 5:32 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 10:24 AM
Points: 22,507, Visits: 30,225
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.



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)
Post #945866
Posted Thursday, July 01, 2010 6:13 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 4:00 PM
Points: 35,967, Visits: 30,258
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." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #946115
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse