SQL Agent Date & Time  

Home
Up
What's New
DTS
SQL-DMO
SQL-NS
XP's
Misc. Tools
Events
FAQ
Links
About...

 

SQL Agent Date and Time Handling

version: 1.0.0.1

last updated: 22 November 2002

SQL Agent uses two ways to represent date and time information. In some cases it uses the SQL Server datatime data type, but in most occasions it uses two integers to represent the date and time separately. The format of the date and time integers are very straight forward, the date is formatted as YYYYMMDD and the time is formatted as HHMMSS. Everywhere where schedule information is represented the date and time are stored using integers.

The problem is that you need to convert the integer representation to a datetime, before you can leverage the existing datetime manipulation functions in SQL Server. This article provides helper functions to convert between the two representations. In total there are five user defined functions.

Name Description
fn_AgentDate2DateTime Converts an SQL Agent integer date representation in to a SQL Server datetime datatype, since the time is not specified, the time is always 00:00:00.000
fn_AgentTime2DateTime Converts an SQL Agent integer time representation in to a SQL Server datetime datatype, since the date is not specified, the date is always 1900-01-01
fn_AgentDateTime2DateTime Converts an SQL Agent integer date and time representation in to a SQL Server datetime datatype
fn_DateTime2AgentDate Converts a SQL Server datetime into an SQL Agent integer date representation
fn_DateTime2AgentTime Converts a SQL Server datetime into an SQL Agent integer time representation

Below follows the source code for the five user defined functions:

create function [dbo].[fn_AgentDate2DateTime] (@agentdate int)
returns
datetime
as
begin
   
declare @date datetime,
            @year
int,
            @month
int,
            @day
int,
            @datestr nvarchar(40)

   
select @year = (@agentdate / 10000)
   
select @month = (@agentdate - (@year * 10000)) / 100
   
select @day = (@agentdate - (@year * 10000) - (@month * 100))

   
select @datestr = convert(nvarchar(4), @year) + N'-' +
                      convert
(nvarchar(2), @month) + N'-' +
                      convert
(nvarchar(4), @day)

   
select @date = convert(datetime, @datestr)
   
   
return @date
end
go

-- example
select [dbo].[fn_AgentDate2DateTime](20020430)
go

create function [dbo].[fn_AgentTime2DateTime](@agenttime int)
returns
datetime
as
begin
   
declare @date datetime,
            @hour
int,
            @min
int,
            @sec
int,
            @datestr nvarchar(40)

   
select @hour = (@agenttime / 10000)
   
select @min = (@agenttime - (@hour * 10000)) / 100
   
select @sec = (@agenttime - (@hour * 10000) - (@min * 100))

   
select @datestr = replace(convert(nvarchar(2), @hour) + N':' +
                             
convert(nvarchar(2), @min) + N':' +
                              convert
(nvarchar
(2), @sec), ' ', '0')

   
select @date = convert(datetime, @datestr)

   
return @date
end
go

-- example

select
[dbo].[fn_AgentTime2DateTime] (110015)
go

create function [dbo].[fn_AgentDateTime2DateTime] (@agentdate int, @agenttime int)
returns
datetime
as
begin
   
declare @date datetime,
            @year
int,
            @month
int,
            @day
int,
            @hour
int,
            @min
int,
            @sec
int,
            @datestr nvarchar(40)

   
select @year = (@agentdate / 10000)
   
select @month = (@agentdate - (@year * 10000)) / 100
   
select @day = (@agentdate - (@year * 10000) - (@month * 100))

   
select @hour = (@agenttime / 10000)
   
select @min = (@agenttime - (@hour * 10000)) / 100
   
select @sec = (@agenttime - (@hour * 10000) - (@min * 100))

   
select @datestr = convert(nvarchar(4), @year) + N'-' +
                      convert
(nvarchar(2), @month) + N'-' +
                      convert
(nvarchar(4), @day) + N' ' +
                      replace(
convert(nchar(2), @hour) + N':' +
                              convert
(nchar(2), @min) + N':' +
                              convert
(nchar
(2), @sec), ' ', '0')

   
select @date = convert(datetime, @datestr)

   
return @date
end
go

-- example
select [dbo].[fn_AgentDateTime2DateTime] (20020222, 110015)
go

create function [dbo].[fn_DateTime2AgentDate] (@date datetime)
returns
int
as
begin
   
declare @dateint int

   
select @dateint = (datepart(year, @date) * 10000) +
                      (
datepart(month, @date) * 100) +
                      (
datepart(day, @date))

   
return @dateint
end
go

-- example
select
[dbo].[fn_DateTime2AgentDate] (getdate())
go

create function [dbo].[fn_DateTime2AgentTime] (@date datetime)
returns
int
as
begin
    declare @timeint int

   
select @timeint = (datepart(hour, @date) * 10000) +
                      (
datepart(minute, @date) * 100) +
                      (
datepart(second, @date))

   
return @timeint
end
go

-- example
select [dbo].[fn_DateTime2AgentTime] (getdate())
go

Download agent_datetime_functions.sql

The following tables use the alternative date and time representation:

Table Columns
msdb.dbo.sysalerts last_occurrence_date
last_occurrence_time
last_response_date
last_response_time
count_reset_date
count_reset_time
msdb.dbo.sysjobhistory run_date
run_time
msdb.dbo.sysjobschedules active_start_date
active_start_time
active_end_date
active_end_time
next_run_date
next_run_time
msdb.dbo.sysjobservers last_run_date
last_run_time
msdb.dbo.sysjobsteps last_run_date
last_run_time
msdb.dbo.sysoperators last_email_date
last_email_time
last_pager_date
last_pager_time
last_netsend_date
last_netsend_time
weekday_pager_start_time
weekday_pager_end_time
saturday_pager_start_time
saturday_pager_end_time
sunday_pager_start_time
sunday_pager_end_time

***

Questions or problems regarding this web site should be directed to webmaster@sqldev.net.
Copyright © 1991-2003 SQLDev.Net. All rights reserved.
Last modified: 07/06/03.