SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 SQL Server 2012 Forums
 Transact-SQL (2012)
 Converting Text Date
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

Gregorys05
Starting Member

5 Posts

Posted - 06/14/2013 :  04:37:03  Show Profile  Reply with Quote
Hi all,
I am trying to covert a column heading date (Text format) to a normal date format

I have Tried

@T = '01/JUN/13'
@Fielddate = Convert(Date,@T,6)


I keep getting the error:
Conversion failed when converting date and/or time from character string

Any ideas


visakh16
Very Important crosS Applying yaK Herder

India
52325 Posts

Posted - 06/14/2013 :  04:44:06  Show Profile  Reply with Quote
try

DECLARE @T varchar(10)='01/JUN/13'

SELECT CONVERT(datetime,STUFF(REPLACE(@T,'/',' '),8,0,'20'),106)


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

India
52325 Posts

Posted - 06/14/2013 :  04:46:59  Show Profile  Reply with Quote
Ok...reading again a small thing . if the datatype is text you need this small hack as well. I also guess its should be a column as you cant have local variable with text datatype.


SELECT CONVERT(datetime,STUFF(REPLACE(CAST(column AS varchar(max)),'/',' '),8,0,'20'),106)
FROM table



Few things to note

1. text datatype is deprecated. So you should be using varchar(max) instead
2. Please try to use appropriate datatypes for fields. If it stores date values datatype has to be datetime,date etc

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs

Edited by - visakh16 on 06/14/2013 04:50:33
Go to Top of Page

Gregorys05
Starting Member

5 Posts

Posted - 06/14/2013 :  05:01:34  Show Profile  Reply with Quote
That works Thanks

on a slight side note, the @T column cycles through the name of the columns within my table so some times the column is not a date format it could be just words is there a way to skip over the @fielddate if it errors?
Go to Top of Page

stepson
Constraint Violating Yak Guru

Romania
439 Posts

Posted - 06/14/2013 :  05:08:48  Show Profile  Reply with Quote
with ISDATE('expression')
you can skip
see link
http://msdn.microsoft.com/en-us/library/ms187347.aspx


select ...
from table
where ISDATE('expression')=1



Ce-am pe mine am si-n dulap, cand ma-mbrac zici ca ma mut
sabinWeb
Go to Top of Page

Gregorys05
Starting Member

5 Posts

Posted - 06/14/2013 :  05:17:32  Show Profile  Reply with Quote
That's Brilliant thank you very much
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

India
52325 Posts

Posted - 06/14/2013 :  05:17:50  Show Profile  Reply with Quote
quote:
Originally posted by Gregorys05

That works Thanks

on a slight side note, the @T column cycles through the name of the columns within my table so some times the column is not a date format it could be just words is there a way to skip over the @fielddate if it errors?


in that case it might be better to use functions like TRYCONVERT() available in 2012 to parse and make it datetime which will return just NULL and will not throw any error if the value is not in valid dateformat

then you could put a WHERE condition to filter off the nulls



SELECT TRY_CONVERT(datetime,STUFF(REPLACE(@T,'/',' '),8,0,'20'),106)


http://msdn.microsoft.com/en-us/library/hh230993.aspx

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.08 seconds. Powered By: Snitz Forums 2000