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 ««1234»»»

Time as a high precision difference of dates Expand / Collapse
Author
Message
Posted Wednesday, September 5, 2012 11:09 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, April 23, 2013 1:42 PM
Points: 31, Visits: 79
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.
Post #1354769
Posted Wednesday, September 5, 2012 11:36 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, April 23, 2013 1:42 PM
Points: 31, Visits: 79
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
Post #1354782
Posted Wednesday, September 5, 2012 11:38 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, April 23, 2013 1:42 PM
Points: 31, Visits: 79
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. :)
Post #1354783
Posted Wednesday, September 5, 2012 12:26 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, April 23, 2013 1:42 PM
Points: 31, Visits: 79
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.
Post #1354814
Posted Wednesday, September 5, 2012 2:28 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 9:09 AM
Points: 2,268, Visits: 3,429
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)

Carl Sagan said: "There is no such thing as a dumb question." Sagan obviously never watched a congressional hearing!
Post #1354889
Posted Wednesday, September 5, 2012 3:54 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, April 23, 2013 1:42 PM
Points: 31, Visits: 79
Oops, the s_difference+1 is incorrect. That should be been just s_difference. The minus is correct.
Post #1354931
Posted Wednesday, September 5, 2012 3:54 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, April 23, 2013 1:42 PM
Points: 31, Visits: 79
I saw that you had made an extremely compact version. Haven't had time to check it out yet, but it looks pretty good at a glance.

Thanks for all the help...
Bruce
Post #1354932
Posted Thursday, September 6, 2012 2:18 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 6:52 AM
Points: 6,872, Visits: 14,185
bmahf (9/5/2012)
Oops, the s_difference+1 is incorrect. That should be been just s_difference. The minus is correct.


Here's a version which corrects for aTime being more recent than bTime, and includes a filter designed to return rows where the algorithm falls over. I've set it up with multiple CROSS APPLY operators as before, because a cascaded CROSS APPLY like this is much easier to understand and debug. Once the code is verified, the cCA can be "compacted down".

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'
UNION ALL SELECT '1900-01-01 00:10:00.000000111', '1900-01-01 00:00:00.000000222'
)
SELECT
*
From myCTE a1
CROSS APPLY (SELECT SecondsDifferenceINT = DATEDIFF(second,aTime, bTime)) a
CROSS APPLY (SELECT AdjustedFirstDateDT = DATEADD(second,SecondsDifferenceINT,aTime)) b
CROSS APPLY (SELECT NanosecondRemainderINT = DATEDIFF(ns,AdjustedFirstDateDT,bTime)) c
-- use ABS() to convert seconds difference to a positive number
-- where aTime is more recent than bTime
CROSS APPLY (SELECT TimeToSecondsDT = DATEADD(second,ABS(SecondsDifferenceINT),0)) d
CROSS APPLY (SELECT TimeToSecondsVC = CONVERT(VARCHAR(8),TimeToSecondsDT,108)) e
CROSS APPLY (SELECT ResultVC = e.TimeToSecondsVC + '.'
+ RIGHT('000000000'+CAST(NanosecondRemainderINT AS VARCHAR),9)
) f
CROSS APPLY (
SELECT
TimeResult = CAST(f.ResultVC AS TIME(7)),
SimpleProof = CAST(DATEADD(ms,ABS(DATEDIFF(ms,aTime, bTime)),CAST(CAST(0 AS DATETIME) AS DATETIME2)) AS TIME(3))
) g
-- Filter for exceptions - this will return rows where the algorithm fails
-- (if SQL Server doesn't bork first).
WHERE CAST(TimeResult AS DATETIME) <> CAST(SimpleProof AS DATETIME)



“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
Exploring Recursive CTEs by Example Dwain Camps
Post #1355103
Posted Thursday, September 6, 2012 3:31 AM


SSCrazy Eights

SSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy Eights

Group: General Forum Members
Last Login: Today @ 4:51 AM
Points: 9,928, Visits: 11,199
This looks like a thread without a one-line SQLCLR solution yet

-- see later post for updated code --




Paul White
SQL Server MVP
SQLblog.com
@SQL_Kiwi
Post #1355151
Posted Thursday, September 6, 2012 4:05 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 6:52 AM
Points: 6,872, Visits: 14,185
Nice one, Paul.

Here are two different one-line TSQL solutions:

;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'
UNION ALL SELECT '1900-01-01 00:10:00.000000111', '1900-01-01 00:00:00.000000222'
)
SELECT
aTime,
bTime,
SimpleProof = CAST(DATEADD(ms,ABS(DATEDIFF(ms,aTime, bTime)),CAST(CAST(0 AS DATETIME) AS DATETIME2)) AS TIME(3)),

-- Method 1 (Chris R - too shy to post)
TimeResult1 = CAST(
DATEADD(
NS,
ABS(CAST(SUBSTRING(CAST(btime as varchar(30)),20,8) AS float) -
CAST(SUBSTRING(CAST(atime as varchar(30)),20,8) AS float)
) *1000000000,
DATEADD(
SS,
ABS(DATEDIFF(SS, aTime, btime)),
CAST('1900-01-01 00:00' AS datetime2))
)
AS time(7)),

-- Method 2 (Chris M)
TimeResult2 = CAST(
CONVERT(VARCHAR(8),
DATEADD(second,ABS(DATEDIFF(second,aTime, bTime)),0),108) + '.'
+ RIGHT('000000000'
+ CAST(ABS(
DATEDIFF(ns,
DATEADD(second,DATEDIFF(second,aTime, bTime),aTime),
bTime))
AS VARCHAR)
,9)
AS TIME(7))


From myCTE



“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
Exploring Recursive CTEs by Example Dwain Camps
Post #1355170
« Prev Topic | Next Topic »

Add to briefcase ««1234»»»

Permissions Expand / Collapse