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


Is there an accurate script for datediff format in years:months:days?


Is there an accurate script for datediff format in years:months:days?

Author
Message
memymasta
memymasta
SSC Veteran
SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)

Group: General Forum Members
Points: 243 Visits: 402
I've tryed several tsql scripts and none of them have proven to be accurate.

If you got a neat script up your sleeve, i'd appreciate.

Someting like this http://www.sqlservercentral.com/scripts/Age/75784/
(which doesnt work for ('2011-01-16', '2013-01-01') )


/*----------------------------------------------------------------------------------------------------------------------------
Author :- ANAND BABU UCHAGAWKAR
Purpose :- To find the datediff/age in text format (eg. 1 year(s), 10 month(s), 10 day(s)).
DATE :- 30-Aug-2011
DATABASE :- SQL

----------------------------------------------------------------------------------------------------------------------------*/
IF (Select COUNT(*) From Sysobjects Where [name] like 'FN_GETDATEDIFFTEXT') > 0
BEGIN
DROP FUNCTION FN_GETDATEDIFFTEXT
END
GO
CREATE FUNCTION FN_GETDATEDIFFTEXT(@FromDate DateTime, @ToDate DateTime)
RETURNS NVARCHAR(50)
AS
BEGIN

Declare @daysDiff Int
Declare @monthDiff Int
Declare @yearDiff Int

--Select @daysDiff = DATEDIFF(DAY, @FromDate, @ToDate)
Set @monthDiff = ABS(DATEDIFF(MONTH, @FromDate, @ToDate)%12)
Set @yearDiff = ABS(DATEDIFF(YYYY, @FromDate, @ToDate))

-- If the From date month is greater than the month of the To date and the year difference is greater than zero
-- then the year should the deducted by one
IF DATEPART(MONTH,@FromDate) > DATEPART(MONTH,@ToDate) AND @yearDiff > 0
BEGIN
Set @yearDiff = @yearDiff - 1
END

IF DATEPART(DAY,@FromDate) > DATEPART(DAY, @ToDate)
Begin
--Get last date of the month of the FromDate
Declare @lastDateOfMonth DateTime = DATEADD(MONTH, 1, @FromDate)
Set @lastDateOfMonth = '01-' + DATENAME(MONTH,@lastDateOfMonth) + '-'+DATENAME(YEAR,@lastDateOfMonth)
Set @lastDateOfMonth = DATEADD(DAY, -1, @lastDateOfMonth)

Set @daysDiff = DATEDIFF(DAY, @FromDate, @lastDateOfMonth)
Set @daysDiff = @daysDiff + DATEPART(DAY, @ToDate)
Set @monthDiff = @monthDiff - 1
End
ELSE
BEGIN
Set @daysDiff = DATEPART(DAY, @ToDate) - DATEPART(DAY, @FromDate)
END

-- Select @yearDiff Yr, @monthDiff Mn, @daysDiff Dy
RETURN
CAST(@yearDiff as nvarchar) + ' year(s), ' +
CAST(@monthDiff as nvarchar) + ' month(s), ' +
CAST(@daysDiff as nvarchar) + ' day(s)'
END
GO

Select DBO.FN_GETDATEDIFFTEXT('2011-01-16', '2013-01-01')
-- Select DBO.FN_GETDATEDIFFTEXT('01-Jan-1990', Getdate())



The Dixie Flatline
The Dixie Flatline
SSCertifiable
SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)

Group: General Forum Members
Points: 6994 Visits: 6900
Just threw this together from scratch. Test it out and see if you can break it.
@date1 should always be prior to or the same as @date2

declare @date1 date = '2012-01-15'
declare @date2 date = '2013-01-16'
declare @years int
declare @months int
declare @days int

select @years = DATEDIFF(YEAR,@date1,@date2) - case when datepart(day,@date1) > datepart(day,@date2) then 1 else 0 end
select @months = DATEdiff(month,@date1,@date2) % 12 - case when datepart(day,@date1) > datepart(day,@date2) then 1 else 0 end
select @months = case when @months >= 0 then @months else 12 + @months end
select @days = DATEPART(dy,@date2) - DATEPART(dy,@date1)
select @days = case when @days >=0 then @days else DATEDIFF(DAY,DATEADD(month,-1,@date2),@date2)+@days end

select @years as [@years], @months as [@months], @days as [@days]

__________________________________________________

Against stupidity the gods themselves contend in vain. -- Friedrich Schiller
Stop, children, what's that sound? Everybody look what's going down. -- Stephen Stills
Lowell
Lowell
SSC-Dedicated
SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)

Group: General Forum Members
Points: 35738 Visits: 40228
i have tehse saved in my snippets; does this do what you want?

--elapsed time/datediff

select
[Days] = datediff(day,0,ET-ST)-1,
[Hours] = datepart(Hour,ET-ST)-1,
[Minutes] = datepart(Minute,ET-ST)-1,
[Seconds] = datepart(Second,ET-ST),
[Milliseconds] = datepart(millisecond,ET-ST)
from
(
select -- Test Data
ST = convert(datetime,'2008/09/22 00:35:33.997'),
ET = convert(datetime,'2009/10/22 04:05:45.443')
) a

select [Years] = datediff(year,0,ET-ST)-1,
[Months] = datepart(month,ET-ST)-1,
[Days] = datepart(day,ET-ST)-1,
[Hours] = datepart(Hour,ET-ST),
[Minutes] = datepart(Minute,ET-ST),
[Seconds] = datepart(Second,ET-ST),
[Milliseconds] = datepart(millisecond,ET-ST)
from
(
select -- Test Data
ST = convert(datetime,'2008/09/22 00:35:33.997'),
ET = convert(datetime,'2009/10/23 04:05:45.443')
) a



