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

datediff producing erroneous result when datetime is between midnight and 1AM Expand / Collapse
Author
Message
Posted Tuesday, October 15, 2013 11:34 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Wednesday, September 10, 2014 4:45 PM
Points: 308, Visits: 839
Needed a way to find datediff which renders result as follows:
-- HH:MI:SS:MMM(24H) format .
ie. 17:59:30:000 <---I WANT THIS FORMAT
instead of 17.9917 (which has to be read 17 hours and 99/60 minutes).

found this link and a SOLUTION:
http://www.mindfiresolutions.com/Get-Time-Difference-in-Hours-Minutes-Seconds-and-milliseconds-in-SQL-Server-2276.php

CONVERT(VARCHAR(12), DATEADD(MS,DATEDIFF(ms, ActualStartTime, EndTime), 0), 114) AS ELAPSED


WORKS WELL EXCEPT when start time is just after midnight

--CORRECT
CONVERT(VARCHAR(12), DATEADD(MS,DATEDIFF(ms,'2013-09-13 17:49:36.000', '2013-09-14 12:40:47.000'), 0), 114) AS ELAPSED

renders 18:51:11:000<----CORRECT

--INCORRECT
CONVERT(VARCHAR(12), DATEADD(MS,DATEDIFF(ms,'2013-09-30 00:22:05.000', '2013-10-01 02:04:51.000'), 0), 114) AS ELAPSED

This renders 01:42:46:000 <----INCORRECT (should be 25:42:46) AS IN 25 hours, 42 minutes, 46 seconds.

How to handle for start times that are between midnight and 01:00?



Post #1504879
Posted Tuesday, October 15, 2013 11:39 AM
Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Today @ 9:58 AM
Points: 590, Visits: 6,881
Hrm... I might be missing something here, but why is the second case incorrect? September this year had 30 days, so the difference between 22 after midnight and 4 after 2 in the morning the next day should indeed be about 1:42, as October 1st is the next day after September 30th. Am I not seeing something here?



-
Post #1504881
Posted Tuesday, October 15, 2013 12:24 PM
SSChasing Mays

SSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing Mays

Group: General Forum Members
Last Login: Yesterday @ 9:09 AM
Points: 637, Visits: 2,142
The convert you are using is only showing the hours, minutes and seconds, and the answer you want is 1 day, 1 hour, 42 minutes, and 46 seconds

You can try something like

select convert(varchar,DATEDIFF(mi,'2013-09-30 00:22:05.000', '2013-10-01 02:04:51.000')/60) + right(CONVERT(VARCHAR(12), DATEADD(MS,DATEDIFF(ms,'2013-09-30 00:22:05.000', '2013-10-01 02:04:51.000'), 0), 114),10)

to get hours over 24 in the hours count.

You can also break it down yourself and avoid using date/string manipulation by using division and remainders, and converting the answers into strings
Post #1504905
Posted Tuesday, October 15, 2013 12:43 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 6:38 PM
Points: 1,796, Visits: 5,804
You could use a function to return the three values Hours, Minutes, Seconds for the time difference.

How you then display them is a simple matter of formatting in the front end


create function TimeDifference(@Date1 datetime,@Date2 datetime)
returns table
with schemabinding
as
return
select
datediff(hour,@Date1,@Date2) as [hours]
, datediff(minute,@Date1,@Date2)%60 as [minutes]
, datediff(second,@Date1,@Date2)%60 as [seconds]




