Time as a high precision difference of dates

  • Hi all,

    I am trying to get a high precision difference of dates in SQL Server 2008 R2, and can't seem to fine anything but datediff, which gives the difference down to 3 places for milliseconds. So if I have a difference of dates that has 3 hours, 2 minutes, 12 seconds, and 9859381 in milliseconds, I will get 3:2:12.985. I am looking for 3:2:12.9859381, and that is to be used as data to a time variable. Any suggestions? I've looked around and can't seem to find anything about getting a higher precision than 3 places. And then I need to be able to convert the result to save in a Time variable with that level of precision.

    Thanks for any help...

  • Have you looked at DATETIME2 and TIME? They can go to 7 decimal places in precision and DATADIFF will go to nanoseconds if I remember correctly. Also, I think it only goes to 100 nanoseconds. You'll have to check that in Books Online.

  • the datetime2 datatype goes to 7 decimal places;

    can you show what it is you are trying to do?

    With MyCTE (TheTime)

    AS

    (

    SELECT convert(datetime2,'1900-01-01 0:12:14.1241234') UNION ALL

    SELECT '1900-01-01 0:08:16.361' UNION ALL

    SELECT '1900-01-01 0:08:57.705'

    )

    SELECT *

    From myCTE

    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!

  • You know, I only just thought of the fact I'd done a convert to milliseconds instead of microseconds, and then I checked with microseconds which only gives a precision of 6 places, but I didn't realize datediff does nanoseconds. Thank you. That is my answer as far as getting the precision.

    Thanks a lot...

    bruce

  • Ok, so this isn't enough for what I need. Here's what I'm actually trying to do. I am writing a SQL script as a conversion process from an old to a new db schema. For one table in particular, I need to take two dates in each field, and in the destination table, I need to write out the time difference between these two dates. Due to the nature of the data being written to this table, the difference between these two dates will never be greater than a few hours.

    So what I need to do is take the difference between the two datetime2(7) fields in a record, and create a time(7), which contains the same precision in nanoseconds as the original datetime2(7) fields.

    What I originally thought I could do was to just subtract one date from another and then cast the result to a time(7), but when I do that I get the error message "Operand data type datetime2 is invalid for subtract operator".

    So I thought I'd use datediff, which now I know I can go down to nanoseconds, but when I try with something that has a difference of a little over an hour I get "The datediff function resulted in an overflow", with a suggestion that I use lower precision, but the precision is important to my customer for this application.

    So the next thing I'm thinking is to convert each datetime2 to a string, split into its parts, and then work the thing out for myself. But I have a hard time believing that SQL Server's transact sql has no way of doing this for us. Am I right? Should I need to get down and dirty with this thing? Or is there something I'm missing?

  • Here is my problem. As good as your description of the process, I can't see what you are trying to accomplish. You should post the DDL for the tables, some sample data for the tables (NOT PRODUCTION DATA), and the expected results when done based on the sample data.

  • Sorry about that. Below, you can see that I have a source and a destination table, with names changed to protect the innocent. The source table has two datetime2(7) fields, and the destination table has one time(7) field. All other fields in the source table are duplicated in the destination table. This is because I am converting the data in the source into the correct format for the destination, which amounts to just copying all fields over except the date/time fields, and for the date/time fields, I want to take the two datetime2(7) dates, get a time span as the difference between the two dates (which as said before is never going to be more than a few hours difference). This time span needs to be stored as a time(7) data type.

    So the questions I'm trying to find an answer for are, how do I first get the time span difference between the two, and how do I then get that into a time(7) data format. I would think this should be pretty easy, because in most higher level languages, there are one-liners for doing something like this. But I haven't yet found a one-liner for doing this.

    SourceTable {

    ID identity int,

    StartTime datetime2(7),

    EndTime datetime2(7),

    SomeField1 int,

    SomeField2 varchar(128),

    SomeField3 double

    }

    DestinationTable {

    ID identity int,

    TimeSpan time(7),

    SomeField1 int,

    SomeField2 varchar(128),

    SomeField3 double

    }

    SourceTable (data):

    ID StartTime EndTime SomeField1 SomeField2 SomeField3

    1 2012-04-26 13:53:43.0000000 2012-04-26 13:54:44.5448951 1234 dummytext1 9853.12354

    2 2012-10-01 12:00:00.0130952 2012-10-01 17:00:04.9845083 24778 dummytext2 325.0

    The above table data needs to be processed so that it becomes the below expected destination data:

    DestinationTable (data):

    ID TimeSpan SomeField1 SomeField2 SomeField3

    1 00:01:01.5448951 1234 dummytext1 9853.12354

    2 05:00:04.9714131 24778 dummytext2 325.0

    The problems I've run into so far are:

    1) I tried using datediff for nanoseconds (since I want to keep the level of precision at 7 places), but I got the error "The datediff function resulted in an overflow". And anyway, I don't really see a way to convert the integer result into time(7) data. An example of what I did to produce this error is as follows:

    declare @dt1 datetime2(7) = convert (datetime2, '2012-04-26 13:53:43.0')

    declare @dt2 datetime2(7) = convert (datetime2, '2012-04-26 14:54:44.5448951')

    select datediff(nanosecond, @dt1, @dt2)

    2) I tried merely subtracting the earlier datetime2 from the later datetime2, but got the error "Operand data type datetime2 is invalid for subtract operator". At least with this I would have expected the result to be a datetime2, which I could then just grab the time part from, but it is not allowed for datetime2. And example of this is:

    declare @dt1 datetime2(7) = convert (datetime2, '2012-04-26 13:53:43.0')

    declare @dt2 datetime2(7) = convert (datetime2, '2012-04-26 14:54:44.5448951')

    select datediff(nanosecond, @dt1, @dt2)

    3) I am now looking at getting strings for each datetime2 and splitting them to get the hours, minutes, seconds, and nanoseconds strings, and then convert these to integer and do the timespan calculation myself, with hours, minutes, seconds, and nanoseconds as the result, and then creating time(7) data from the result. But this really seems to be so much more work than should be necessary.

    Hopefully this is enough information. I'm just thinking it shouldn't be this hard, and so I'm wondering if I'm going in the wrong direction, and if there's just another way that someone would normally do this in transact sql. It's not possible that I could be the first to try this. ๐Ÿ™‚

    Thanks again...

  • Tricky but not impossible: this is just a proof of concept.

    With MyCTE (TheTime)

    AS

    (

    SELECT convert(datetime2,'1900-01-01 0:08:00.0000001') UNION ALL

    SELECT '1900-01-01 0:09:18.361' UNION ALL

    SELECT '1900-01-01 0:13:50.705'

    )

    SELECT

    *,

    CAST(f.q AS TIME(7))

    From myCTE a1

    CROSS JOIN myCTE a2

    CROSS APPLY (SELECT s_difference = DATEDIFF(second,a1.TheTime, a2.TheTime)) a

    CROSS APPLY (SELECT aTime = DATEADD(second,s_difference,a1.TheTime)) b

    CROSS APPLY (SELECT nsFraction = DATEDIFF(ns,aTime,a2.TheTime)) c

    CROSS APPLY (SELECT tt = DATEADD(second,s_difference,0)) d

    CROSS APPLY (SELECT t = CONVERT(VARCHAR(8),tt,108)) e

    CROSS APPLY (SELECT q = e.t + '.' + CAST(nsFraction AS VARCHAR)) f

    WHERE a1.TheTime < a2.TheTime

    โ€œ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

  • That's great!!! Thanks. I had to make a slight change because if the nsFraction part is small, when it is cast to varchar, it should have leading zeroes to put it in the right place, but it doesn't. So I changed it to the following code. This is exactly the same as yours, but I added a few more datetime2 entries for more testing, and functionally, I added a case statement to the select that assigns to q. This case statement, kind of laboriously, makes sure that the correct place is kept for the fractional part.

    With MyCTE (TheTime)

    AS

    (

    SELECT convert(datetime2,'1900-01-01 00:08:33.580') UNION ALL

    SELECT '1900-01-01 00:08:32.579' UNION ALL

    SELECT '1900-01-01 00:08:32.581' UNION ALL

    SELECT '1900-01-01 00:09:18.361' UNION ALL

    SELECT '1900-01-01 00:13:50.705'

    )

    SELECT

    *,

    CAST(f.q AS TIME(7))

    From myCTE a1

    CROSS JOIN myCTE a2

    CROSS APPLY (SELECT s_difference = DATEDIFF(second,a1.TheTime, a2.TheTime)) a

    CROSS APPLY (SELECT aTime = DATEADD(second,s_difference,a1.TheTime)) b

    CROSS APPLY (SELECT nsFraction = DATEDIFF(ns,aTime,a2.TheTime)) c

    CROSS APPLY (SELECT tt = DATEADD(second,s_difference,0)) d

    CROSS APPLY (SELECT t = CONVERT(VARCHAR(8),tt,108)) e

    CROSS APPLY (SELECT q = case when nsfraction < 0 then e.t + '.' + CAST(1000000000 + nsFraction AS VARCHAR)

    when nsfraction < 10 then e.t + '.00000000' + CAST(nsFraction AS VARCHAR)

    when nsfraction < 100 then e.t + '.0000000' + CAST(nsFraction AS VARCHAR)

    when nsfraction < 1000 then e.t + '.000000' + CAST(nsFraction AS VARCHAR)

    when nsfraction < 10000 then e.t + '.00000' + CAST(nsFraction AS VARCHAR)

    when nsfraction < 100000 then e.t + '.0000' + CAST(nsFraction AS VARCHAR)

    when nsfraction < 1000000 then e.t + '.000' + CAST(nsFraction AS VARCHAR)

    when nsfraction < 10000000 then e.t + '.00' + CAST(nsFraction AS VARCHAR)

    when nsfraction < 100000000 then e.t + '.0' + CAST(nsFraction AS VARCHAR)

    else e.t + '.' + CAST(nsFraction AS VARCHAR)

    end) f

    WHERE a1.TheTime < a2.TheTime

    If you have a better way of going about this, I would like to see it. Your code was very succinct, elegant, and a great deal quicker I'm sure than what I was working on doing.

    Thanks...

    Bruce

  • This might be better than the CASE:

    With MyCTE (aTime, bTime)

    AS

    (

    SELECT convert(datetime2,'1900-01-01 00:08:00.0000001'), convert(datetime2,'1900-01-01 00:09:18.361')

    UNION ALL SELECT '1900-01-01 00:08:00.0000001', '1900-01-01 00:13:50.705'

    UNION ALL SELECT '1900-01-01 00:09:18.361', '1900-01-01 03:13:50.7050001'

    UNION ALL SELECT '1900-01-01 23:09:18.361', '1900-01-02 02:13:50.7050001'

    UNION ALL SELECT '1900-01-01 00:00:00.000000111', '1900-01-01 00:00:00.000000222'

    )

    SELECT

    *,

    CAST(f.q AS TIME(7))

    From myCTE a1

    CROSS APPLY (SELECT s_difference = DATEDIFF(second,aTime, bTime)) a

    CROSS APPLY (SELECT axTime = DATEADD(second,s_difference,aTime)) b

    CROSS APPLY (SELECT nsFraction = DATEDIFF(ns,axTime,bTime)) c

    CROSS APPLY (SELECT tt = DATEADD(second,s_difference,0)) d

    CROSS APPLY (SELECT t = CONVERT(VARCHAR(8),tt,108)) e

    CROSS APPLY (SELECT q = e.t + '.'

    + RIGHT('000000000'+CAST(DATEDIFF(ns,DATEADD(second,s_difference,aTime),bTime) AS VARCHAR),9)

    ) f

    Here's another model after some fiddling around:

    With MyCTE (aTime, bTime)

    AS

    (

    SELECT convert(datetime2,'1900-01-01 00:08:00.0000001'), convert(datetime2,'1900-01-01 00:09:18.361')

    UNION ALL SELECT '1900-01-01 00:08:00.0000001', '1900-01-01 00:13:50.705'

    UNION ALL SELECT '1900-01-01 00:09:18.361', '1900-01-01 03:13:50.7050001'

    UNION ALL SELECT '1900-01-01 23:09:18.361', '1900-01-02 02:13:50.7050001'

    UNION ALL SELECT '1900-01-01 00:00:00.000000111', '1900-01-01 00:00:00.000000222'

    )

    SELECT

    aTime,

    bTime,

    Result = CAST(f.q AS TIME(7)),

    SimpleProof = DATEADD(ms,DATEDIFF(ms,aTime, bTime),CAST(CAST(0 AS DATETIME) AS DATETIME2))

    From myCTE a1

    CROSS APPLY (SELECT s_difference = DATEDIFF(second,aTime, bTime)) a

    CROSS APPLY (

    SELECT q = CONVERT(VARCHAR(8),DATEADD(second,s_difference,0),108) + '.'

    + RIGHT('000000000'+CAST(DATEDIFF(ns,DATEADD(second,s_difference,aTime),bTime) AS VARCHAR),9)

    ) f;

    โ€œ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

  • Actually, I did forget to mention that my case was also taking care of the case where the fraction of the first date is larger than the fraction of the second date. So if you have a first date built using '1900-01-01 00:08:00.367', and a second date using '1900-01-01 00:09:18.361', you'll get a f.g of 00:01:18.0-6000000. This is because, even though the first date is actually earlier than the second, the fraction part is larger, and so you end up with a -6000000 as nsFraction. So in my case, I said if nsFraction is < 0, then add to nsFraction to 1000000000 to get the correct nanoseconds with correct fractional positioning.

    So there are two issues with your original query: the issue of losing position for the fractional part, and the issue where the fractional part, after doing the diff, turns out to be negative.

    Do you have another fix for the negative issue? I'd really like to see your take on this.

  • I forgot to mention that the first part of my case statement checks to see if the nsFraction is negative. This can happen even though the overall first date is less than the second date, since the fraction part of the first can still be larger than the fraction part of the second. So I added a case where if the nsFraction is negative, I add it to 1000000000 before casting to varchar. This fixes the problem of a negative nsFraction.

    If you can do this with another fix to the query(ies) you showed, that would be very interesting to see.

    Thanks...

    Bruce

  • Ok, that's interesting. I didn't see the first of these, and so I sent another version, thinking I'd forgotten, somehow, to click Post. Then I realized I had to go to page 2 to see it. That's very embarrassing. ๐Ÿ™‚

  • I had also forgotten to adjust the seconds. When the earlier date has a larger fractional part than the later date, as well as adding the fractional part to 1000000000, I needed to be subtracting 1 from s_difference, the difference in seconds. I changed the query again so that the CROSS APPLY to calculate tt is as follows:

    CROSS APPLY (SELECT tt = case when nsfraction < 0 then DATEADD(second, s_difference - 1, 0)

    else DATEADD(second, s_difference + 1, 0)

    end) d

    One more thing about the original code, it takes into account the case where the timespan is greater than a day, which is very nice, since, as much as my client assures me that will never happen, I've been assured of many things in my time. This code will not break if that eventuality ever comes about.

  • I think you avoid all the CROSS APPLYs, as below.

    As written the code just ignores anything beyond 24 hrs, but if you needed to, you could add a check for that.

    SELECT

    StartTime, EndTime,

    CONVERT(varchar(8), DATEADD(SECOND, DATEDIFF(SECOND, StartTime, EndTime)

    - CASE WHEN DATEPART(NANOSECOND, StartTime) > DATEPART(NANOSECOND, EndTime) THEN 1 ELSE 0 END, 0), 108) +

    '.' + RIGHT(REPLICATE('0', 7) +

    CAST(((CASE WHEN DATEPART(NANOSECOND, StartTime) > DATEPART(NANOSECOND, EndTime) THEN 1000000000 ELSE 0 END +

    DATEPART(NANOSECOND, EndTime) - DATEPART(NANOSECOND, StartTime)) / 100) AS varchar(7)), 7) AS TimeDiff

    FROM SourceTable

    ORDER BY ID

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

Viewing 15 posts - 1 through 15 (of 36 total)

You must be logged in to reply to this topic. Login to reply