Help needed in converting an int datatype to MM/DD/YYYY and converting another int to HH:MM PM

  • When running the script below I noticed that the two result fields are of datatype int.

    I would like to convert the value of the next_run_date to the format of MM/DD/YYYY and the value of next_run_time to the format of HH:MM AM or PM.

    I have used

    convert(DATE, CAST(dbo.sysjobschedules.next_run_date AS CHAR(12)), 103) AS Next_Run_Date,

    in the script below but no matter what the value of the format (Ex: 100, 101, 102, or 103) I get the result of YYYY-MM-DD.

    -- List Next Run Date And Time For All Jobs.

    USE msdb

    SELECT

    sysjobs.name ,

    dbo.sysjobschedules.next_run_date ,

    dbo.sysjobschedules.next_run_time

    FROM dbo.sysjobs

    INNER JOIN dbo.sysjobschedules ON dbo.sysjobs.job_id = dbo.sysjobschedules.job_id

    Order BY dbo.sysjobschedules.next_run_date, dbo.sysjobschedules.next_run_time asc

    The result of the above script is:

    namenext_run_datenext_run_time

    syspolicy_purge_history2012082820000

    Log_Backup20120902175500

    Databases_Backup 20120902180000

    System_Databases_Backup20120902180500

    database integrity check 20120902 181000

    DBCC CheckDB20120902181500

    I have the following script that appears to work correctly in converting an int to standard time format end with am or pm.

    DECLARE @milTime INT

    DECLARE @militaryTime INT

    SET @militaryTime = 20000

    SET @milTime = STUFF(@militaryTime / 100, 1, 0, REPLICATE('0', 6 - LEN(@militaryTime / 100)))

    SELECT CASE ( ( @milTime / 100 ) % 12 )

    WHEN 0 THEN '12'

    ELSE CAST(( @milTime % 1200 ) / 100 AS VARCHAR(2))

    END + ':' + RIGHT('0' + CAST(( @milTime % 100 ) AS VARCHAR(2)), 2)

    + CASE ( @milTime / 1200 )

    WHEN 0 THEN ' am'

    ELSE ' pm'

    END

    The result of the above query is

    (No column name)

    2:00 am

    But when I include it in my original script the time showing am/pm does not apperar correctly.

    SELECT

    sysjobs.name ,

    convert(DATE, CAST(dbo.sysjobschedules.next_run_date AS CHAR(12)), 101) AS Next_Run_Date,

    dbo.sysjobschedules.next_run_time,

    stuff(stuff(Right('0' + cast(dbo.sysjobschedules.next_run_time as varchar(6)),6),3,0,':'),6,0,':'),

    STUFF(dbo.sysjobschedules.next_run_time / 100, 1, 0, REPLICATE('0', 6 - LEN(dbo.sysjobschedules.next_run_time / 100)))

    + CASE ( ( dbo.sysjobschedules.next_run_time / 100 ) % 12 )

    WHEN 0 THEN '12'

    ELSE CAST(( dbo.sysjobschedules.next_run_time % 1200 ) / 100 AS VARCHAR(2))

    END + ':' + RIGHT('0' + CAST(( dbo.sysjobschedules.next_run_time % 100 ) AS VARCHAR(2)), 2)

    + CASE ( dbo.sysjobschedules.next_run_time / 1200 )

    WHEN 0 THEN ' am'

    ELSE ' pm'

    END

    FROM dbo.sysjobs

    INNER JOIN dbo.sysjobschedules ON dbo.sysjobs.job_id = dbo.sysjobschedules.job_id

    Order BY dbo.sysjobschedules.next_run_date, dbo.sysjobschedules.next_run_time ASC

    This is the result from the above query:

    name Next_Run_Datenext_run_time(No column name)(No column name)

    syspolicy_purge_history2012-08-282000002:00:00 0002008:00 pm

    Log_Backup.Subplan_12012-09-0217550017:55:00 0017553:00 pm

    Databases_Backup.Subplan_12012-09-0218000018:00:00 00180012:00 pm

    System_Databases_Backup2012-09-0218050018:05:00 0018055:00 pm

    database integrity check 2012-09-02181000 18:10:00 00181010:00 pm

    DBCC CheckDB 2012-09-0218150018:15:00 0018153:00 pm

    Any help will be greatly appreciated. I hope that I have not made this too confusing.

    Thanks

    Howard

  • if you convert to CHAR(12), most of the string gets truncated no matter the format.

    try a CHAR(37) instead.

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • Lowell:

    Thank you for the fast reply.

    The only Char(12) that I see is on the following line in the script.

    convert(DATE, CAST(dbo.sysjobschedules.next_run_date AS CHAR(12)), 101) AS Next_Run_Date,

    I changed this Char(12) to Char(37) and the formatting of the next_run_date did not change.

    Also, this won't help me formatting the next_run_time.

    Would you please clarify what you mean?

    Thank you,

    Howard

  • ok, this gets you your value as datetime, right? i guess you could manipulate it a bit more if you really wanted AMPM in it, but i would want the datetime value myself.

    /*

    --Results

    name NextRunDate

    syspolicy_purge_history 2012-08-28 02:00:00.000

    Email Reminders 2012-08-28 07:00:00.000

    Last EDI Exported Status 2012-09-02 09:00:00.000

    */

    SELECT

    sysjobs.name ,

    CONVERT(datetime,

    STUFF(STUFF(CONVERT(VARCHAR,dbo.sysjobschedules.next_run_date),7,0,'-'),5,0,'-')

    + ' '

    + stuff(stuff(Right('0' + cast(dbo.sysjobschedules.next_run_time as varchar(6)),6),3,0,':'),6,0,':')

    ) AS NextRunDate

    FROM dbo.sysjobs

    INNER JOIN dbo.sysjobschedules ON dbo.sysjobs.job_id = dbo.sysjobschedules.job_id

    Order BY dbo.sysjobschedules.next_run_date, dbo.sysjobschedules.next_run_time ASC

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • When you return a date (or datetime, etc.) datatype in a query in Management Studio, the format you get is YYYY-MM-DD. Has nothing to do with how the data is stored, has to do with how SSMS displays it. That's a presentation layer issue.

    If you want to convert to Date datatype in the query, then you'll get YYYY-MM-DD in Management Studio, no matter what format you specify in the conversion from character data.

    Unless the end users will be using SSMS as their application (doubtful), this doesn't actually matter, since their actual application can apply formatting in the presentation layer, where it belongs.

    If you need it to be formatted in SSMS, then convert it to a string (varchar) and use the appropriate mask in the Convert statement. But make sure the final value is a string, not a Date/DateTime. You won't be able to use any of the T-SQL date-math functions on that, and will have issues with Order By, etc., since it'll be a string, not a date, but that's the tradeoff on that kind of thing.

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

  • Lowell:

    Thank you for the revised script.

    However, I was trying to return the two separate columns.

    The next_run_date as MM/DD/YYYY

    and the next_run_time as HH:MM AM/PM.

    GSuared:

    Thank you for the explanation.

    Howard

  • I finally figured out the solution.

    -- List Jobs Next Run Date and Time.

    -- Format Next_Run_Date MMM DD, YYYY and Next_Run_Time HH:MM AM/PM.

    SELECT

    sysjobs.name ,

    CONVERT( varchar,cast(cast(dbo.sysjobschedules.next_run_date as char(8)) as date),107) AS NextRunDate,

    CASE WHEN dbo.sysjobschedules.next_run_time < 120000

    THEN ISNULL(LEFT(CONVERT(VARCHAR, CONVERT(DECIMAL, dbo.sysjobschedules.next_run_time)

    / 10000), 4) + ' AM', 'None')

    ELSE ISNULL(LEFT(CONVERT(VARCHAR, CONVERT(DECIMAL, dbo.sysjobschedules.next_run_time)

    / 10000 - 12), 4) + ' PM', 'None')

    END JOB_start_time

    FROM dbo.sysjobs

    INNER JOIN dbo.sysjobschedules ON dbo.sysjobs.job_id = dbo.sysjobschedules.job_id

    Order BY dbo.sysjobschedules.next_run_date, dbo.sysjobschedules.next_run_time ASC

    Thanks to everyone for their help.

    Howard

  • CELKO (8/29/2012)


    >> When running the script below I noticed that the two result fields [sic: columns are not fields] are of data type INTEGER. I would like to convert the value of the next_run_date to the format of MM/DD/YYYY and the value of next_run_time to the format of HH:MM AM or PM.<<

    Your problem is that you have no idea how RDBMS and SQL work. We have abstract data type in SQL; how they are stored in the databases has nothing whatsoever to do with how they are displayed in the presentation layers.

    Furthermore, the only display format allowed in ANSI/ISO Standard is 'YYYY-MM-DD HH:MM:SS.SSS', not the local dialect you think you should have. That was how COBOL worked in the 1950's when there were no temporal data types. All temporal stuff has to be done with procedural code and strings. Just like you are doing now! You also used context sensitive COBOL field names instead of ISO-11179 data element names.

    We have a timestamps data type, which MS calls DATETIME2(n), so you should not split out the DATE and TIME fields (yes, this is the only place ANSI used 'field'; parts of temporal values).

    These are huge conceptual error and not a little mistake. Let's make guesses and see if we can re-write this pseudo-COBOL to SQL.

    SELECT J.name, JS.run_timestamp

    FROM DBO.SysJobSchedules AS JS, DBO.SysJobs AS J

    WHERE J.job_id = JS.job_id;

    >> I have the following script that appears to work correctly in converting an INTEGER to standard time format end with am or pm. <<

    This is a stinking kludge and should not exist. Standard time does not have the old AM/PM. This will improve the quality of data in your enterprise by orders of magnitude.

    Now, create two look up tables, load the dates with 50, 10 or whatever years, load the times with a full day. Do the look ups and then add the date and time together.

    Create TABLE Stupid_Integer_Dates

    (cal_date DATE NOT NULL,

    int_date INTEGER NOT NULL PRIMARY KEY);

    Create TABLE Stupid_Integer_Times

    (cal_time TIME NOT NULL,

    int_time INTEGER NOT NULL PRIMARY KEY);

    Finally, find the moron that put a timestamp in integers and kill him. I suggest burning him at the stake with his COBOL manuals 🙂

    Chill on the threats and name calling please. And the smiley at the end doesn't change the lack of professionalism demonstrated.

  • CELKO (8/29/2012)


    >> When running the script below I noticed that the two result fields [sic: columns are not fields] are of data type INTEGER. I would like to convert the value of the next_run_date to the format of MM/DD/YYYY and the value of next_run_time to the format of HH:MM AM or PM.<<

    Your problem is that you have no idea how RDBMS and SQL work. We have abstract data type in SQL; how they are stored in the databases has nothing whatsoever to do with how they are displayed in the presentation layers.

    Furthermore, the only display format allowed in ANSI/ISO Standard is 'YYYY-MM-DD HH:MM:SS.SSS', not the local dialect you think you should have. That was how COBOL worked in the 1950's when there were no temporal data types. All temporal stuff has to be done with procedural code and strings. Just like you are doing now! You also used context sensitive COBOL field names instead of ISO-11179 data element names.

    We have a timestamps data type, which MS calls DATETIME2(n), so you should not split out the DATE and TIME fields (yes, this is the only place ANSI used 'field'; parts of temporal values).

    These are huge conceptual error and not a little mistake. Let's make guesses and see if we can re-write this pseudo-COBOL to SQL.

    SELECT J.name, JS.run_timestamp

    FROM DBO.SysJobSchedules AS JS, DBO.SysJobs AS J

    WHERE J.job_id = JS.job_id;

    >> I have the following script that appears to work correctly in converting an INTEGER to standard time format end with am or pm. <<

    This is a stinking kludge and should not exist. Standard time does not have the old AM/PM. This will improve the quality of data in your enterprise by orders of magnitude.

    Now, create two look up tables, load the dates with 50, 10 or whatever years, load the times with a full day. Do the look ups and then add the date and time together.

    Create TABLE Stupid_Integer_Dates

    (cal_date DATE NOT NULL,

    int_date INTEGER NOT NULL PRIMARY KEY);

    Create TABLE Stupid_Integer_Times

    (cal_time TIME NOT NULL,

    int_time INTEGER NOT NULL PRIMARY KEY);

    Finally, find the moron that put a timestamp in integers and kill him. I suggest burning him at the stake with his COBOL manuals 🙂

    These tables are built in MSDB and are populated by SQL Server agent. I would bet you anything this has been around and setup this way as long as SQL Server has had an agent available.

    No matter how much we want to follow standards, there are just times when you have to deal with stupidity and get over it. Ranting on the OP in this case is useless - since he has no choice and no way to make any of the changes you recommend.

    Jeffrey Williams
    “We are all faced with a series of great opportunities brilliantly disguised as impossible situations.”

    ― Charles R. Swindoll

    How to post questions to get better answers faster
    Managing Transaction Logs

  • hmbtx (8/27/2012)


    When running the script below I noticed that the two result fields are of datatype int.

    I would like to convert the value of the next_run_date to the format of MM/DD/YYYY and the value of next_run_time to the format of HH:MM AM or PM.

    I have used

    convert(DATE, CAST(dbo.sysjobschedules.next_run_date AS CHAR(12)), 103) AS Next_Run_Date,

    in the script below but no matter what the value of the format (Ex: 100, 101, 102, or 103) I get the result of YYYY-MM-DD.

    -- List Next Run Date And Time For All Jobs.

    USE msdb

    SELECT

    sysjobs.name ,

    dbo.sysjobschedules.next_run_date ,

    dbo.sysjobschedules.next_run_time

    FROM dbo.sysjobs

    INNER JOIN dbo.sysjobschedules ON dbo.sysjobs.job_id = dbo.sysjobschedules.job_id

    Order BY dbo.sysjobschedules.next_run_date, dbo.sysjobschedules.next_run_time asc

    The result of the above script is:

    namenext_run_datenext_run_time

    syspolicy_purge_history2012082820000

    Log_Backup20120902175500

    Databases_Backup 20120902180000

    System_Databases_Backup20120902180500

    database integrity check 20120902 181000

    DBCC CheckDB20120902181500

    I have the following script that appears to work correctly in converting an int to standard time format end with am or pm.

    DECLARE @milTime INT

    DECLARE @militaryTime INT

    SET @militaryTime = 20000

    SET @milTime = STUFF(@militaryTime / 100, 1, 0, REPLICATE('0', 6 - LEN(@militaryTime / 100)))

    SELECT CASE ( ( @milTime / 100 ) % 12 )

    WHEN 0 THEN '12'

    ELSE CAST(( @milTime % 1200 ) / 100 AS VARCHAR(2))

    END + ':' + RIGHT('0' + CAST(( @milTime % 100 ) AS VARCHAR(2)), 2)

    + CASE ( @milTime / 1200 )

    WHEN 0 THEN ' am'

    ELSE ' pm'

    END

    The result of the above query is

    (No column name)

    2:00 am

    But when I include it in my original script the time showing am/pm does not apperar correctly.

    SELECT

    sysjobs.name ,

    convert(DATE, CAST(dbo.sysjobschedules.next_run_date AS CHAR(12)), 101) AS Next_Run_Date,

    dbo.sysjobschedules.next_run_time,

    stuff(stuff(Right('0' + cast(dbo.sysjobschedules.next_run_time as varchar(6)),6),3,0,':'),6,0,':'),

    STUFF(dbo.sysjobschedules.next_run_time / 100, 1, 0, REPLICATE('0', 6 - LEN(dbo.sysjobschedules.next_run_time / 100)))

    + CASE ( ( dbo.sysjobschedules.next_run_time / 100 ) % 12 )

    WHEN 0 THEN '12'

    ELSE CAST(( dbo.sysjobschedules.next_run_time % 1200 ) / 100 AS VARCHAR(2))

    END + ':' + RIGHT('0' + CAST(( dbo.sysjobschedules.next_run_time % 100 ) AS VARCHAR(2)), 2)

    + CASE ( dbo.sysjobschedules.next_run_time / 1200 )

    WHEN 0 THEN ' am'

    ELSE ' pm'

    END

    FROM dbo.sysjobs

    INNER JOIN dbo.sysjobschedules ON dbo.sysjobs.job_id = dbo.sysjobschedules.job_id

    Order BY dbo.sysjobschedules.next_run_date, dbo.sysjobschedules.next_run_time ASC

    This is the result from the above query:

    name Next_Run_Datenext_run_time(No column name)(No column name)

    syspolicy_purge_history2012-08-282000002:00:00 0002008:00 pm

    Log_Backup.Subplan_12012-09-0217550017:55:00 0017553:00 pm

    Databases_Backup.Subplan_12012-09-0218000018:00:00 00180012:00 pm

    System_Databases_Backup2012-09-0218050018:05:00 0018055:00 pm

    database integrity check 2012-09-02181000 18:10:00 00181010:00 pm

    DBCC CheckDB 2012-09-0218150018:15:00 0018153:00 pm

    Any help will be greatly appreciated. I hope that I have not made this too confusing.

    Thanks

    Howard

    The following should make your life a bit easier. Format the output anyway you like using CONVERT. As usual, the details are in the code comments. I believe you find some good utility in the usage example

    CREATE FUNCTION dbo.ConvertIntegerDateTime

    /****************************************************************************************

    Purpose:

    Create a DATETIME datatype return from an Integer Date and an Integer Time.

    Note that the DATETIME is NOT formatted in any way. That should be left up to either

    the GUI or the reporting tool instead of being done in this function.

    Example Usage:

    SELECT NextRunDateTime = dt.FullDateTime

    FROM msdb.dbo.sysjobschedules sched

    CROSS APPLY dbo.ConvertIntegerDateTime(sched.next_run_date, sched.next_run_time) dt

    ;

    -- Jeff Moden

    ****************************************************************************************/

    (

    @pIntegerDate INT,

    @pIntegerTime INT

    )

    RETURNS TABLE WITH SCHEMABINDING AS

    RETURN

    SELECT FullDateTime =

    DATEADD(mm, (@pIntegerDate/10000-1900)*12 --Years converted to months

    + (@pIntegerDate/100)%100-1 --Months

    , @pIntegerDate%100-1) --Days

    + DATEADD(ss, @pIntegerTime/10000*3600 --Hours converted to seconds

    + @pIntegerTime/100%100*60 --Minutes converted to seconds

    + @pIntegerTime%100 --Seconds

    , 0)

    ;

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

  • I would like to thank Lynn, Jeffrey, and Jeff for their responses.

    Howard

  • CELKO (8/29/2012)


    Now, create two look up tables, load the dates with 50, 10 or whatever years, load the times with a full day. Do the look ups and then add the date and time together.

    Create TABLE Stupid_Integer_Dates

    (cal_date DATE NOT NULL,

    int_date INTEGER NOT NULL PRIMARY KEY);

    Create TABLE Stupid_Integer_Times

    (cal_time TIME NOT NULL,

    int_time INTEGER NOT NULL PRIMARY KEY);

    Gosh, Joe... Even when you're right you sound snotty to people. And, you didn't demonstrate how to actually populate these tables. If the OP is having a hard time taking an integer date/time apart, what makes you think they'll know how to built one?

    Heh.. and yeah... the others are correct. The OP didn't design these tables... they're actually system tables located in the MSDB.

    --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 12 posts - 1 through 11 (of 11 total)

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