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


Converting Time value stored in minutes


Converting Time value stored in minutes

Author
Message
Tom Van Harpen
Tom Van Harpen
SSC Eights!
SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)

Group: General Forum Members
Points: 918 Visits: 1102
In the source system the date and time is stored as an integer representing the number of minutes AD. I have been unable to tie out to the date and time value.

Minutes = 1056915413

The application that uses this data displays it as 6/30/2010 19:53 (CDT). The metadata indicates the time is stored as UTC so the minutes should equal - 2010-07-01 01:53:00.000

Manual calculations:

--(1440*365.25) minutes per year = 525960.00

-- get year, add 1 since start date should be 1-1-0001
SELECT (1056915413/525960)+1

-- minutes based on remainder
SELECT (1056915413%525960)

-- add minutes remaining to midnight on jan 1, 2010
SELECT DATEADD(n,261773,'2010-01-01 00:00:00')



Results:

-----------
2010

(1 row(s) affected

---------------------------------------
261773.00

(1 row(s) affected)

-----------------------
2010-07-01 18:53:00.000

(1 row(s) affected)


Is there a function in SQL or a standard method to determine this.

I tried the following C#:

DateTime startDT = new DateTime(0001, 1, 1, 0, 0, 0);
TimeSpan span = new TimeSpan(0, 1056915413, 0);

textBox1.Text = Convert.ToString(startDT+span);


This returned 7/17/2010 0:53:00 AM

The minutes are correct in both examples. Any suggestions would be great.
stevefromOZ
stevefromOZ
Hall of Fame
Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)

Group: Moderators
Points: 3610 Visits: 3757
You could make a UDF that contains the logic and then use it inline. Primary contents would be


DECLARE
@jDate INT,
@jBase INT
SET @jBase = 998799780 -- 1900-01-01

SET @jDate = 1056915413 -- this is the parameter you set to your incoming 'number'

SELECT DATEADD(n, (@jDate - @jBase), '1900-01-01 00:00')

HTH,

Steve.
Wesley Norton
Wesley Norton
Old Hand
Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)Old Hand (383 reputation)

Group: General Forum Members
Points: 383 Visits: 442
How about correcting for the time zone? Maybe I'm not getting your question, but would something like this work:

SELECT dateadd(ss,(DATEDIFF(ss,GETDATE(),GETUTCDATE())),(DATEADD(n,261773,'2010-01-01 00:00:00')))


WayneS
WayneS
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10146 Visits: 10575
Since you posted in a SQL 2005 forum, I'm assuming that you are on that version, which means that the sql 2008 date/time enhancements won't help you:
declare @minutes int = 1056915413
declare @test datetime2 = '01/01/0001'
select DATEADD(minute, @minutes, @test)


This code returns:
2010-07-17 00:53:00.0000000

The six hour part is the GMT offset (which takes it to 2010-07-16 18:53:00.0000000), but this leaves a 15 day discrepancy. I think that most of this is that the day after 9/2/1752 was 9/14/1752, but this only accounts for 11 of those days. The 365.25 accounts for some also... years evenly divisible by 100, unless evenly divisibly by 400, aren't leap years. Which means in 400 years, there are 146097 days (210379680 minutes); your calculation would get 146100 days (210384000 minutes).

So, the conversion you're doing in C# looks correct to me.

You might want to consider a calendar table - list of all dates since 01/01/0001. The following code (on SQL 2008) returns the proper date/time (7/17/2010 00:53:00.0000000) for the minutes:
declare @test datetime2 = '01/01/0001'
-- See Jeff Moden's article
-- The "Numbers" or "Tally" Table: What it is and how it replaces a loop.
-- at http://www.sqlservercentral.com/articles/T-SQL/62867/.
-- NOTE! A permanent tally table will always be MUCH faster
-- than this inline one. See the above article to create your own!
;WITH
Tens (N) AS (SELECT 0 UNION ALL SELECT 0 UNION ALL SELECT 0 UNION ALL
SELECT 0 UNION ALL SELECT 0 UNION ALL SELECT 0 UNION ALL
SELECT 0 UNION ALL SELECT 0 UNION ALL SELECT 0 UNION ALL SELECT 0),
Thousands(N) AS (SELECT 1 FROM Tens t1 CROSS JOIN Tens t2 CROSS JOIN Tens t3),
Millions (N) AS (SELECT 1 FROM Thousands t1 CROSS JOIN Thousands t2),
Tally (N) AS (SELECT ROW_NUMBER() OVER (ORDER BY (SELECT 0)) FROM Millions),
Dates AS (SELECT DateField = DATEADD(day, N-1, @test) FROM Tally WHERE N-1 = 1056915413/1440)
SELECT DATEADD(MINUTE, 1056915413 % 1440, DateField)
FROM Dates



Edit: Modified to add the minutes to the date in the calendar table CTE.

Wayne
Microsoft Certified Master: SQL Server 2008
Author - SQL Server T-SQL Recipes
If you can't explain to another person how the code that you're copying from the internet works, then DON'T USE IT on a production system! After all, you will be the one supporting it!
Links: For better assistance in answering your questions, How to ask a question, Performance Problems, Common date/time routines,
CROSS-TABS and PIVOT tables Part 1 & Part 2, Using APPLY Part 1 & Part 2, Splitting Delimited Strings

Michael Valentine Jones
Michael Valentine Jones
SSCertifiable
SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)

Group: General Forum Members
Points: 5958 Visits: 11771
This conversion looks close to what you want:


select
*,
MyDateTime =
dateadd(mi,convert(bigint,a.MyTime-998799780)%convert(bigint,1440),dateadd(dd,(a.MyTime-998799780)/1440,0))
from
( -- Test Data
select MyTime = convert(bigint,1056915413) union all
select MyTime = 000001056915413+(00000000001440*2918000)





Results:


MyTime MyDateTime
--------------------- -----------------------
1056915413 2010-07-01 01:53:00.000
5258835413 9999-09-17 01:53:00.000




Edit:
Changed solution to modify time offset, and to cover the entire range of DATETIME values.
Tom Van Harpen
Tom Van Harpen
SSC Eights!
SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)

Group: General Forum Members
Points: 918 Visits: 1102
stevefromoz
that appears to do the trick.
can I ask how you got the minute value for 1900-01-01?
stevefromOZ
stevefromOZ
Hall of Fame
Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)

Group: Moderators
Points: 3610 Visits: 3757
It may be achievable using something like todays date, but using what you gave us. You gave a starting point/constant of 1056915413 == 2010-07-01 01:53

So we're looking for [constant] - (minutes between [constant] and [1900-01-01 00:00])

which, assuming the logic is correct, could look like...

SELECT
1056915413 -- what you told me was 2010-07-01 01:53
- DATEDIFF(n, '1900-01-01 00:00', '2010-07-01 01:53') -- the date diff of that date to 1900-01-01 00:00

-- Result
998799780



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