Convert Date

  • Hi Guys,
    Is there a way to convert the Datein in the below to show this format MMM DD YYYY

    Thanks

    SELECT DateIn
    ,Booking
    ,RegNo
    ,CustName
    ,Model
    ,ServText
    ,Phone
    ,Team
    ,Facilities
    --,TimeIn
    --,TimeOut
    , CONCAT(TIMEIN, '-' , TIMEOUT) as [In-Out]
    ,TimeOut - TimeIn AS Hrs
    --,DateReg
    FROM Bookings
    WHERE DATEIN >= GETDATE()+6 AND DATEIN < GETDATE()+7
    AND DEALER = 'BA'
    --AND SERVTEXT NOT LIKE '%DIAG%'
    --AND Facilities LIKE '%WAIT%'
    --AND DateReg >= DATEADD(month, 12, getdate())
    ORDER BY DateReg

  • What tool will actually run the query?   You don't have to do anything at all in your query if you use a reporting tool.   You can just format the value in the reporting tool.   However, if you have no such tool, you can use the FORMAT function.   Just be aware that it will slow down your query., and potentially seriously.   Look up the syntax online for it.

    Steve (aka sgmunson) 🙂 🙂 🙂
    Rent Servers for Income (picks and shovels strategy)

  • craig.jenkins - Friday, September 21, 2018 6:53 AM

    Hi Guys,
    Is there a way to convert the Datein in the below to show this format MMM DD YYYY

    Thanks

    SELECT DateIn
    ,Booking
    ,RegNo
    ,CustName
    ,Model
    ,ServText
    ,Phone
    ,Team
    ,Facilities
    --,TimeIn
    --,TimeOut
    , CONCAT(TIMEIN, '-' , TIMEOUT) as [In-Out]
    ,TimeOut - TimeIn AS Hrs
    --,DateReg
    FROM Bookings
    WHERE DATEIN >= GETDATE()+6 AND DATEIN < GETDATE()+7
    AND DEALER = 'BA'
    --AND SERVTEXT NOT LIKE '%DIAG%'
    --AND Facilities LIKE '%WAIT%'
    --AND DateReg >= DATEADD(month, 12, getdate())
    ORDER BY DateReg

    FORMAT(DateIn,N'MMM dd yyyy')

  • You could try this:
    CONVERT(CHAR(11), DateIn, 107) AS DateIn

    -------------------------------------------------------------
    we travel not to escape life but for life not to escape us
    Don't fear failure, fear regret.

  • below86 - Friday, September 21, 2018 7:50 AM

    You could try this:
    CONVERT(CHAR(11), DateIn, 107) AS DateIn

    That's nearly there but it also adds a comma e.g."Sep 21, 2018"

  • Thanks guys much appreciated FORMAT(DateIn,N'MMM dd yyyy') works a treat

  • Jonathan AC Roberts - Friday, September 21, 2018 7:06 AM

    craig.jenkins - Friday, September 21, 2018 6:53 AM

    Hi Guys,
    Is there a way to convert the Datein in the below to show this format MMM DD YYYY

    Thanks

    SELECT DateIn
    ,Booking
    ,RegNo
    ,CustName
    ,Model
    ,ServText
    ,Phone
    ,Team
    ,Facilities
    --,TimeIn
    --,TimeOut
    , CONCAT(TIMEIN, '-' , TIMEOUT) as [In-Out]
    ,TimeOut - TimeIn AS Hrs
    --,DateReg
    FROM Bookings
    WHERE DATEIN >= GETDATE()+6 AND DATEIN < GETDATE()+7
    AND DEALER = 'BA'
    --AND SERVTEXT NOT LIKE '%DIAG%'
    --AND Facilities LIKE '%WAIT%'
    --AND DateReg >= DATEADD(month, 12, getdate())
    ORDER BY DateReg

    FORMAT(DateIn,N'MMM dd yyyy')

    craig.jenkins - Friday, September 21, 2018 8:18 AM

    Thanks guys much appreciated FORMAT(DateIn,N'MMM dd yyyy') works a treat

    Just a suggestion.... avoid the use of FORMAT.  While it's incredibly easy to use, it's 44 times slower than CONVERT and many other methods.

    --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)

  • below86 - Friday, September 21, 2018 7:50 AM

    You could try this:
    CONVERT(CHAR(11), DateIn, 107) AS DateIn

    107 is going to have a comma in it.  I believe you meant 109.  100 would also work.

    --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)

  • Jeff Moden - Friday, September 21, 2018 8:41 AM

    Jonathan AC Roberts - Friday, September 21, 2018 7:06 AM

    craig.jenkins - Friday, September 21, 2018 6:53 AM

    Hi Guys,
    Is there a way to convert the Datein in the below to show this format MMM DD YYYY

    Thanks

    SELECT DateIn
    ,Booking
    ,RegNo
    ,CustName
    ,Model
    ,ServText
    ,Phone
    ,Team
    ,Facilities
    --,TimeIn
    --,TimeOut
    , CONCAT(TIMEIN, '-' , TIMEOUT) as [In-Out]
    ,TimeOut - TimeIn AS Hrs
    --,DateReg
    FROM Bookings
    WHERE DATEIN >= GETDATE()+6 AND DATEIN < GETDATE()+7
    AND DEALER = 'BA'
    --AND SERVTEXT NOT LIKE '%DIAG%'
    --AND Facilities LIKE '%WAIT%'
    --AND DateReg >= DATEADD(month, 12, getdate())
    ORDER BY DateReg

    FORMAT(DateIn,N'MMM dd yyyy')

    craig.jenkins - Friday, September 21, 2018 8:18 AM

    Thanks guys much appreciated FORMAT(DateIn,N'MMM dd yyyy') works a treat

    Just a suggestion.... avoid the use of FORMAT.  While it's incredibly easy to use, it's 44 times slower than CONVERT and many other methods.

    Yes, it's much slower I just did a 1 million row test:
    CONVERT(CHAR(10), datestamp, 100)
    CPU time = 515 ms, elapsed time = 516 ms.

    FORMAT(datestamp,N'MMM dd yyyy')
    CPU time = 13868 ms, elapsed time = 14928 ms.
    And 234 ms of both is taken with other parts of the query. So on my machine it's 53 times slower.

  • Jonathan AC Roberts - Friday, September 21, 2018 9:04 AM

    Jeff Moden - Friday, September 21, 2018 8:41 AM

    Jonathan AC Roberts - Friday, September 21, 2018 7:06 AM

    craig.jenkins - Friday, September 21, 2018 6:53 AM

    Hi Guys,
    Is there a way to convert the Datein in the below to show this format MMM DD YYYY

    Thanks

    SELECT DateIn
    ,Booking
    ,RegNo
    ,CustName
    ,Model
    ,ServText
    ,Phone
    ,Team
    ,Facilities
    --,TimeIn
    --,TimeOut
    , CONCAT(TIMEIN, '-' , TIMEOUT) as [In-Out]
    ,TimeOut - TimeIn AS Hrs
    --,DateReg
    FROM Bookings
    WHERE DATEIN >= GETDATE()+6 AND DATEIN < GETDATE()+7
    AND DEALER = 'BA'
    --AND SERVTEXT NOT LIKE '%DIAG%'
    --AND Facilities LIKE '%WAIT%'
    --AND DateReg >= DATEADD(month, 12, getdate())
    ORDER BY DateReg

    FORMAT(DateIn,N'MMM dd yyyy')

    craig.jenkins - Friday, September 21, 2018 8:18 AM

    Thanks guys much appreciated FORMAT(DateIn,N'MMM dd yyyy') works a treat

    Just a suggestion.... avoid the use of FORMAT.  While it's incredibly easy to use, it's 44 times slower than CONVERT and many other methods.

    Yes, it's much slower I just did a 1 million row test:
    CONVERT(CHAR(10), datestamp, 100)
    CPU time = 515 ms, elapsed time = 516 ms.

    FORMAT(datestamp,N'MMM dd yyyy')
    CPU time = 13868 ms, elapsed time = 14928 ms.
    And 234 ms of both is taken with other parts of the query. So on my machine it's 53 times slower.

    Thanks for that.  I believe, however , the your first test needs a minor correction "MMM DD YYYY" occupies 11 characters and so the CHAR(10) should be CHAR(11).  It won't make much difference in the timing, though.

    --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)

  • You need char(11).
    select convert(char(11), getdate(), 100) as DefaultDateFormat;
    See https://docs.microsoft.com/en-us/sql/t-sql/functions/cast-and-convert-transact-sql

  • craig.jenkins - Friday, September 21, 2018 8:18 AM

    Thanks guys much appreciated FORMAT(DateIn,N'MMM dd yyyy') works a treat

    If you find this to be too slow (I have heard that FORMAT is a dog), you could go to this: REPLACE(CONVERT(CHAR(11), DateIn, 107),',','') AS DateIn

  • Jeff Moden - Friday, September 21, 2018 9:22 AM

    Jonathan AC Roberts - Friday, September 21, 2018 9:04 AM

    Jeff Moden - Friday, September 21, 2018 8:41 AM

    Jonathan AC Roberts - Friday, September 21, 2018 7:06 AM

    craig.jenkins - Friday, September 21, 2018 6:53 AM

    Hi Guys,
    Is there a way to convert the Datein in the below to show this format MMM DD YYYY

    Thanks

    SELECT DateIn
    ,Booking
    ,RegNo
    ,CustName
    ,Model
    ,ServText
    ,Phone
    ,Team
    ,Facilities
    --,TimeIn
    --,TimeOut
    , CONCAT(TIMEIN, '-' , TIMEOUT) as [In-Out]
    ,TimeOut - TimeIn AS Hrs
    --,DateReg
    FROM Bookings
    WHERE DATEIN >= GETDATE()+6 AND DATEIN < GETDATE()+7
    AND DEALER = 'BA'
    --AND SERVTEXT NOT LIKE '%DIAG%'
    --AND Facilities LIKE '%WAIT%'
    --AND DateReg >= DATEADD(month, 12, getdate())
    ORDER BY DateReg

    FORMAT(DateIn,N'MMM dd yyyy')

    craig.jenkins - Friday, September 21, 2018 8:18 AM

    Thanks guys much appreciated FORMAT(DateIn,N'MMM dd yyyy') works a treat

    Just a suggestion.... avoid the use of FORMAT.  While it's incredibly easy to use, it's 44 times slower than CONVERT and many other methods.

    Yes, it's much slower I just did a 1 million row test:
    CONVERT(CHAR(10), datestamp, 100)
    CPU time = 515 ms, elapsed time = 516 ms.

    FORMAT(datestamp,N'MMM dd yyyy')
    CPU time = 13868 ms, elapsed time = 14928 ms.
    And 234 ms of both is taken with other parts of the query. So on my machine it's 53 times slower.

    Thanks for that.  I believe, however , the your first test needs a minor correction "MMM DD YYYY" occupies 11 characters and so the CHAR(10) should be CHAR(11).  It won't make much difference in the timing, though.

    It didn't make much difference. Probably slowed it down a tiny bit so it's about 44 times slower now.😉

  • Lynn Pettis - Friday, September 21, 2018 9:42 AM

    craig.jenkins - Friday, September 21, 2018 8:18 AM

    Thanks guys much appreciated FORMAT(DateIn,N'MMM dd yyyy') works a treat

    If you find this to be too slow (I have heard that FORMAT is a dog), you could go to this: REPLACE(CONVERT(CHAR(11), DateIn, 107),',','') AS DateIn

    Or just CONVERT(CHAR(11),DateIn,100)

    --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)

  • Jeff Moden - Friday, September 21, 2018 10:06 PM

    Lynn Pettis - Friday, September 21, 2018 9:42 AM

    craig.jenkins - Friday, September 21, 2018 8:18 AM

    Thanks guys much appreciated FORMAT(DateIn,N'MMM dd yyyy') works a treat

    If you find this to be too slow (I have heard that FORMAT is a dog), you could go to this: REPLACE(CONVERT(CHAR(11), DateIn, 107),',','') AS DateIn

    Or just CONVERT(CHAR(11),DateIn,100)

    That would be better, didn't read the OP carefully enough, made a bad assumption that you would want the comma.  Thanks for the info on the FORMAT as well, didn't know that, but then I rarely ever need to use it.

    -------------------------------------------------------------
    we travel not to escape life but for life not to escape us
    Don't fear failure, fear regret.

Viewing 15 posts - 1 through 14 (of 14 total)

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