How to format the data in column in sql server

  • 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

  • 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.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • 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.

  • 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'

    SELECTCASE

    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/

  • 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.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • 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[/url]

    @SeanPearceSQL

    About Me[/url]

  • Hi,

    Thank you very much.It works fine.

  • 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
  • +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.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 9 posts - 1 through 8 (of 8 total)

You must be logged in to reply to this topic. Login to reply