January 6, 2012 at 1:02 pm
I'm looking at the next_run_time field in sysjobschedules, which is stored as an integer with a presumed format of HHMMSS according to BOL. I'd like to get this to a human-friendly time display of HH:MM:SS. I have code that's working, but it's ugly. Really ugly. I know there's better available but either my search skills are seriously lacking or nobody's sharing and I'm drawing a blank. Since it's an int field, there has to be a way of left padding with 0.
Here's what I have:
SELECT next_run_date ,
next_run_time ,
LEFT(RIGHT('000000' + CAST(next_run_time AS VARCHAR(6)), 6),
2) + ':' + SUBSTRING(RIGHT('000000'
+ CAST(next_run_time AS VARCHAR(6)),
6), 3, 2) + ':'
+ RIGHT(RIGHT('000000' + CAST(next_run_time AS VARCHAR(6)),
6), 2) AS TheTime
FROM msdb.dbo.sysjobschedules AS s
(BTW, this is going into an SSRS report so if there's a way to format it on that end I'm all for it.)
January 6, 2012 at 1:59 pm
I searched on google for "sql server convert sysjobschedules to datetime" and the very first hit has the following function.
create FUNCTION [dbo].[udfGetDateTimeFromInteger]
(
@intDate int,
@intTime int
)
RETURNS datetime
AS BEGIN
-- Declare the return variable here
DECLARE @DT_datetime datetime = NULL,
@str_date varchar(11),
@str_time varchar(8)
if(@intDate is not null and @intDate > 0)
begin
select @str_date = CONVERT(varchar(11),@intDate)
select @str_date = SUBSTRING(@str_date,1,4)+'/'+SUBSTRING(@str_date,5,2)+'/'+SUBSTRING(@str_date,7,2)
if @intTime=0
select @str_time ='000000'
else
select @str_time = right('0'+CONVERT(varchar(11),@intTime),6)
select @str_time = SUBSTRING(@str_time,1,2)+':'+SUBSTRING(@str_time,3,2)+':'+SUBSTRING(@str_time,5,2)
select @DT_datetime = CAST(@str_date+' '+@str_time as datetime)
end
-- Return the result of the function
RETURN @DT_datetime
END
Then to use it to get your time only i did this.
SELECT next_run_date ,
next_run_time ,
convert(varchar, dbo.udfGetDateTimeFromInteger(next_run_date, next_run_time), 108)
FROM msdb.dbo.sysjobschedules AS s
You can either use this function of roll it into your select (which might be a bit tricky). Your method does also work and is probably bit quicker, although unless you have a ton of sql jobs performance really isn't going to be much of a factor here.
--edit-- fat fingers strike again. 😛
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
January 6, 2012 at 2:44 pm
Here is a solution that doesn't use conversion to character string and back again.
select
next_run_date ,
next_run_time ,
NEXT_RUN_DATETIME =
-- convert date
dateadd(dd,((next_run_date)%100)-1,
dateadd(mm,((next_run_date)/100%100)-1,
dateadd(yy,(nullif(next_run_date,0)/10000)-1900,0)))+
-- convert time
dateadd(ss,next_run_time%100,
dateadd(mi,(next_run_time/100)%100,
--dateadd(hh,nullif(next_run_time,0)/10000,0)))
-- Fix for prior line, because a time of 0 is valid
dateadd(hh,@Time/10000,0)))
from
msdb.dbo.sysjobschedules AS s
Results:
next_run_date next_run_time NEXT_RUN_DATETIME
------------- ------------- -----------------------
20120109 131501 2012-01-09 13:15:01.000
20120107 113020 2012-01-07 11:30:20.000
20120109 105000 2012-01-09 10:50:00.000
20120107 20000 2012-01-07 02:00:00.000
20120107 51007 2012-01-07 05:10:07.000
20111221 200000 2011-12-21 20:00:00.000
20120106 170100 2012-01-06 17:01:00.000
20111221 163000 2011-12-21 16:30:00.000
20120110 34000 2012-01-10 03:40:00.000
0 0 NULL
20120106 181500 2012-01-06 18:15:00.000
20120107 500 2012-01-07 00:05:00.000
20120109 20010 2012-01-09 02:00:10.000
20120106 170200 2012-01-06 17:02:00.000
20120106 170000 2012-01-06 17:00:00.000
0 0 NULL
20120107 110007 2012-01-07 11:00:07.000
...
...
Edit to post bug fix.
January 8, 2012 at 5:55 am
There's a system function shipped as part of msdb that turns an integer date and an integer time into a DATETIME. Being undocumented, using it directly isn't be supported (and it might be changed or removed in future with no deprecation cycle). It is unchanged in the latest SQL Server 2012 preview though. Anyway, it's called dbo.agent_datetime, and has the following definition:
CREATE FUNCTION agent_datetime(@date int, @time int)
RETURNS DATETIME
AS
BEGIN
RETURN
(
CONVERT(DATETIME,
CONVERT(NVARCHAR(4),@date / 10000) + N'-' +
CONVERT(NVARCHAR(2),(@date % 10000)/100) + N'-' +
CONVERT(NVARCHAR(2),@date % 100) + N' ' +
CONVERT(NVARCHAR(2),@time / 10000) + N':' +
CONVERT(NVARCHAR(2),(@time % 10000)/100) + N':' +
CONVERT(NVARCHAR(2),@time % 100),
120)
)
END
Paul White
SQLPerformance.com
SQLkiwi blog
@SQL_Kiwi
January 8, 2012 at 10:16 am
Sean Lange (1/6/2012)
I searched on google for "sql server convert sysjobschedules to datetime" and the very first hit has the following function.
Unfortunately, the function fails for certain date time combinations...
select dbo.udfGetDateTimeFromInteger(20121224,2819)
Msg 242, Level 16, State 3, Line 1
The conversion of a char data type to a datetime data type resulted in an out-of-range datetime value.
--Jeff Moden
Change is inevitable... Change for the better is not.
January 8, 2012 at 10:54 am
To add to the reasons not to use undocumented or, sometimes, even documented MS provided code...
The Developers of SQL Server will occasionally make significant performance mistakes in their code just like the rest of us.
I absolutely agree that the msdb.dbo.sysjobschedules will never have enough rows in it to become a real performance concern. I am, however, concerned that someone may copy the code from the msdb.dbo.agent_datetime() function that MS provided and use it for much larger things. If someone were to use that function for converting million row inputs multiple times per day, you could be stressing your server just because of the way the function was built. To summarize and as Michael suggested, conversions to character based datatypes can take a real toll on performance.
Of course, such statements on performance of code aren't worth a hoot without a little evidence. 🙂
Here's the typical million row test table...
--=====================================================================================================================
-- Create and populate the test table.
-- Nothing in this section is a part of the solutions being tested.
-- We're just building the test data here.
--=====================================================================================================================
--===== Conditionally drop the test table to make reruns easier in SSMS
IF OBJECT_ID('tempdb..#TestTable','U') IS NOT NULL
DROP TABLE #TestTable
;
--===== Create and populate the test table on the fly
WITH
cteGenDates AS
(
SELECT TOP (1000000)
SomeDateTime = RAND(CHECKSUM(NEWID()))*DATEDIFF(dd,'2012','2013')+CAST('2012' AS DATETIME)
FROM sys.all_columns ac1,
sys.all_columns ac2
)
SELECT next_run_date = CAST(CONVERT(CHAR(8),SomeDateTime,112) AS INT),
next_run_time = CAST(REPLACE(CONVERT(CHAR(8),SomeDateTime,108),':','') AS INT)
INTO #TestTable
FROM cteGenDates
;
GO
And here's the test harness. You need to setup SQL Profiler to measure this one because SET STATISTICS TIME ON really and unfairly slows the MS code down a lot!
--=====================================================================================================================
-- Do the test using the solutions found so far for converting Integer-based Dates and Times to DATETIME values.
-- To take display times out of the picture, all results are dumped to a "bit-bucket" variable.
-- RUN THIS TEST WITH SQL PROFILER RUNNING TO SEE THE PERFORMANCE DIFFERENCES.
-- Don't use SET STATISTICS TIME ON for this test because it really makes the MS code suffer.
--=====================================================================================================================
GO
--===== Michael's Solution ============================================================================================
--===== Declare the "bit-bucket" variable
DECLARE @Bitbucket DATETIME;
--===== Run the test
select
-- convert date
dateadd(dd,((next_run_date)%100)-1,
dateadd(mm,((next_run_date)/100%100)-1,
dateadd(yy,(nullif(next_run_date,0)/10000)-1900,0)))+
-- convert time
dateadd(ss,next_run_time%100,
dateadd(mi,(next_run_time/100)%100,
dateadd(hh,nullif(next_run_time,0)/10000,0)))
from
#TestTable
;
GO
--===== msdb.dbo.agent_datetime Function ==============================================================================
--===== Declare the "bit-bucket" variable
DECLARE @Bitbucket DATETIME;
--===== Run the test
SELECT @Bitbucket = msdb.dbo.agent_datetime(next_run_date,next_run_time)
FROM #TestTable
;
GO
Here are the results on my 9 year old, single cpu war-horse...
Heh... Michael must be slipping... his code is "only" 13 times faster. 😛
--Jeff Moden
Change is inevitable... Change for the better is not.
January 8, 2012 at 10:56 am
As a sidebar, it looks like they've really messed up the colorization on the code windows again. I sent an email to the SSC webmaster and have gotten no response. I'll send one to Steve.
--Jeff Moden
Change is inevitable... Change for the better is not.
January 8, 2012 at 7:16 pm
Jeff Moden (1/8/2012)
To add to the reasons not to use undocumented or, sometimes, even documented MS provided code...The Developers of SQL Server will occasionally make significant performance mistakes in their code just like the rest of us.
I absolutely agree that the msdb.dbo.sysjobschedules will never have enough rows in it to become a real performance concern. I am, however, concerned that someone may copy the code from the msdb.dbo.agent_datetime() function that MS provided and use it for much larger things. If someone were to use that function for converting million row inputs multiple times per day, you could be stressing your server just because of the way the function was built. To summarize and as Michael suggested, conversions to character based datatypes can take a real toll on performance.
Of course, such statements on performance of code aren't worth a hoot without a little evidence. 🙂
Here's the typical million row test table...
Heh... Michael must be slipping... his code is "only" 13 times faster. 😛
I hate to rain on results that show my code to be faster, but I think a fairer test would be if you had the function contents "in-line" or had my code in a function. The overhead of the function call can have a large impact on the results.
Demo Performance Penalty of User Defined Functions
January 8, 2012 at 7:31 pm
Michael Valentine Jones (1/8/2012)
The overhead of the function call can have a large impact on the results.
Understood and agreed... that's precisely the reason I posted such a test... to show just how bad using a MS provided scalar function can be when compared to simple in-line code. Speaking of which, if you'd like to convert your code to an in-line Table Valued Function, I'd be happy to include that in the testing. Unless I'm terribly mistaken, you won't see much of a difference using such an iTVF.
--Jeff Moden
Change is inevitable... Change for the better is not.
January 8, 2012 at 9:19 pm
Jeff Moden (1/8/2012)
To add to the reasons not to use undocumented or, sometimes, even documented MS provided code...the developers of SQL Server will occasionally make significant performance mistakes in their code just like the rest of us.
That's extremely generous of you Jeff. My impression is that the SQL code behind SSMS and in some of the system databases like msdb, must be written by a completely different team: the SQL code is most often pretty shonky, if we're honest. This isn't a particularly bad example, but it could/should have been written as an in-line function:
CREATE FUNCTION dbo.agent_datetime_inline
(
@Date integer,
@Time integer
)
RETURNS TABLE WITH SCHEMABINDING
AS RETURN
SELECT
CONVERT(datetime,
CONVERT(nvarchar(4), @Date/ 10000) + N'-' +
CONVERT(nvarchar(2),(@Date % 10000)/100) + N'-' +
CONVERT(nvarchar(2), @Date % 100) + N' ' +
CONVERT(nvarchar(2), @Time / 10000) + N':' +
CONVERT(nvarchar(2),(@Time % 10000)/100) + N':' +
CONVERT(nvarchar(2), @Time % 100),
120) AS date_time
GO
Paul White
SQLPerformance.com
SQLkiwi blog
@SQL_Kiwi
January 8, 2012 at 9:24 pm
Jeff Moden (1/8/2012)
Michael Valentine Jones (1/8/2012)
The overhead of the function call can have a large impact on the results.Understood and agreed... that's precisely the reason I posted such a test... to show just how bad using a MS provided scalar function can be when compared to simple in-line code. Speaking of which, if you'd like to convert your code to an in-line Table Valued Function, I'd be happy to include that in the testing. Unless I'm terribly mistaken, you won't see much of a difference using such an iTVF.
I think Michael was proposing that the test could be made fairer by:
Paul White
SQLPerformance.com
SQLkiwi blog
@SQL_Kiwi
January 9, 2012 at 6:17 am
I agree that the MS function should have been written as an iTVF instead of a scalar UDF. Heh... that was a part of the point I was trying to make with my last test. You just can't use these things blindly.
Shifting gears to how it should have been done (as both Michael and Paul have recommended), changing the MS code to an iTVF will certainly solve the major portion of the performance problem but, as Michael alluded to in his original post on this thread, using character-based conversions for date/time manipulation is still a lot slower (twice as slow on my ol' box).
Here are the two iTVF's... (Michael's code and MS' code)
CREATE FUNCTION dbo.IntsToDate
(
@Date integer,
@Time integer
)
RETURNS TABLE WITH SCHEMABINDING
AS RETURN
SELECT FullDateTime =
-- convert date
dateadd(dd,((@Date)%100)-1,
dateadd(mm,((@Date)/100%100)-1,
dateadd(yy,(nullif(@Date,0)/10000)-1900,0)))+
-- convert time
dateadd(ss,@Time%100,
dateadd(mi,(@Time/100)%100,
dateadd(hh,nullif(@Time,0)/10000,0)))
;
CREATE FUNCTION dbo.agent_datetime_inline
(
@Date integer,
@Time integer
)
RETURNS TABLE WITH SCHEMABINDING
AS RETURN
SELECT
CONVERT(datetime,
CONVERT(nvarchar(4), @Date/ 10000) + N'-' +
CONVERT(nvarchar(2),(@Date % 10000)/100) + N'-' +
CONVERT(nvarchar(2), @Date % 100) + N' ' +
CONVERT(nvarchar(2), @Time / 10000) + N':' +
CONVERT(nvarchar(2),(@Time % 10000)/100) + N':' +
CONVERT(nvarchar(2), @Time % 100),
120) AS date_time
GO
Here's the modified test harness...
--=====================================================================================================================
-- Do the test using the solutions found so far for converting Integer-based Dates and Times to DATETIME values.
-- To take display times out of the picture, all results are dumped to a "bit-bucket" variable.
-- RUN THIS TEST WITH SQL PROFILER RUNNING TO SEE THE PERFORMANCE DIFFERENCES.
-- Don't use SET STATISTICS TIME ON for this test because it really makes the MS code suffer.
--=====================================================================================================================
GO
--===== Michael's Solution ============================================================================================
--===== Declare the "bit-bucket" variable
DECLARE @Bitbucket DATETIME;
--===== Run the test
SELECT @Bitbucket = dt.FullDateTime
FROM #TestTable t
CROSS APPLY dbo.IntsToDate(next_run_date,next_run_time) dt
;
GO
--===== MS Code "in-line" =============================================================================================
--===== Declare the "bit-bucket" variable
DECLARE @Bitbucket DATETIME;
--===== Run the test
SELECT @Bitbucket = dt.date_time
FROM #TestTable t
CROSS APPLY dbo.agent_datetime_inline(next_run_date,next_run_time) dt
;
GO
Here're the results using the previously provided test data...
--Jeff Moden
Change is inevitable... Change for the better is not.
January 9, 2012 at 6:46 am
Just for interest's sake, here's the in-line function written to use SQL Server 2012:
CREATE FUNCTION dbo.agent_datetime_inline
(
@Date integer,
@Time integer
)
RETURNS TABLE WITH SCHEMABINDING
AS RETURN
SELECT
DATETIMEFROMPARTS
(
@Date / 10000,
@Date / 100 % 100,
@Date % 100,
@Time / 10000,
@Time / 100 % 100,
@Time % 100,
0
) AS date_time
Test results using Jeff's rig:
Michael's code: 1155ms
New function: 670ms
Paul White
SQLPerformance.com
SQLkiwi blog
@SQL_Kiwi
January 9, 2012 at 7:08 am
And, just to complete the picture, here's a CLR scalar function (not in-line!):
CREATE ASSEMBLY [DateTimeExtensions]
AUTHORIZATION [dbo]
FROM 0x4D5A90000300000004000000FFFF0000B800000000000000400000000000000000000000000000000000000000000000000000000000000000000000800000000E1FBA0E00B409CD21B8014CCD21546869732070726F6772616D2063616E6E6F742062652072756E20696E20444F53206D6F64652E0D0D0A2400000000000000504500004C01030024F30A4F0000000000000000E00002210B010800000A000000060000000000009E280000002000000040000000004000002000000002000004000000000000000400000000000000008000000002000000000000030040850000100000100000000010000010000000000000100000000000000000000000442800005700000000400000C803000000000000000000000000000000000000006000000C0000008C2700001C0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000200000080000000000000000000000082000004800000000000000000000002E74657874000000A408000000200000000A000000020000000000000000000000000000200000602E72737263000000C80300000040000000040000000C0000000000000000000000000000400000402E72656C6F6300000C00000000600000000200000010000000000000000000000000000040000042000000000000000000000000000000008028000000000000480000000200050094200000F80600000100000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000133007002F00000001000011000220102700005B021F645B1F645D021F645D0320102700005B031F645B1F645D031F645D730F00000A0A2B00062A1E02281000000A2A0042534A4201000100000000000C00000076322E302E35303732370000000005006C000000E0010000237E00004C0200009402000023537472696E677300000000E00400000800000023555300E8040000100000002347554944000000F80400000002000023426C6F620000000000000002000001471502000900000000FA2533001600000100000011000000020000000200000002000000100000000C00000001000000010000000200000000000A00010000000000060046003F0006004D003F00060091007F000600A8007F000600C5007F000600E4007F000600FD007F00060016017F00060031017F0006004C017F00060084016501060098017F000600C401B1013700D801000006000702E70106002702E7010A007F02640200000000010000000000010001000100100021000000050001000100502000000000960056000A0001008B200000000086186F0011000300000001007500000002007A0019006F00150021006F00150029006F00150031006F00150039006F00150041006F00150049006F00150051006F00150059006F001A0061006F00150069006F001F0079006F00250081006F00110089006F00110011006F00720109006F001100200073002A002E002B0081012E00130099012E001B0099012E0023009F012E000B0081012E003300AE012E003B0099012E004B0099012E005B00CF012E006300D8012E006B00E1017C01048000000100000028113A15000000000000450200000200000000000000000000000100360000000000020000000000000000000000010058020000000000000000003C4D6F64756C653E004461746554696D65457874656E73696F6E732E646C6C0055736572446566696E656446756E6374696F6E73006D73636F726C69620053797374656D004F626A656374004461746554696D65004461746554696D6546726F6D496E74656765725061727473002E63746F7200446174650054696D650053797374656D2E5265666C656374696F6E00417373656D626C795469746C6541747472696275746500417373656D626C794465736372697074696F6E41747472696275746500417373656D626C79436F6E66696775726174696F6E41747472696275746500417373656D626C79436F6D70616E7941747472696275746500417373656D626C7950726F6475637441747472696275746500417373656D626C79436F7079726967687441747472696275746500417373656D626C7954726164656D61726B41747472696275746500417373656D626C7943756C747572654174747269627574650053797374656D2E52756E74696D652E496E7465726F70536572766963657300436F6D56697369626C6541747472696275746500417373656D626C7956657273696F6E4174747269627574650053797374656D2E446961676E6F73746963730044656275676761626C6541747472696275746500446562756767696E674D6F6465730053797374656D2E52756E74696D652E436F6D70696C6572536572766963657300436F6D70696C6174696F6E52656C61786174696F6E734174747269627574650052756E74696D65436F6D7061746962696C697479417474726962757465004461746554696D65457874656E73696F6E730053797374656D2E44617461004D6963726F736F66742E53716C5365727665722E5365727665720053716C46756E6374696F6E4174747269627574650000032000000000002D4C33179D0E4D4BAAE00759A4F1A8860008B77A5C561934E0890600021109080803200001042001010E042001010205200101113904200101088146010004005455794D6963726F736F66742E53716C5365727665722E5365727665722E446174614163636573734B696E642C2053797374656D2E446174612C2056657273696F6E3D322E302E302E302C2043756C747572653D6E65757472616C2C205075626C69634B6579546F6B656E3D623737613563353631393334653038390A446174614163636573730000000054020F497344657465726D696E6973746963015402094973507265636973650154557F4D6963726F736F66742E53716C5365727665722E5365727665722E53797374656D446174614163636573734B696E642C2053797374656D2E446174612C2056657273696F6E3D322E302E302E302C2043756C747572653D6E65757472616C2C205075626C69634B6579546F6B656E3D623737613563353631393334653038391053797374656D4461746141636365737300000000092006010808080808080407011109170100124461746554696D65457874656E73696F6E7300000501000000000E0100094D6963726F736F667400002001001B436F7079726967687420C2A9204D6963726F736F6674203230313200000801000701000000000801000800000000001E01000100540216577261704E6F6E457863657074696F6E5468726F7773010000000024F30A4F000000000200000099000000A8270000A80900005253445336FDC6FA984ACC49ACCF9F555F663F9403000000633A5C75736572735C7061756C2077686974655C646F63756D656E74735C76697375616C2073747564696F20323031305C50726F6A656374735C4461746554696D65457874656E73696F6E735C4461746554696D65457874656E73696F6E735C6F626A5C44656275675C4461746554696D65457874656E73696F6E732E706462000000006C28000000000000000000008E280000002000000000000000000000000000000000000000000000802800000000000000000000000000000000000000005F436F72446C6C4D61696E006D73636F7265652E646C6C0000000000FF2500204000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000001001000000018000080000000000000000000000000000001000100000030000080000000000000000000000000000001000000000048000000584000006C03000000000000000000006C0334000000560053005F00560045005200530049004F004E005F0049004E0046004F0000000000BD04EFFE00000100000001003A152811000001003A1528113F000000000000000400000002000000000000000000000000000000440000000100560061007200460069006C00650049006E0066006F00000000002400040000005400720061006E0073006C006100740069006F006E00000000000000B004CC020000010053007400720069006E006700460069006C00650049006E0066006F000000A8020000010030003000300030003000340062003000000034000A00010043006F006D00700061006E0079004E0061006D006500000000004D006900630072006F0073006F00660074000000500013000100460069006C0065004400650073006300720069007000740069006F006E00000000004400610074006500540069006D00650045007800740065006E00730069006F006E007300000000003C000E000100460069006C006500560065007200730069006F006E000000000031002E0030002E0034003300390032002E003500340033003400000050001700010049006E007400650072006E0061006C004E0061006D00650000004400610074006500540069006D00650045007800740065006E00730069006F006E0073002E0064006C006C00000000005C001B0001004C006500670061006C0043006F007000790072006900670068007400000043006F0070007900720069006700680074002000A90020004D006900630072006F0073006F006600740020003200300031003200000000005800170001004F0072006900670069006E0061006C00460069006C0065006E0061006D00650000004400610074006500540069006D00650045007800740065006E00730069006F006E0073002E0064006C006C0000000000480013000100500072006F0064007500630074004E0061006D006500000000004400610074006500540069006D00650045007800740065006E00730069006F006E0073000000000040000E000100500072006F006400750063007400560065007200730069006F006E00000031002E0030002E0034003300390032002E003500340033003400000044000E00010041007300730065006D0062006C0079002000560065007200730069006F006E00000031002E0030002E0034003300390032002E0035003400330034000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000002000000C000000A03800000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000
WITH PERMISSION_SET = SAFE
GO
CREATE FUNCTION dbo.DateTimeFromIntegerParts
(
@Date integer,
@Time integer
)
RETURNS datetime
WITH EXECUTE AS CALLER
AS EXTERNAL NAME [DateTimeExtensions].[UserDefinedFunctions].[DateTimeFromIntegerParts]
GO
Called as so:
SELECT
dbo.DateTimeFromIntegerParts
(
tt.next_run_date,
tt.next_run_time
)
FROM #TestTable AS tt
Test results using Jeff's rig:
Michael's code: 1155ms
CLR function: 859ms
Source code:
using System;
using Microsoft.SqlServer.Server;
public partial class UserDefinedFunctions
{
[SqlFunction
(
DataAccess = DataAccessKind.None,
IsDeterministic = true,
IsPrecise = true,
SystemDataAccess = SystemDataAccessKind.None
)
]
public static DateTime DateTimeFromIntegerParts(int Date, int Time)
{
return new DateTime
(
Date / 10000,
Date / 100 % 100,
Date % 100,
Time / 10000,
Time / 100 % 100,
Time % 100
);
}
};
Paul White
SQLPerformance.com
SQLkiwi blog
@SQL_Kiwi
January 9, 2012 at 9:11 am
I simplified my original code to eliminate three DATEADD function calls and one NULLIF function call, so it might run a bit faster.
select
next_run_date ,
next_run_time ,
NEXT_RUN_DATETIME =
dateadd(mm,((next_run_date)/100%100)-1,
dateadd(yy,(nullif(next_run_date,0)/10000)-1900,
dateadd(ss,
-- Seconds
(next_run_time%100)+
-- Minutes
(((next_run_time/100)%100)*60)+
-- Hours
((next_run_time/10000)*3600)+
-- Days
(((next_run_date)%100)-1)*86400
,0)))
from
msdb.dbo.sysjobschedules AS s
next_run_date next_run_time NEXT_RUN_DATETIME
------------- ------------- -----------------------
20120109 170000 2012-01-09 17:00:00.000
20120109 170000 2012-01-09 17:00:00.000
20120204 20000 2012-02-04 02:00:00.000
20100718 83033 2010-07-18 08:30:33.000
20120110 100 2012-01-10 00:01:00.000
20120114 30000 2012-01-14 03:00:00.000
20120121 23000 2012-01-21 02:30:00.000
20100821 142000 2010-08-21 14:20:00.000
0 0 NULL
20120109 105000 2012-01-09 10:50:00.000
20091104 100000 2009-11-04 10:00:00.000
20120115 200 2012-01-15 00:02:00.000
0 0 NULL
20120110 90000 2012-01-10 09:00:00.000
20120115 150000 2012-01-15 15:00:00.000
20120110 30000 2012-01-10 03:00:00.000
Viewing 15 posts - 1 through 15 (of 20 total)
You must be logged in to reply to this topic. Login to reply