Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


SQL 2005 query error


SQL 2005 query error

Author
Message
balasach82
balasach82
SSC-Addicted
SSC-Addicted (459 reputation)SSC-Addicted (459 reputation)SSC-Addicted (459 reputation)SSC-Addicted (459 reputation)SSC-Addicted (459 reputation)SSC-Addicted (459 reputation)SSC-Addicted (459 reputation)SSC-Addicted (459 reputation)

Group: General Forum Members
Points: 459 Visits: 1079
ColA -- nvarchar
SELECT * from TABLENAME where isdate(ColA)=1 and (ColA)<>'' and DATEDIFF(year,cast(ColA as datetime), GETDATE()) = 1

SELECT * from TABLENAME where isdate(ColA)=1 and (ColA)<>'' and CAST(ColA AS DATETIME) < DATEADD(yyyy, -1, GETDATE())

Msg 8115, Level 16, State 2, Line 1
Arithmetic overflow error converting expression to data type datetime.

Any idea why i get this error?

If new datetime col is added and values are inserted from ColA then the above queries runs.
Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16539 Visits: 16992
balasach82 (3/29/2013)
ColA -- nvarchar
SELECT * from TABLENAME where isdate(ColA)=1 and (ColA)<>'' and DATEDIFF(year,cast(ColA as datetime), GETDATE()) = 1

SELECT * from TABLENAME where isdate(ColA)=1 and (ColA)<>'' and CAST(ColA AS DATETIME) < DATEADD(yyyy, -1, GETDATE())

Msg 8115, Level 16, State 2, Line 1
Arithmetic overflow error converting expression to data type datetime.

Any idea why i get this error?

If new datetime col is added and values are inserted from ColA then the above queries runs.



Because you have some values that can't be cast as datetime. You probably need to do this in two passes. Create a cte then filter it.

Something like this:



;with MyDates as
(
   SELECT * from TABLENAME where isdate(ColA)=1
)

select * from MyDates
where DATEDIFF(year,cast(ColA as datetime), GETDATE()) = 1



Also there is no need for this: and (ColA) <> ''

The IsDate function already removes that.


select ISDATE('')



_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
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