Spreading Job Run Times Out on an MSX/TSX Scheduled Job

Problem

My company heavily uses MSX/TSX jobs for everything.  But our SAN doesn’t necessarily like if we run all our index maintenance, backups, and integrity checks at the same time.  So here is a quick little post on how you can schedule the workload to spread out across all your servers across multiple time blocks and still have only one job.

Solution

First, you need to decide how many time blocks or hours you want the jobs to run in.  So let’s start with scenario one where you pick for example four time blocks.  First, you declare a variable with the time block in it and we will feed in the @@SERVERNAME to let determine a value for the time block that server will run.  Then we wrap our code around our time block, our example we will run Index Maintenance for a 12 period spread out for three hours.  Mind you for my index process which I probably should blog about as well I am processing one index at a time have something that BREAKs out of the procedure when it exceeds the time block it is.  So below we run Index Maintenace between start the index maintenance job on a server between the hours 6  PM and 5 AM based on the time block value we got back.

DECLARE @TimeBlock INT = ABS(CHECKSUM(@@SERVERNAME))%4+1 --Returns a value between 1 and 4 based on @@SERVERNAME

IF (@TimeBlock = 1 AND (CONVERT(INT,(DATEPART(HOUR,GETDATE()))) >= 21 OR CONVERT(INT,(DATEPART(HOUR,GETDATE()))) < 18)) OR (@TimeBlock = 2 AND CONVERT(INT,(DATEPART(HOUR,GETDATE()))) >= 0)
	OR (@TimeBlock = 3 AND CONVERT(INT,(DATEPART(HOUR,GETDATE()))) >= 3)
	OR (@TimeBlock = 4 AND CONVERT(INT,(DATEPART(HOUR,GETDATE()))) >= 6)
BEGIN
--Run code for index maintenace
END

Using the same concept we could spread out when out backups start on our servers at night by using the following code:

IF @Hour = CONVERT(INT,(DATEPART(HOUR,GETDATE())))
BEGIN
--Run backups
END

Next Steps

If you are using MSX/TSX you can now consolidate your jobs, if you aren’t using MSX/TSX explore it, it does make managing your jobs easier.  This can use with Ola Hallengren’s scripts or MinionWare scripts or any other scripts you need to run for maintenance across all your servers during a certain window of time without saturating you SAN.

Related Posts

2 thoughts on “Spreading Job Run Times Out on an MSX/TSX Scheduled Job

  1. Very slick!

    To answer the question of how this will distribute execution of the MSX jobs, use the query below. One would think that this method would relatively evenly distribute between the time blocks. I found that this is not always the case.

    DECLARE @TimeBlocks int = 4;

    SELECT
    j.name
    , t.server_name
    , ABS(CHECKSUM(t.server_name)) % @TimeBlocks
    FROM sysjobs j
    INNER JOIN sysjobservers s ON j.job_id = s.job_id
    INNER JOIN systargetservers t ON s.server_id = t.server_id
    ORDER BY j.name
    , t.server_name;

Leave a Comment

This site uses Akismet to reduce spam. Learn how your comment data is processed.