MM


  • MMGrid Addin
  • MMNose Addin


  • Forum Etiquette: How to post Reporting Services problems
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • How to Post Performance Problems - by Gail Shaw

  • Post #1504913
    Posted Tuesday, October 15, 2013 3:38 PM
    SSCrazy

    SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

    Group: General Forum Members
    Last Login: Yesterday @ 1:40 PM
    Points: 2,214, Visits: 3,335
    You'll need to format the hours separately, as below, since style "114" will only handle up to 23 hours:


    SELECT
    CAST(DATEDIFF(ms, ActualStartTime, EndTime) / 3600000 AS varchar(3)) +
    RIGHT(CONVERT(VARCHAR(12), DATEADD(MS,DATEDIFF(ms, ActualStartTime, EndTime), 0), 114), 10) AS ELAPSED

    FROM (
    select cast('2013-09-13 17:49:36.000' as datetime) AS ActualStartTime,
    cast('2013-09-14 12:40:47.000' as datetime) AS EndTime
    union all
    select '2013-09-30 00:22:05.000', '2013-10-01 02:04:51.000'
    ) AS test_data




    SQL DBA,SQL Server MVP('07, '08, '09)

    Carl Sagan said: "There is no such thing as a dumb question." Sagan obviously never watched a congressional hearing!
    Post #1505006
    Posted Tuesday, October 15, 2013 6:16 PM


    Hall of Fame

    Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

    Group: General Forum Members
    Last Login: Tuesday, October 7, 2014 10:53 PM
    Points: 3,421, Visits: 5,359
    Similar to Scott's last:

    SELECT CAST(DATEDIFF(ms,StartDT, EndDT)/3600000 AS VARCHAR) + ':' +
    RIGHT(CAST(CAST(DATEADD(ms, DATEDIFF(ms,StartDT, EndDT)%86400000, 0) AS TIME) AS VARCHAR(12)), 9)
    FROM
    (
    SELECT StartDT='2013-09-30 00:22:05.000', EndDT='2013-10-01 02:04:51.000'
    ) a;





    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
    Since random numbers are too important to be left to chance, let's generate some!
    Learn to understand recursive CTEs by example.
    Splitting strings based on patterns can be fast!
    Post #1505032
    Posted Tuesday, October 15, 2013 7:10 PM


    SSC-Dedicated

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

    Group: General Forum Members
    Last Login: Yesterday @ 8:02 PM
    Points: 35,397, Visits: 31,955
    Nevyn (10/15/2013)
    The convert you are using is only showing the hours, minutes and seconds, and the answer you want is 1 day, 1 hour, 42 minutes, and 46 seconds

    You can try something like

    select convert(varchar,DATEDIFF(mi,'2013-09-30 00:22:05.000', '2013-10-01 02:04:51.000')/60) + right(CONVERT(VARCHAR(12), DATEADD(MS,DATEDIFF(ms,'2013-09-30 00:22:05.000', '2013-10-01 02:04:51.000'), 0), 114),10)

    to get hours over 24 in the hours count.

    You can also break it down yourself and avoid using date/string manipulation by using division and remainders, and converting the answers into strings


    Look again, please. There is absolutely no way that there are more than 25 hours between 10:05PM one day and 02:04AM the very next day.

    My apologies... I really misread that one! That's 00:22:05 and not 22:05 like I read it.


    --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."

    (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 #1505042
    Posted Tuesday, October 15, 2013 7:15 PM


    Hall of Fame

    Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

    Group: General Forum Members
    Last Login: Tuesday, October 7, 2014 10:53 PM
    Points: 3,421, Visits: 5,359
    2013-09-30 00:22:05.000



    Jeff Moden (10/15/2013)

    Look again, please. There is absolutely no way that there are more than 25 hours between 10:05PM one day and 02:04AM the very next day.


    Looks like 22 minutes after midnight to me not 10:05PM.



    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
    Since random numbers are too important to be left to chance, let's generate some!
    Learn to understand recursive CTEs by example.
    Splitting strings based on patterns can be fast!
    Post #1505043
    Posted Tuesday, October 15, 2013 8:40 PM


    SSC-Dedicated

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

    Group: General Forum Members
    Last Login: Yesterday @ 8:02 PM
    Points: 35,397, Visits: 31,955
    dwain.c (10/15/2013)
    2013-09-30 00:22:05.000



    Jeff Moden (10/15/2013)

    Look again, please. There is absolutely no way that there are more than 25 hours between 10:05PM one day and 02:04AM the very next day.


    Looks like 22 minutes after midnight to me not 10:05PM.


    Ah crud. You're right. My apologies. I'd like to blame it on old eyes but can't on this one..


    --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."

    (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 #1505049
    Posted Tuesday, October 15, 2013 9: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 @ 8:02 PM
    Points: 35,397, Visits: 31,955
    Shifting gears back to the original subject... IF you're using the DATETIME datatype, you can really cheat on this one. As a bit of a sidebar, there's great utility in being able to do direct addition and subtraction of dates and times. I'll never understand why MS didn't include such a simple capability with the DATE and TIME datatypes. If they ever change that for the DATETIME datatype, there will be some high velocity porkchops in some designer's future.

    Details are in the code below and I've created a test table in case folks want to do performance testing or "effective range" testing. Solutions with a DATEDIFF in milliseconds have their limits.

    --===== Create a million row test table of start and end dates
    -- where the end date is always later than the start date.
    -- In this case, there could be a full century of time between the dates.
    IF OBJECT_ID('tempdb..#JBMTest','U') IS NOT NULL DROP TABLE #JBMTest;

    WITH cteRandomStartDT AS
    (
    SELECT TOP 1000000
    StartDT = RAND(CHECKSUM(NEWID())) * DATEDIFF(dd,'2000','2020') + CAST('2000' AS DATETIME)
    FROM sys.all_columns ac1
    CROSS JOIN sys.all_columns ac2
    )
    SELECT StartDT
    ,EndDT = RAND(CHECKSUM(NEWID())) * DATEDIFF(dd,'2000','2100') + StartDT
    INTO #JBMTest
    FROM cteRandomStartDT
    ;
    --===== Calculate the Delta-T for each start/end date pair in the table.
    -- I'm dumping the output to a variable to take display times out of the picture.
    -- The formula calculates the total difference in time, converts that to HH:MI:SS:mmm format,
    -- and then stuffs the first 2 characters out and replaces them with difference in time
    -- measured in whole hours.
    DECLARE @BitBucket VARCHAR(20);
    SET STATISTICS TIME ON;
    SELECT @BitBucket = STUFF(CONVERT(VARCHAR(20),EndDT-StartDT,114),1,2,DATEDIFF(hh,0,EndDT-StartDT))
    FROM #JBMTest;
    SET STATISTICS TIME OFF;
    GO
    --===== Just to show that it really does work...
    SELECT *
    ,DeltaT = STUFF(CONVERT(VARCHAR(20),EndDT-StartDT,114),1,2,DATEDIFF(hh,0,EndDT-StartDT))
    FROM #JBMTest
    ORDER BY EndDT-StartDT
    ;





    --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."

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

    Add to briefcase 12»»

    Permissions Expand / Collapse