SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


How to format the data in column in sql server


How to format the data in column in sql server

Author
Message
SriSudha
SriSudha
SSC-Enthusiastic
SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)

Group: General Forum Members
Points: 107 Visits: 114
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
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)

Group: General Forum Members
Points: 213433 Visits: 41977
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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
SriSudha
SriSudha
SSC-Enthusiastic
SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)

Group: General Forum Members
Points: 107 Visits: 114
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.
Kingston Dhasian
Kingston Dhasian
SSCertifiable
SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)

Group: General Forum Members
Points: 5996 Visits: 5280
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/
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)

Group: General Forum Members
Points: 213433 Visits: 41977
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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Sean Pearce
Sean Pearce
SSCarpal Tunnel
SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)

Group: General Forum Members
Points: 4024 Visits: 3436
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 :-D



The SQL Guy @ blogspot

@SeanPearceSQL

About Me
SriSudha
SriSudha
SSC-Enthusiastic
SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)

Group: General Forum Members
Points: 107 Visits: 114
Hi,

Thank you very much.It works fine.
GilaMonster
GilaMonster
SSC Guru
SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)

Group: General Forum Members
Points: 222559 Visits: 46291
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, MVP, M.Sc (Comp Sci)
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


Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)

Group: General Forum Members
Points: 213433 Visits: 41977
+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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
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