Lowell

--
help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

memymasta
memymasta
SSC Veteran
SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)

Group: General Forum Members
Points: 243 Visits: 402
select  [Years]        = datediff(year,0,ET-ST)-1,
[Months] = datepart(month,ET-ST)-1,
[Days] = datepart(day,ET-ST)-1
from
(
select -- Test Data
ST = convert(datetime,'2011/01/01'),
ET = convert(datetime,'2013/01/13')
) a



Gives 1 year, 0 months and 13 days.
memymasta
memymasta
SSC Veteran
SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)

Group: General Forum Members
Points: 243 Visits: 402
declare @date1 date = '2010-05-17'
declare @date2 date = '2013-01-16'
declare @years int
declare @months int
declare @days int

select @years = DATEDIFF(YEAR,@date1,@date2) - case when datepart(day,@date1) > datepart(day,@date2) then 1 else 0 end
select @months = DATEdiff(month,@date1,@date2) % 12 - case when datepart(day,@date1) > datepart(day,@date2) then 1 else 0 end
select @months = case when @months >= 0 then @months else 12 + @months end
select @days = DATEPART(dy,@date2) - DATEPART(dy,@date1)
select @days = case when @days >=0 then @days else DATEDIFF(DAY,DATEADD(month,-1,@date2),@date2)+@days end

select @years as [@years], @months as [@months], @days as [@days]



Gives 2 years, 7 months, -90 days
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)

Group: General Forum Members
Points: 114300 Visits: 41367
Ummm.... how long is a month for this particular problem?

--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
memymasta
memymasta
SSC Veteran
SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)

Group: General Forum Members
Points: 243 Visits: 402
If there's no way for dynamical months, then 30 days/month.
drew.allen
drew.allen
SSCrazy Eights
SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)

Group: General Forum Members
Points: 8311 Visits: 11008
I think this will give you what you are looking for. It depends on the fact that the variables are set in left to right order. You can separate them out to single SET or SELECT statements if you're not comfortable with that.


DECLARE @FromDate DateTime, @ToDate DateTime
SELECT @FromDate = '2011-01-16', @ToDate = '2013-01-01'

DECLARE @RefDate datetime
, @dayDiff Int
, @monthDiff Int
, @yearDiff Int


IF @FromDate > @ToDate
SELECT @RefDate = @FromDate, @FromDate = @ToDate, @ToDate = @RefDate

SELECT @RefDate = DateAdd(Year, DateDiff(Year, @FromDate, @ToDate), @FromDate)
, @RefDate = CASE WHEN @RefDate > @ToDate THEN DateAdd(Year, -1, @RefDate) ELSE @RefDate END
, @yearDiff = DateDiff(Year, @FromDate, @RefDate)
, @FromDate = @RefDate
, @RefDate = DateAdd(Month, DateDiff(Month, @FromDate, @ToDate), @FromDate)
, @RefDate = CASE WHEN @RefDate > @ToDate THEN DateAdd(Month, -1, @RefDate) ELSE @RefDate END
, @monthDiff = DateDiff(Month, @FromDate, @RefDate)
, @FromDate = @RefDate
, @RefDate = DateAdd(Day, DateDiff(Day, @FromDate, @ToDate), @FromDate)
, @RefDate = CASE WHEN @RefDate > @ToDate THEN DateAdd(Day, -1, @RefDate) ELSE @RefDate END
, @dayDiff = DateDiff(Day, @FromDate, @RefDate)

SELECT @yearDiff, @monthDiff, @dayDiff



Drew

J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
How to post data/code on a forum to get the best help.
How to Post Performance Problems
Make sure that you include code in the appropriate IFCode tags, e.g. [code=sql]<your code here>[/code]. You can find the IFCode tags under the INSERT options when you are writing a post.
drew.allen
drew.allen
SSCrazy Eights
SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)

Group: General Forum Members
Points: 8311 Visits: 11008
Lowell (1/17/2012)
i have tehse saved in my snippets; does this do what you want?

--elapsed time/datediff

select [Years] = datediff(year,0,ET-ST)-1,
[Months] = datepart(month,ET-ST)-1,
[Days] = datepart(day,ET-ST)-1,
[Hours] = datepart(Hour,ET-ST),
[Minutes] = datepart(Minute,ET-ST),
[Seconds] = datepart(Second,ET-ST),
[Milliseconds] = datepart(millisecond,ET-ST)
from
(
select -- Test Data
ST = convert(datetime,'2008/09/22 00:35:33.997'),
ET = convert(datetime,'2009/10/23 04:05:45.443')
) a



This doesn't work as expected, because it doesn't appropriately account for leap years. For example, the range 2011-01-01 to 2012-12-31 contains a leap year (2012). Using ET-ST essentially converts the range to 1900-01-01 to 1902-01-01 which does NOT contain a leap year (1900 though divisible by 4 is not a leap year, because it is not divisible by 400) and subsequently gives the wrong values for year, month, and day.

Drew

J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
How to post data/code on a forum to get the best help.
How to Post Performance Problems
Make sure that you include code in the appropriate IFCode tags, e.g. [code=sql]<your code here>[/code]. You can find the IFCode tags under the INSERT options when you are writing a post.
Lowell
Lowell
SSC-Dedicated
SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)

Group: General Forum Members
Points: 35738 Visits: 40228
thanks drew;
it's actually inaccurate in a lot of other situations too, depending on the range between the two dates; that date -1 stuff works just for the date supplied in the example; start putting in other dates and it blows up.

your version is much more elegant, and I added it to my snippets.
Thanks!

Lowell

--
help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

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