Polling in SQL Agent
A fun question over on StackOverflow asked about using SQL Agent with SSIS to poll for a file's existence. As the comments indicate, there's a non-zero startup time associated with SSIS (it must validate the metadata associated to the sources and destinations), but there is a faster, lighter weight alternative. Putting together a host of TSQL ingredients, including undocumented extended stored procedures, the following recipe could be used as a SQL Agent job step.
If you copy and paste the following query into your favorite instance of SQL Server, it will execute for one minute and it will complete by printing the words "Naughty, naughty".
SET NOCOUNT ON; -- http://www.patrickkeisler.com/2012/11/how-to-use-xpdirtree-to-list-all-files.html DECLARE -- Don't do stupid things like adding spaces into folder names @sourceFolder varchar(260) = 'C:\ssisdata\Input' -- Have to use SQL matching rules, not DOS/SSIS , @fileMask sysname = 'SourceData%.txt' -- how long to wait between polling , @SleepInSeconds int = 5 -- Don't exceed 24 hours aka 86400 seconds , @MaxTimerDurationInSeconds int = (3600 * 0) + (60 * 1) + 0 -- parameter for xp_dirtree 0 => top folder only; 1 => subfolders , @depth int = 1 -- parameter for xp_dirtree 0 => directory only; 1 => directory and files , @collectFile int = 1 , @RC bigint = 0; -- Create a table variable to capture the results of our directory command DECLARE @DirectoryTree table ( id int IDENTITY(1, 1) , subdirectory nvarchar(512) , depth int , isFile bit ); -- Use our sleep in seconds time to generate a delay time string DECLARE @delayTime char(10) = CONVERT(char(10), TIMEFROMPARTS(@SleepInSeconds/60 /60, @SleepInSeconds/60, @SleepInSeconds%60, 0, 0), 108) , @stopDateTime datetime2(0) = DATEADD(SECOND, @MaxTimerDurationInSeconds, CURRENT_TIMESTAMP); -- Force creation of the folder EXECUTE dbo.xp_create_subdir @sourceFolder; -- Load the results of our directory INSERT INTO @DirectoryTree ( subdirectory , depth , isFile ) EXECUTE dbo.xp_dirtree @sourceFolder , @depth , @collectFile; -- Prime the pump SELECT @RC = COUNT_BIG(1) FROM @DirectoryTree AS DT WHERE DT.isFile = 1 AND DT.subdirectory LIKE @fileMask; WHILE @rc = 0 AND @stopDateTime > CURRENT_TIMESTAMP BEGIN -- Load the results of our directory INSERT INTO @DirectoryTree ( subdirectory , depth , isFile ) EXECUTE dbo.xp_dirtree @sourceFolder , @depth , @collectFile; -- Test for file existence SELECT @RC = COUNT_BIG(1) FROM @DirectoryTree AS DT WHERE DT.isFile = 1 AND DT.subdirectory LIKE @fileMask; IF @RC = 0 BEGIN -- Put our process to sleep for a period of time WAITFOR DELAY @delayTime; END END -- at this point, we have either exited due to file found or time expired IF @RC > 0 BEGIN -- Take action when file was found PRINT 'Go run SSIS or something'; END ELSE BEGIN -- Take action for file not delivered in expected timeframe PRINT 'Naughty, naughty'; END
If you rerun the above query, in a separate window, assuming you have xp_cmdshell enabled, firing the following query will create a file with the expected pattern. Instead, it'll print out "Go run SSIS or something"
DECLARE @sourceFolder varchar(260) = 'C:\ssisdata\Input' , @fileMask sysname = REPLACE('SourceData%.txt', '%', CONVERT(char(10), CURRENT_TIMESTAMP, 120)) DECLARE @command varchar(1000) = 'echo > ' + @sourceFolder + '\' + @fileMask; -- If you get this error --Msg 15281, Level 16, State 1, Procedure sys.xp_cmdshell, Line 1 [Batch Start Line 0] --SQL Server blocked access to procedure 'sys.xp_cmdshell' of component 'xp_cmdshell' because this component is turned off as part of the security configuration for this server. A system administrator can enable the use of 'xp_cmdshell' by using sp_configure. For more information about enabling 'xp_cmdshell', search for 'xp_cmdshell' in SQL Server Books Online. -- -- Run this --EXECUTE sys.sp_configure'xp_cmdshell', 1; --GO --RECONFIGURE; --GO EXECUTE sys.xp_cmdshell @command;
Once you're satisfied with how that works, now what? I'd likely set up a step 2 which is the actual running of the SSIS package (instead of printing a message). What about the condition that a file wasn't found? I'd likely use throw/raiserrror or just old fashioned divide by zero to force the first job step to fail. And then specify a reasonable number of @retry_attempts and @retry_interval.
No comments:
Post a Comment