how to combine and convert two integer columns to datetime

  • I have date stored in a column as integer type and time stored in a column as integer type. How do I combine and convert both columns into datetime type?

    For Example: Col A has 20130314 (yyyymmdd) and Col B has 123000 (hhmmss). My Output should be 2013-03-14 12:30:00

    Thanks,
    Naveen.
    Every thought is a cause and every condition an effect

  • naveen.pasupuleti (3/15/2013)


    I have date stored in a column as integer type and time stored in a column as integer type. How do I combine and convert both columns into datetime type?

    For Example: Col A has 20130314 (yyyymmdd) and Col B has 123000 (hhmmss). My Output should be 2013-03-14 12:30:00

    Something like this:

    declare @TestDate int = 20130314,

    @TestTIme int = 123000;

    select cast(cast(@TestDate as varchar(8)) as datetime),

    cast(stuff(stuff(cast(@TestTime as varchar(6)),5,0,':'),3,0,':') as time(0)),

    cast(cast(@TestDate as varchar(8)) as datetime) + cast(stuff(stuff(cast(@TestTime as varchar(6)),5,0,':'),3,0,':') as time(0));

  • Thanks Lynn for your response.

    The code you shared works for this example but sometimes integer time column or col B can have values like 93000 (9.30am) or 0 (12 am). The number of digits vary in the column.

    SELECT last_run_date,last_run_time from msdb.dbo.sysjobservers

    One closest example I can think of is from msdb database. Sysjobservers table has two columns that match exactly my requirement. Last_run_date column is a integer type having date number and Last_run_time is a integer type having time number. How to get datetime out of these two columns.

    Thanks,
    Naveen.
    Every thought is a cause and every condition an effect

  • naveen.pasupuleti (3/15/2013)


    Thanks Lynn for your response.

    The code you shared works for this example but sometimes integer time column or col B can have values like 93000 (9.30am) or 0 (12 am). The number of digits vary in the column.

    SELECT last_run_date,last_run_time from msdb.dbo.sysjobservers

    One closest example I can think of is from msdb database. Sysjobservers table has two columns that match exactly my requirement. Last_run_date column is a integer type having date number and Last_run_time is a integer type having time number. How to get datetime out of these two columns.

    Try this:

    declare @TestDate int = 20130314,

    @TestTIme int = 123000;

    select cast(cast(@TestDate as varchar(8)) as datetime),

    cast(stuff(stuff(cast(@TestTime as varchar(6)),5,0,':'),3,0,':') as time(0)),

    cast(cast(@TestDate as varchar(8)) as datetime) + cast(stuff(stuff(right('000000' + cast(@TestTime as varchar(6)),6),5,0,':'),3,0,':') as time(0));

  • Or, another possibility (with no character conversions/manipulation):

    SELECT

    ColA, ColB,

    DATEADD(SECOND, ColB % 100, DATEADD(MINUTE, ColB % 10000 / 100, DATEADD(HOUR, ColB / 10000,

    DATEADD(DAY, ColA % 100 - 1, DATEADD(MONTH, ColA % 10000 / 100 - 1, DATEADD(YEAR, ColA / 10000 - 1900, 0)))))) AS Col_New

    FROM (

    SELECT 20130314 AS ColA, 123011 AS ColB UNION ALL

    SELECT 20130314, 093015

    ) AS test_data

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

  • Are these SQL Agent date and time values? I used to have my own homegrown functions but I just picked up knowledge of this lttle gem on these forums the other day:

    SELECT msdb.dbo.agent_datetime(20130314, 123000);

    There are no special teachers of virtue, because virtue is taught by the whole community.
    --Plato

  • PS Forgot to mention the function is undocumented so take that into consideration.

    There are no special teachers of virtue, because virtue is taught by the whole community.
    --Plato

  • Thank you very much OPC.Three.

    This builtin function msdb.dbo.agent_datetime did the job for me.

    Thanks,
    Naveen.
    Every thought is a cause and every condition an effect

  • You're welcome. Thanks for the feedback.

    There are no special teachers of virtue, because virtue is taught by the whole community.
    --Plato

  • opc.three (3/15/2013)


    PS Forgot to mention the function is undocumented so take that into consideration.

    It's a cough scalar function too.

    Combine the best bits of Lynn's and Scott's solutions and roll them into an inline TVF:

    CREATE FUNCTION [dbo].[IF_Agent_Datetime]

    (

    @Date INT,

    @Time INT

    )

    RETURNS TABLE WITH SCHEMABINDING AS

    RETURN

    (

    SELECT DatetimeValue =

    DATEADD(SECOND,@Time % 100,

    DATEADD(MINUTE,@Time % 10000 / 100,

    DATEADD(HOUR,@Time/10000,

    CAST(CAST(@Date AS CHAR(8)) AS DATETIME))))

    )

    GO

    SELECT *

    FROM dbo.IF_Agent_Datetime (20130314, 123011)

    2013-03-14 12:30:11.000

    β€œWrite the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • ChrisM@Work (3/18/2013)


    opc.three (3/15/2013)


    PS Forgot to mention the function is undocumented so take that into consideration.

    It's a cough scalar function too.

    Meh. We're talking about SQL Agent data so IMHO it's not something to get in a twist over (or even having a cough over) πŸ˜€

    There are no special teachers of virtue, because virtue is taught by the whole community.
    --Plato

  • opc.three (3/18/2013)


    ChrisM@Work (3/18/2013)


    opc.three (3/15/2013)


    PS Forgot to mention the function is undocumented so take that into consideration.

    It's a cough scalar function too.

    Meh. We're talking about SQL Agent data so IMHO it's not something to get in a twist over (or even having a cough over) πŸ˜€

    Actually, the OP never did say if it was SQL Agent data that he was working with here. It could actually be data in his application database.

  • Lynn Pettis (3/18/2013)


    opc.three (3/18/2013)


    ChrisM@Work (3/18/2013)


    opc.three (3/15/2013)


    PS Forgot to mention the function is undocumented so take that into consideration.

    It's a cough scalar function too.

    Meh. We're talking about SQL Agent data so IMHO it's not something to get in a twist over (or even having a cough over) πŸ˜€

    Actually, the OP never did say if it was SQL Agent data that he was working with here. It could actually be data in his application database.

    Well, gee, I was thinking that was implied given the format of the data and was validated by the fact that the OP latched onto the msdb proc when replying directly to me, but you have a valid point. He could have been talking about data in an application database, or come to think of it, he could also have a shedload of historical data in his SQL Agent history tables but that would likely point to job-history maintenance issue.

    @naveen.pasupuleti, could you tell us if you're applying this to SQL Agent data stored in msdb, or some other type of data source where you could be evaluating a non-trivial number of rows?

    There are no special teachers of virtue, because virtue is taught by the whole community.
    --Plato

  • It is an application database used for reporting purposes, where I need to calculate datetime out of two integer columns (till last week, I calculated only date but new requirement asks for date and time). However, these int columns get data from msdb.dbo.sysjobservers as source table.

    This function msdb.dbo.agent_datetime(@int1, @int2) is helpful for me in both ways:

    1. I applied for my immediate reporting purposes

    2. I added a datetime column in my table, updated column for current data and used this function in SSIS package.

    All solutions are good but built-in function is new learning & quick for me.

    I appreciate each of you for your responses.

    Thanks,

    Naveen.

    Thanks,
    Naveen.
    Every thought is a cause and every condition an effect

  • OK, SQL Agent data, that's good, the use case fits, but you're repurposing it so how much data are we talking about? For managing SQL Agent historical data the scalar-function is fine because the volume is limited (if the instance is configured well) but if we're talking about a non-trivial amount of data you should consider switching to a home-made table-valued function instead. It will scale much better and not use anywhere near as much CPU.

    There are no special teachers of virtue, because virtue is taught by the whole community.
    --Plato

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

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