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


Time Difference Help


Time Difference Help

Author
Message
Steve-0
Steve-0
SSC-Enthusiastic
SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)

Group: General Forum Members
Points: 132 Visits: 92
Hey everyone,

I'm looking to see how long it took someone to complete a task, but I'm unable to figure out how to basically get a 'hours:minutes' difference between the 2 datetime fields.

OPENDATE-ASSNDATE

I'd like the layout to be something like 00:00. I tried using datediff but I"m having trouble with it. I see many examples where the value is static but nothing with a field value. I'm inexperienced with SQL scripts. Any help would be greatly appreciated.

Thanks in advance for your help.

Steve
Sean Lange
Sean Lange
SSC Guru
SSC Guru (65K reputation)SSC Guru (65K reputation)SSC Guru (65K reputation)SSC Guru (65K reputation)SSC Guru (65K reputation)SSC Guru (65K reputation)SSC Guru (65K reputation)SSC Guru (65K reputation)

Group: General Forum Members
Points: 65158 Visits: 17979
This can get a little bit tricky when the dates span multiple days. If they are within the same day you can use something like this. It will actually work for dates spanning multiple days, it will just increment the hours to more than 24.


declare @StartDate datetime = '05-02-2014 01:00:00'
declare @EndDate datetime = '05-02-2014 19:12:33'

select right('00' + cast(DATEDIFF(HOUR, @StartDate, @EndDate) as varchar), 2) + ':' +
right('00' + CAST(DATEDIFF(MINUTE, @StartDate, @EndDate) as varchar) % 60, 2) + ':' +
right('00' + cast(DATEDIFF(SECOND, @StartDate, @EndDate) % 60 as varchar), 2) as [HH:MM:SS]



_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Scott Coleman
Scott Coleman
SSCertifiable
SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)

Group: General Forum Members
Points: 7496 Visits: 1534
DECLARE @t1 DATETIME = '2014-05-02 10:30:43';
DECLARE @t2 DATETIME = '2014-05-02 14:25:13';

-- Show the time difference in HH:MM:SS (assumes timespan < 24 hours)
PRINT CONVERT(CHAR(8), @t2 - @t1, 8)
-- Shrink to HH:MM - value is truncated, not rounded to nearest minute
PRINT CONVERT(CHAR(5), @t2 - @t1, 8)
-- Round the minutes by adding 30 seconds
PRINT CONVERT(CHAR(5), DATEADD(SECOND, 30, @t2 - @t1), 8)
-- Casting the timespan to TIME allows using CAST(time AS CHAR) instead of CONVERT(CHAR, datetime, 8)
PRINT CAST(CAST(DATEADD(SECOND, 30, @t2 - @t1) AS TIME) AS CHAR(5))

-- Handle timespans over 24 hours as HHH:MM ( up to about 68 years )
-- Using DATEDIFF(MINUTE, @t1, @t2) will also run into rounding issues, so use seconds and add 30
DECLARE @mins INT = (DATEDIFF(SECOND, @t1, @t2) + 30) / 60;
PRINT CASE WHEN @mins < 600 THEN '0' ELSE '' END + LTRIM(@mins / 60) + ':' + LTRIM(@mins % 60)





ScottPletcher
ScottPletcher
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20438 Visits: 7428


SELECT
OPENDATE, ASSNDATE,
CAST(minutes_diff / 60 AS varchar(3)) + ':' +
RIGHT('0' + CAST(minutes_diff % 60 AS varchar(2)), 2) AS Date_Diff
FROM (
SELECT GETDATE() AS OPENDATE, DATEADD(MINUTE, -9, GETDATE()) AS ASSNDATE UNION ALL -- lt 60 mins
SELECT GETDATE(), DATEADD(MINUTE, -196, GETDATE()) UNION ALL -- gt 60 mins, lt 24 hrs
SELECT GETDATE(), DATEADD(MINUTE, -(24*60+112), GETDATE()) -- gt 24 hrs
) AS test_data
CROSS APPLY (
SELECT DATEDIFF(MINUTE, ASSNDATE, OPENDATE) AS minutes_diff
) AS assign_alias_names_to_calculated_values_1




SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
Steve-0
Steve-0
SSC-Enthusiastic
SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)

Group: General Forum Members
Points: 132 Visits: 92
Hi Everyone thanks for the replies.

For the first 2, I'm not using static dates as per your queries.

Scott, your query is just casting values for actual field values. OPENDATE and ASSGNDATE are actual fields in a task table. When I run that query I get 3 returned records based solely on the SELECT GETDATE.

The output is based on the current time:

ASSNDATE OPENDATE Date_Diff
2014-05-05 09:29:30.833 2014-05-05 09:38:30.833 0:09
2014-05-05 06:22:30.833 2014-05-05 09:38:30.833 3:16
2014-05-04 07:46:30.833 2014-05-05 09:38:30.833 25:52

I need to do this on every record in the table (minus anything that's not being worked on). Suggestions?
ScottPletcher
ScottPletcher
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20438 Visits: 7428
Steve-0 (5/5/2014)
Hi Everyone thanks for the replies.

For the first 2, I'm not using static dates as per your queries.

Scott, your query is just casting values for actual field values. OPENDATE and ASSGNDATE are actual fields in a task table. When I run that query I get 3 returned records based solely on the SELECT GETDATE.

The output is based on the current time:

ASSNDATE OPENDATE Date_Diff
2014-05-05 09:29:30.833 2014-05-05 09:38:30.833 0:09
2014-05-05 06:22:30.833 2014-05-05 09:38:30.833 3:16
2014-05-04 07:46:30.833 2014-05-05 09:38:30.833 25:52

I need to do this on every record in the table (minus anything that's not being worked on). Suggestions?



That was just to provide sample data. Naturally you should replace:


FROM (
SELECT GETDATE() AS OPENDATE, DATEADD(MINUTE, -9, GETDATE()) AS ASSNDATE UNION ALL -- lt 60 mins
SELECT GETDATE(), DATEADD(MINUTE, -196, GETDATE()) UNION ALL -- gt 60 mins, lt 24 hrs
SELECT GETDATE(), DATEADD(MINUTE, -(24*60+112), GETDATE()) -- gt 24 hrs
) AS test_data



with your own table name, like
FROM dbo.your_table_name

SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)

Group: General Forum Members
Points: 222940 Visits: 42003
The static dates are just examples. Substitute the correct column names.

Shifting gears, to get the duration between two DATETIME datatypes, just subtract the smaller of the two from the larger of the two and format the result the way you want with CONVERT (good enough for durations < 24 hours) and other tricks (necessary if you have durations >= 24 hours.

--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
Steve-0
Steve-0
SSC-Enthusiastic
SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)SSC-Enthusiastic (132 reputation)

Group: General Forum Members
Points: 132 Visits: 92
Where do I input the table reference (TASKS) as the FROM is a SELECT statement?

Thanks again everyone for helping me in my nubness. People like you guys make support forums

completely relevant!

Steve
ScottPletcher
ScottPletcher
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20438 Visits: 7428


SELECT TOP (1000) --remove after testing!
t.OPENDATE, t.ASSNDATE,
CAST(minutes_diff / 60 AS varchar(3)) + ':' +
RIGHT('0' + CAST(minutes_diff % 60 AS varchar(2)), 2) AS Date_Diff
FROM dbo.Tasks t
CROSS APPLY (
SELECT DATEDIFF(MINUTE, t.ASSNDATE, t.OPENDATE) AS minutes_diff
) AS assign_alias_names_to_calculated_values_1




SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
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