Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

How to format the data in column in sql server Expand / Collapse
Author
Message
Posted Wednesday, June 12, 2013 7:38 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Saturday, September 27, 2014 8:18 AM
Points: 32, Visits: 104
Hi,

Please help me,

In my table have a one date column. It contains data in different formats .I want to set all these different formats into a single format.

Like...

Date
10.12.2012 ---in this '10' is Day and 12 is Month and then Year.
12-10-2012
10.12.2012
2012/10/12

Post #1462880
Posted Wednesday, June 12, 2013 9:33 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 8:51 PM
Points: 35,606, Visits: 32,190
SriSudha (6/12/2013)
Hi,

Please help me,

In my table have a one date column. It contains data in different formats .I want to set all these different formats into a single format.

Like...

Date
10.12.2012 ---in this '10' is Day and 12 is Month and then Year.
12-10-2012
10.12.2012
2012/10/12



How do you know that first date is in the dmy format instead of the mdy format? There has to be something else in the table for SQL Server to figure that out. Without some hint, even a human couldn't figure out that the first date was dmy and the 3rd day was mdy.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1462892
Posted Thursday, June 13, 2013 5:18 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Saturday, September 27, 2014 8:18 AM
Points: 32, Visits: 104

Hi,
Yes you are right,without hint we can't do nothing.

The data comes into 3 formats only.Based on that we will decide the Day and Month and Year.
That 3 formats are

10.12.2012 ----- if it is in this format the 1st part is "Day" and 2nd part is "Month" and then Year.

12-10-2012 --- if it is in this format the 1st part is "Month" and 2nd part is "Day" and then year.

2012/10/12 --if it is in this format the 1st part is "Year" and 2nd part is "Day" and 3rd part is Month.

Thanks for your quick reply.
Please help me.Its not my own thought, I got a data like this only.

Post #1462986
Posted Thursday, June 13, 2013 5:50 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 7:17 AM
Points: 2,682, Visits: 4,745
One way to achieve the results

DECLARE @YourTableName TABLE
(
ColumnName VARCHAR(20)
)

INSERT @YourTableName
SELECT '10.12.2012' UNION ALL
SELECT '12-10-2012' UNION ALL
SELECT '2012/10/12'

SELECT CASE
WHEN ColumnName LIKE '%.%' THEN CONVERT(DATETIME,ColumnName,104)
WHEN ColumnName LIKE '%-%' THEN CONVERT(DATETIME,ColumnName,110)
WHEN ColumnName LIKE '%/%' THEN CONVERT(DATETIME,LEFT(ColumnName,5)+RIGHT(ColumnName,2)+SUBSTRING(ColumnName,5,3),111)
END AS NewColumn, ColumnName
FROM @YourTableName




Kingston Dhasian

How to post data/code on a forum to get the best help - Jeff Moden
http://www.sqlservercentral.com/articles/Best+Practices/61537/
Post #1462995
Posted Thursday, June 13, 2013 6:32 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 8:51 PM
Points: 35,606, Visits: 32,190
Kinston beat me to it but, to add a little more checking, here's what I came up with.
--=============================================================================
-- Create and populate a test table. This is NOT a part of the solution.
--=============================================================================
--===== Conditionally drop the test table to make reruns in SSMS easier.
IF OBJECT_ID('tempdb..#TestTable','U') IS NOT NULL
DROP TABLE #TestTable
;
--===== Create and populate the test table on the fly
SELECT DateString
INTO #TestTable
FROM (
SELECT '10.12.2012' UNION ALL --dmy
SELECT '12-10-2012' UNION ALL --mdy
SELECT '2012/10/12' --ydm
)d(DateString)
;
--=============================================================================
-- Demonstrate one possible solution
--=============================================================================
--===== Change all the 3 types of date formats to real dates.
SELECT OriginalDateString = DateString,
ReformattedDate =
CASE
WHEN DateString LIKE '[0-3][0-9].[0-1][0-9].[1-2][0-9][0-9][0-9]' --dd.mm.yyyy
THEN CONVERT(DATETIME,DateString,104)
WHEN DateString LIKE '[0-1][0-9]-[0-3][0-9]-[1-2][0-9][0-9][0-9]' --mm-dd-yyyy
THEN CONVERT(DATETIME,DateString,110)
WHEN DateString LIKE '[1-2][0-9][0-9][0-9]/[0-3][0-9]/[0-1][0-9]' --yyyy/dd/mm
THEN CONVERT(DATETIME,RIGHT(DateString,5)+'/'+LEFT(DateString,4),103)
ELSE NULL
END
FROM #TestTable
;

If that last date format were actually yyyy/mm/dd instead of yyyy/dd/mm, we could make this a whole lot simpler as well as being able to add extra checking.




--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1463032
Posted Friday, June 14, 2013 7:49 AM


SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Today @ 9:54 AM
Points: 975, Visits: 3,036
SriSudha (6/12/2013)
Hi,

Please help me,

In my table have a one date column. It contains data in different formats .I want to set all these different formats into a single format.

Like...

Date
10.12.2012 ---in this '10' is Day and 12 is Month and then Year.
12-10-2012
10.12.2012
2012/10/12


I'm just replying because you used my birthday for your test data




The SQL Guy @ blogspot

@SeanPearceSQL

About Me
Post #1463575
Posted Saturday, June 15, 2013 9:51 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Saturday, September 27, 2014 8:18 AM
Points: 32, Visits: 104

Hi,

Thank you very much.It works fine.
Post #1463925
Posted Sunday, June 16, 2013 12:08 PM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 7:43 AM
Points: 40,438, Visits: 36,894
To be honest, dates shouldn't be stored in formats. They should be stored as a datetime data type and formatted when selected or in the application.


Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1463972
Posted Monday, June 24, 2013 6:29 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 8:51 PM
Points: 35,606, Visits: 32,190
+1000 to that. That's why the script I wrote converted everything to DATETIME.

--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1466958
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse