472,145 Members | 1,733 Online
Bytes | Software Development & Data Engineering Community
Post +

Home Posts Topics Members FAQ

Join Bytes to post your question to a community of 472,145 software developers and data experts.

Adding a time column to a date column

I have two columns in a table:
StartDate DateTime and StartTime DateTime.
The StartDate column holds a value such as 07/16/2004
The StartTime column holds a value such as 3:00:00 PM

I want to be able to add them in a stored procedure.
When I use StartDate + StartTime I get a date two days earlier than expected.
For example, instead of 7/16/2004 3:00:00 PM StartDate + StartTime returns
7/14/2004 3:00:00 PM.

Can anyone point out wht I'm doing wrong with this one?

Thanks,
lq
Jul 20 '05 #1
2 6419
Lauren,

It sounds like you are using Enterprise Manager. All datetime columns in SQL Server hold both a date and a time, and if you view the
data in Query Analyzer, you should find that your StartDate column holds something like 2004-07-16 12:00:00AM and your StartTime column
holds a value like 1899-12-30 03:00:00PM.

Tools that allows data input will attach a date when a time only is entered into a SQL Server database column, and unfortunately some
tools will attach 1900-01-01 and others will attach 1899-12-30. SQL Server stores the first of these as its zero date, but it stores the
second as -2 (plus whatever fraction of a date the time portion represents, in each case). Enterprise Manager thinks that 1899-12-30 is the
base date, and both attaches it when a bare time is entered and suppresses it when it appears in a datetime to be displayed.

You are doing nothing wrong, but to be safe, you can calculate the time portion explicitly before you add. One way to do this is

StartDate + (StartTime - datediff(day,0,StartTime))

Storing time-only values in SQL Server is tricky, since there is no appropriate type. You need to be careful, and you might want to
consider alternatives, such as storing only the StartDateTime in the database, in which case you can make StartDate and StartTime computed
columns, or calculate them on the fly when you need them.

Steve Kass
Drew University

Lauren Quantrell wrote:
I have two columns in a table:
StartDate DateTime and StartTime DateTime.
The StartDate column holds a value such as 07/16/2004
The StartTime column holds a value such as 3:00:00 PM

I want to be able to add them in a stored procedure.
When I use StartDate + StartTime I get a date two days earlier than expected.
For example, instead of 7/16/2004 3:00:00 PM StartDate + StartTime returns
7/14/2004 3:00:00 PM.

Can anyone point out wht I'm doing wrong with this one?

Thanks,
lq

Jul 20 '05 #2
Steve,
Thanks a million for that. I was trying all manner of cast, convert
and datepart functions but yours is quick and simple. Thanks!
lq

Steve Kass <sk***@drew.edu> wrote in message news:<8h*****************@newsread1.news.pas.earth link.net>...
Lauren,

It sounds like you are using Enterprise Manager. All datetime columns in SQL Server hold both a date and a time, and if you view the
data in Query Analyzer, you should find that your StartDate column holds something like 2004-07-16 12:00:00AM and your StartTime column
holds a value like 1899-12-30 03:00:00PM.

Tools that allows data input will attach a date when a time only is entered into a SQL Server database column, and unfortunately some
tools will attach 1900-01-01 and others will attach 1899-12-30. SQL Server stores the first of these as its zero date, but it stores the
second as -2 (plus whatever fraction of a date the time portion represents, in each case). Enterprise Manager thinks that 1899-12-30 is the
base date, and both attaches it when a bare time is entered and suppresses it when it appears in a datetime to be displayed.

You are doing nothing wrong, but to be safe, you can calculate the time portion explicitly before you add. One way to do this is

StartDate + (StartTime - datediff(day,0,StartTime))

Storing time-only values in SQL Server is tricky, since there is no appropriate type. You need to be careful, and you might want to
consider alternatives, such as storing only the StartDateTime in the database, in which case you can make StartDate and StartTime computed
columns, or calculate them on the fly when you need them.

Steve Kass
Drew University

Lauren Quantrell wrote:
I have two columns in a table:
StartDate DateTime and StartTime DateTime.
The StartDate column holds a value such as 07/16/2004
The StartTime column holds a value such as 3:00:00 PM

I want to be able to add them in a stored procedure.
When I use StartDate + StartTime I get a date two days earlier than expected.
For example, instead of 7/16/2004 3:00:00 PM StartDate + StartTime returns
7/14/2004 3:00:00 PM.

Can anyone point out wht I'm doing wrong with this one?

Thanks,
lq

Jul 20 '05 #3

This discussion thread is closed

Replies have been disabled for this discussion.

Similar topics

9 posts views Thread by Roy Riddex | last post: by
4 posts views Thread by Rich Hurley | last post: by
4 posts views Thread by John Siracusa | last post: by
5 posts views Thread by news.swissonline.ch | last post: by
reply views Thread by Saiars | last post: by
reply views Thread by leo001 | last post: by

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.