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

Convert nanoseconds since 1/1/1601 Expand / Collapse
Author
Message
Posted Thursday, August 07, 2008 9:16 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Friday, September 19, 2008 1:56 PM
Points: 10, Visits: 17
I have an ldap query which writes data to a SQL table. Fields like "LastLoggedON". Unfortunately it extracts this data in 100 Nanoseconds since 1/1/1601. I have been unsuccessful in converting these large integers. Example: this number reflects someone who logged in at approximately noon yesterday. (128624995457225598)

I have this correct syntax for Dateadd but when the integer gets too big it throws this error:
Arithmetic overflow error converting expression to data type int.

select dateAdd(hour,
datediff(hour, getutcdate(), getdate()), --UTC offset
dateadd(second, 1116012701, '1/1/1970 12:00 AM'))
Post #548385
Posted Thursday, August 07, 2008 10:08 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 6:24 AM
Points: 10,907, Visits: 12,540
You are going to have to do some interesting work to get this up because the Datetime datatype starts at 1/1/1753. Here is how I think you need to do it.

SELECT 
  
128624995457225598*100/POWER(10, 9) seconds_since_1601,
  
CONVERT(bigint, DATEDIFF(minute, '1/1/1801', '1/1/1953')) * 60 seconds_in_153_years,
  
128624995457225598*100/POWER(10, 9) - (CONVERT(bigint, DATEDIFF(minute, '1/1/1801', '1/1/1953')) * 60) col1_minus_col2,
   (
128624995457225598*100/POWER(10, 9) -  (CONVERT(bigint, DATEDIFF(minute, '1/1/1801', '1/1/1953')) * 60))/60 minutes,
  
DATEADD(minute,(128624995457225598*100/POWER(10, 9) -  (CONVERT(bigint, DATEDIFF(minute, '1/1/1801', '1/1/1953')) * 60))/60, '1/1/1753') AS date


I think this will do what you need.




Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
Post #548443
Posted Thursday, August 07, 2008 10:46 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Friday, September 19, 2008 1:56 PM
Points: 10, Visits: 17
This works GREAT: (your code)
SELECT
DATEADD(minute,(128624995457225598*100/POWER(10, 9) - (CONVERT(bigint, DATEDIFF(minute, '1/1/1801', '1/1/1953')) * 60))/60, '1/1/1753') AS date

But as soon as I try to plug in the real column (which had to be imported as a varchar) I get this error:
Arithmetic overflow error converting expression to data type bigint.

SELECT
DATEADD(minute,(convert(bigint,lastlogon)*100/POWER(10, 9) - (CONVERT(bigint, DATEDIFF(minute, '1/1/1801', '1/1/1953')) * 60))/60, '1/1/1753') AS date
from dbo.smx_empdirectory
Post #548480
Posted Thursday, August 07, 2008 11:04 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 6:24 AM
Points: 10,907, Visits: 12,540
Sounds like you have a really huge number on your hands then, or you have some non-numeric data in that column. I'd usually try to break the problem down into chunks here. I'd start by doing:

SELECT
  
lastlogon
FROM
   TABLE
WHERE
  
ISNUMERIC(lastlogon) <> 1


To see if I have any non-numeric characters although this doesn't always work as '+', '-', and '.' will return 1.





Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
Post #548497
Posted Thursday, August 07, 2008 11:23 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Friday, September 19, 2008 1:56 PM
Points: 10, Visits: 17
Good thinking. There were no non-numerics except what appeared to be white space. I deleted all those rows and searched for + and -. I also found some ZERO's and deleted those rows.

I did a max and min len and all the integers are 18 in length.

Still get the same error.
Post #548523
Posted Thursday, August 07, 2008 11:27 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 6:24 AM
Points: 10,907, Visits: 12,540
Here's what I'd do next (assumes you have primary key on the source table):

CREATE TABLE logins 
  
(
  
pk datatype,
  
lastlogon bigint
  
)

INSERT INTO logins
  
SELECT TOP 50%
      
A.pk,
      
A.laslogon
  
FROM
       TABLE
A LEFT JOIN
      
logins L ON
          
A.pk = L.pk
  
WHERE
      
L.pk IS NULL

SELECT
  
lastlogon
FROM
   TABLE
WHERE
  
ISNUMERIC(lastlogon) <> 0






Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
Post #548532
Posted Thursday, August 07, 2008 11:35 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 3:15 PM
Points: 22,475, Visits: 30,154
Not sure, but would using a decimal (decimal(24,0)) instead of bigint help at all?




Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #548538
Posted Thursday, August 07, 2008 12:07 PM


SSCrazy Eights

SSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy Eights

Group: General Forum Members
Last Login: Friday, March 28, 2014 2:25 PM
Points: 9,902, Visits: 9,479
Actually, I think that this will fix Jack's original code:
SELECT 
DATEADD(minute,(convert(bigint,lastlogon)*(100/POWER(10, 9)) - (CONVERT(bigint, DATEDIFF(minute, '1/1/1801', '1/1/1953')) * 60))/60, '1/1/1753') AS date
from dbo.smx_empdirectory



-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
Post #548560
Posted Thursday, August 07, 2008 12:15 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Friday, September 19, 2008 1:56 PM
Points: 10, Visits: 17
I don't see any change....
Post #548567
Posted Thursday, August 07, 2008 12:45 PM


SSCrazy Eights

SSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy Eights

Group: General Forum Members
Last Login: Friday, March 28, 2014 2:25 PM
Points: 9,902, Visits: 9,479
Actually, it's a different error now. This should do it:
SELECT 
DATEADD(minute,(convert(bigint,lastlogon)*100.0/POWER(10, 9) - (CONVERT(bigint, DATEDIFF(minute, '1/1/1801', '1/1/1953')) * 60))/60, '1/1/1753') AS date
from dbo.smx_empdirectory



-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
Post #548589
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse