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


Convert nanoseconds since 1/1/1601


Convert nanoseconds since 1/1/1601

Author
Message
kevin sexton
kevin sexton
SSC Veteran
SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)

Group: General Forum Members
Points: 238 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'))
Jack Corbett
  Jack Corbett
SSC Guru
SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)

Group: General Forum Members
Points: 103939 Visits: 15047
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
Consultant Straight Path Solutions
Dont let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work
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 QuestionHow 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
kevin sexton
kevin sexton
SSC Veteran
SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)

Group: General Forum Members
Points: 238 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
Jack Corbett
  Jack Corbett
SSC Guru
SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)

Group: General Forum Members
Points: 103939 Visits: 15047
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
Consultant Straight Path Solutions
Dont let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work
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 QuestionHow 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
kevin sexton
kevin sexton
SSC Veteran
SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)

Group: General Forum Members
Points: 238 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.
Jack Corbett
  Jack Corbett
SSC Guru
SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)

Group: General Forum Members
Points: 103939 Visits: 15047
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
Consultant Straight Path Solutions
Dont let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work
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 QuestionHow 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
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)

Group: General Forum Members
Points: 224698 Visits: 40419
Not sure, but would using a decimal (decimal(24,0)) instead of bigint help at all?

Cool

Cool
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)
RBarryYoung
RBarryYoung
SSC Guru
SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)

Group: General Forum Members
Points: 80398 Visits: 9519
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."
kevin sexton
kevin sexton
SSC Veteran
SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)SSC Veteran (238 reputation)

Group: General Forum Members
Points: 238 Visits: 17
I don't see any change....
RBarryYoung
RBarryYoung
SSC Guru
SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)

Group: General Forum Members
Points: 80398 Visits: 9519
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."
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