July 23, 2013 at 3:23 pm
I am trying to convert 20114 which is stored as varchar to datetime but I am getting the following error
Syntax error during explicit conversion of VARCHAR value '20114' to a DATETIME field.
Can some one help me in solving this?
July 23, 2013 at 3:36 pm
And what date do you expect 20114 to convert to? And by which rule?
[font="Times New Roman"]Erland Sommarskog, SQL Server MVP, www.sommarskog.se[/font]
July 23, 2013 at 5:51 pm
I need to convert it to 2011401 and need to use convert..Thank you
July 23, 2013 at 6:11 pm
2011401 does not have a common format for a date. Can you explain which is the year, month and day?
July 23, 2013 at 8:05 pm
2011 is year
4 month
01 is day
July 23, 2013 at 9:43 pm
You could try something like this
DECLARE @cDate varchar(5) = '20114'
SELECT DATEADD( MONTH, RIGHT(@cDate, 1) , CAST( LEFT(@cDate,4) + '0101' as DATE))
July 23, 2013 at 10:37 pm
Thank you..and actually it is a column that stores data as varchar and data is like this
start date
------------
20114 ----2011 is year and 4 is month
20113
20112
20105
20106
I need to represent above data as (adding date 01 to all rows)
2011401-- year month and date
2011301
2011201
2010501
2010601
that is I need to add date and convert into DATETIME and 101 style
July 24, 2013 at 1:47 am
DECLARE @d varchar(6) = '20114'
SELECT try_convert(date, substring(@d, 1, 4) +
CASE WHEN len(@d) = 5 THEN '0' ELSE '' END +
substring(@d, 5, 2) + '01')
I assume that 201110 would be 2011-10-01
I added try_convert, since most likely you have values in that column that are illegal.
[font="Times New Roman"]Erland Sommarskog, SQL Server MVP, www.sommarskog.se[/font]
July 24, 2013 at 3:10 am
Ignoring the try_convert (which is probably a good idea), I think this may be another way:
SELECT CONVERT(VARCHAR(10), CAST(STUFF('201311',5,0,'-0')+'-01' AS DATETIME), 101)
,CONVERT(VARCHAR(10), CAST(STUFF('20131',5,0,'-0')+'-01' AS DATETIME), 101);
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
July 24, 2013 at 8:28 am
DECLARE @d varchar(6) = '20114'
SELECT try_convert(date, substring(@d, 1, 4) +
CASE WHEN len(@d) = 5 THEN '0' ELSE '' END +
substring(@d, 5, 2) + '01')
This worked Thank you
July 24, 2013 at 9:31 am
DECLARE @d varchar(6) = '20114'
SELECT try_convert(date, substring(@d, 1, 4) +
CASE WHEN len(@d) = 5 THEN '0' ELSE '' END +
substring(@d, 5, 2) + '01')
This worked but I am not getting in 101 style that is 04/01/2011
July 24, 2013 at 3:12 pm
You wanted to convert to datetime, didn't you? Datetime is a binary value and includes no format. If you want a text string, just add a conversion to varchar. However, formatting of date values is best done in the client, so that the user's regional settings can be respected.
[font="Times New Roman"]Erland Sommarskog, SQL Server MVP, www.sommarskog.se[/font]
July 24, 2013 at 9:15 pm
savycara (7/24/2013)
DECLARE @d varchar(6) = '20114'SELECT try_convert(date, substring(@d, 1, 4) +
CASE WHEN len(@d) = 5 THEN '0' ELSE '' END +
substring(@d, 5, 2) + '01')
This worked but I am not getting in 101 style that is 04/01/2011
If you don't mind a non-Ansi solution (and I don't), this is pretty easy. That, not withstanding, it would be good to heed the warnings about formatting dates on the backend.
WITH
cteTestData(D) AS
( --=== This is test data and is not a part of the solution
SELECT '20111' UNION ALL
SELECT '20112' UNION ALL
SELECT '20113' UNION ALL
SELECT '20114' UNION ALL
SELECT '20115' UNION ALL
SELECT '20116' UNION ALL
SELECT '20117' UNION ALL
SELECT '20118' UNION ALL
SELECT '20119' UNION ALL
SELECT '201110' UNION ALL
SELECT '201111' UNION ALL
SELECT '201112' UNION ALL
SELECT '20121'
)
SELECT OriginalData = D
, Converted = CONVERT(CHAR(10),DATEADD(mm,SUBSTRING(D,5,2)-1,SUBSTRING(D,1,4)),101)
FROM cteTestData
;
Results:
OriginalData Converted
------------ ----------
20111 01/01/2011
20112 02/01/2011
20113 03/01/2011
20114 04/01/2011
20115 05/01/2011
20116 06/01/2011
20117 07/01/2011
20118 08/01/2011
20119 09/01/2011
201110 10/01/2011
201111 11/01/2011
201112 12/01/2011
20121 01/01/2012
If you remove the CONVERT, it will be an ANSI solution that returns the DATETIME datatype which is better for the front-end. I wouldn't even think of permanently storing a formatted date in anything but a staging table being made ready for output to a text file.
If it were me, I'd find the person that wrote the code that created original formatted date mess and take them to the woodshed for a bit of education.
--Jeff Moden
Change is inevitable... Change for the better is not.
July 24, 2013 at 9:46 pm
Jeff Moden (7/24/2013)
savycara (7/24/2013)
DECLARE @d varchar(6) = '20114'SELECT try_convert(date, substring(@d, 1, 4) +
CASE WHEN len(@d) = 5 THEN '0' ELSE '' END +
substring(@d, 5, 2) + '01')
This worked but I am not getting in 101 style that is 04/01/2011
If you don't mind a non-Ansi solution (and I don't), this is pretty easy. That, not withstanding, it would be good to heed the warnings about formatting dates on the backend.
WITH
cteTestData(D) AS
( --=== This is test data and is not a part of the solution
SELECT '20111' UNION ALL
SELECT '20112' UNION ALL
SELECT '20113' UNION ALL
SELECT '20114' UNION ALL
SELECT '20115' UNION ALL
SELECT '20116' UNION ALL
SELECT '20117' UNION ALL
SELECT '20118' UNION ALL
SELECT '20119' UNION ALL
SELECT '201110' UNION ALL
SELECT '201111' UNION ALL
SELECT '201112' UNION ALL
SELECT '20121'
)
SELECT OriginalData = D
, Converted = CONVERT(CHAR(10),DATEADD(mm,SUBSTRING(D,5,2)-1,SUBSTRING(D,1,4)),101)
FROM cteTestData
;
Results:
OriginalData Converted
------------ ----------
20111 01/01/2011
20112 02/01/2011
20113 03/01/2011
20114 04/01/2011
20115 05/01/2011
20116 06/01/2011
20117 07/01/2011
20118 08/01/2011
20119 09/01/2011
201110 10/01/2011
201111 11/01/2011
201112 12/01/2011
20121 01/01/2012
If you remove the CONVERT, it will be an ANSI solution that returns the DATETIME datatype which is better for the front-end. I wouldn't even think of permanently storing a formatted date in anything but a staging table being made ready for output to a text file.
If it were me, I'd find the person that wrote the code that created original formatted date mess and take them to the woodshed for a bit of education.
Gee whiz! And here I was thinking my STUFF solution was pretty clever.
Nice one Jeff!
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
Viewing 15 posts - 1 through 15 (of 17 total)
You must be logged in to reply to this topic. Login to reply