July 26, 2013 at 10:06 am
Hello Everyone
I am trying something, that I am not sure is possible.
I have a CreateDate column in a table, there are approx 5000 rows with the same date and time. This was done from the data load. I need to change the the time by adding one millisecond to each one, but incrementing by one from the previous row.
So if I have a datetime like this:
RowID, CreateDate
1, 2013-07-30 08:20:40:010
2, 2013-07-30 08:20:40:010
3, 2013-07-30 08:20:40:010
4, 2013-07-30 08:20:40:010
5, 2013-07-30 08:20:40:010
I would like to add one millisecond to each, but incrementing from the previous row.
RowID, CreateDate
1, 2013-07-30 08:20:40:010
2, 2013-07-30 08:20:40:011
3, 2013-07-30 08:20:40:012
4, 2013-07-30 08:20:40:013
5, 2013-07-30 08:20:40:014
Here is some dummy code.
; WITH DifferentTimes
(
RowID
, CreateDate
)
AS
(
SELECT TOP (500) n = CONVERT(INT, ROW_NUMBER() OVER (ORDER BY s1.[object_id])), '2013-07-30 08:20:40:010'
FROM sys.all_objects AS s1 CROSS JOIN sys.all_objects AS s2
)
SELECT * FROM DifferentTimes
So after that, I am not sure how I can perform an update to increment the time by each row, using the previous row.
Thank You in advance for all your assistance, suggestions and comments
Andrew SQLDBA
July 26, 2013 at 10:12 am
First of all, you can't add a milisecond to a datetime, you need to use datetime2.
Here's an example, if you remove the CAST, you'll see what I mean.
SELECT TOP (500) DATEADD( ms, ROW_NUMBER() OVER (ORDER BY s1.[object_id]), CAST('2013-07-30 08:20:40:010' AS datetime2))
FROM sys.all_objects AS s1
CROSS JOIN sys.all_objects AS s2
July 26, 2013 at 10:24 am
AndrewSQLDBA (7/26/2013)
Hello EveryoneI am trying something, that I am not sure is possible.
I have a CreateDate column in a table, there are approx 5000 rows with the same date and time. This was done from the data load. I need to change the the time by adding one millisecond to each one, but incrementing by one from the previous row.
So if I have a datetime like this:
RowID, CreateDate
1, 2013-07-30 08:20:40:010
2, 2013-07-30 08:20:40:010
3, 2013-07-30 08:20:40:010
4, 2013-07-30 08:20:40:010
5, 2013-07-30 08:20:40:010
I would like to add one millisecond to each, but incrementing from the previous row.
...
Think of it in a different way - add RowID-1 milliseconds to your datetime2 value.
For better assistance in answering your questions, please read this[/url].
Hidden RBAR: Triangular Joins[/url] / The "Numbers" or "Tally" Table: What it is and how it replaces a loop[/url] Jeff Moden[/url]
July 26, 2013 at 10:25 am
As An FYI for datetime, Luis mentioned you can't add a single millisecond; the minimum is 3 milliseconds, and that's imposed due to the way the data is stored by SQL server behind the scenes as two separate 4 byte integers.
http://msdn.microsoft.com/en-us/library/aa258277(v=sql.80).aspx
Lowell
July 26, 2013 at 10:28 am
Thank you for the reference Lowell, I knew I had read it, but I wasn't sure where to start looking for it again.
July 26, 2013 at 10:31 am
Thank You Everyone
I will try the code sample
Have a great weekend.
Andrew SQLDBA
July 28, 2013 at 6:59 pm
May I ask why you need to add 1 millisecond to each row?
In other words, what is the problem you're facing when all of the bulk insert CreatedDates are the same?
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
August 3, 2013 at 6:40 pm
dwain.c (7/28/2013)
May I ask why you need to add 1 millisecond to each row?In other words, what is the problem you're facing when all of the bulk insert CreatedDates are the same?
This is why I sometimes don't answer a question until they give me an answer. Sometimes folks just forget to post back because they're busy. 😉
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply