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 12345»»»

Calculating Duration Using DATETIME Start and End Dates (SQL Spackle) Expand / Collapse
Author
Message
Posted Wednesday, January 15, 2014 9:43 PM


SSC-Dedicated

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

Group: General Forum Members
Last Login: Today @ 4:00 PM
Points: 35,967, Visits: 30,258
Comments posted to this topic are about the item Calculating Duration Using DATETIME Start and End Dates (SQL Spackle)


--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 #1531387
Posted Thursday, January 16, 2014 1:09 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Today @ 3:02 PM
Points: 230, Visits: 1,271
Thank you for the spackle Jeff but it looks like there is a small crack in it as it makes the assumption that the end time is always greater than the start time. This is the reason why I prefer to use double cast, first to varbinary and then to bigint.

SELECT 
StartDT
,EndDT
,Duration = STUFF(CONVERT(VARCHAR(20),EndDT-StartDT,114),1,2,DATEDIFF(hh,0,EndDT-StartDT))
,DurationI = STUFF(CONVERT(VARCHAR(20),StartDT-EndDT,114),1,2,DATEDIFF(hh,0,StartDT-EndDT))
,cast(cast(StartDT as varbinary(128)) as bigint) As StartTicks
,cast(cast(EndDT as varbinary(128)) as bigint) AS EndTicks
,cast(cast(StartDT as varbinary(128)) as bigint)-cast(cast(EndDT as varbinary(128)) as bigint) as XmY
,cast(cast(EndDT as varbinary(128)) as bigint)-cast(cast(StartDT as varbinary(128)) as bigint) as YmX
FROM #JBMTest;

Post #1531437
Posted Thursday, January 16, 2014 1:16 AM


SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Today @ 11:34 AM
Points: 404, Visits: 591
There is one more thing to notice about the first query.

You assign the value "2000-02-01 12:34:56.789" to @EndDT but the query returns "2000-01-02 12:34:56.789".

Either make sure you are using "SET DATEFORMAT YMD" or use an unambiguous date format for the string literal "2000-02-01T12:34:56.789".



Post #1531444
Posted Thursday, January 16, 2014 5:51 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, January 28, 2014 6:18 AM
Points: 1, Visits: 56
Here is my simple method to format the output to a more readable format:

CAST(GETDATE() - @StartDT AS TIME(2)) AS Duration

Post #1531520
Posted Thursday, January 16, 2014 6:14 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Monday, April 07, 2014 8:19 AM
Points: 48, Visits: 195
Do you have a good query for formatting duration (or age) in Years, Months, Days?

So often in my world, I am asked to find out who was the youngest or oldest to achieve something, or how long has it been since something has been achieved in a span of that range. I have a function that will do it, but I'd be interested to see how others have done it.

Of course I know that not all months have 30 days, so saying that someone is 16 years, 8 months, and 7 days old could be equivalent to 16 years, 8 months, and 10 days if months with 31 and 28 days are involved in the calculation. You also cannot just assume that a month is 30 days in your calculation since you could end up with 16 years, 12 months, and 4 days which would immediately look ridiculous and completely destroy your credibility. Number of days is the truest measure for comparison, but telling someone that the youngest was 6095 days old has no meaning to most people.

Anyone out there got a good method for YMD?
Post #1531526
Posted Thursday, January 16, 2014 6:28 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Yesterday @ 9:53 AM
Points: 312, Visits: 242
I'm guessing the @EndDT for the first code example should have been.

@EndDT  = '2000-01-02 12:34:56.789'

That gives the same answer as the example.
Post #1531531
Posted Thursday, January 16, 2014 7:40 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 7:35 AM
Points: 1,625, Visits: 2,034
Dennis Wagner-347763 (1/16/2014)
Do you have a good query for formatting duration (or age) in Years, Months, Days?

So often in my world, I am asked to find out who was the youngest or oldest to achieve something, or how long has it been since something has been achieved in a span of that range. I have a function that will do it, but I'd be interested to see how others have done it.

Of course I know that not all months have 30 days, so saying that someone is 16 years, 8 months, and 7 days old could be equivalent to 16 years, 8 months, and 10 days if months with 31 and 28 days are involved in the calculation. You also cannot just assume that a month is 30 days in your calculation since you could end up with 16 years, 12 months, and 4 days which would immediately look ridiculous and completely destroy your credibility. Number of days is the truest measure for comparison, but telling someone that the youngest was 6095 days old has no meaning to most people.

Anyone out there got a good method for YMD?


Which years in the calendar should we use to calculate this? The actual span between the two dates? Then comparisons between calculations made from different pairs of dates are not strictly compatible. The biggest reason is the occurrence of leap years within ranges. It might may a difference of only a day, but it sounds like for your applications, that may be important.

But, you could just do three DATEPART calculations and be done with it.


Please don't go. The drones need you. They look up to you.
Connect to me on LinkedIn
Post #1531574
Posted Thursday, January 16, 2014 7:42 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 7:35 AM
Points: 1,625, Visits: 2,034
Oliver Gugolz (1/16/2014)
Here is my simple method to format the output to a more readable format:

CAST(GETDATE() - @StartDT AS TIME(2)) AS Duration



But that only displays the fractional hours portion of the difference. You still lose the days converted to hours that Jeff's method preserves.


Please don't go. The drones need you. They look up to you.
Connect to me on LinkedIn
Post #1531577
Posted Thursday, January 16, 2014 7:46 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Tuesday, April 08, 2014 6:45 AM
Points: 17, Visits: 41
My specific use of the datetime field is to see if it occurs
within a user specified date range.
The examples I received with the stored procedures (from software application vendor)
had the user enter full date and time (2014-01-14 23:59.59)when I am not interested in the time aspect.

I changed to have the user just enter the date ('2014-01-14') which defaults to zero time.
If inclusive start date and end date are entered, with the default zero time, I would miss
the last date, so I compare
between @startdate and @enddate + 1
which does include the entire enddate.

Post #1531581
Posted Thursday, January 16, 2014 7:46 AM


SSC-Dedicated

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

Group: General Forum Members
Last Login: Today @ 4:00 PM
Points: 35,967, Visits: 30,258
Thanks for the feedback folks. I'm on my way to work and will look into your replies when I get home.

--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 #1531582
« Prev Topic | Next Topic »

Add to briefcase 12345»»»

Permissions Expand / Collapse