Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Custom SQL Agent job schedule to run on the 5th working day of each month


Custom SQL Agent job schedule to run on the 5th working day of each month

Author
Message
Griffster
Griffster
SSC Veteran
SSC Veteran (251 reputation)SSC Veteran (251 reputation)SSC Veteran (251 reputation)SSC Veteran (251 reputation)SSC Veteran (251 reputation)SSC Veteran (251 reputation)SSC Veteran (251 reputation)SSC Veteran (251 reputation)

Group: General Forum Members
Points: 251 Visits: 713
I have the need to send a suite of SSRS reports to a client on the 5th working day of the month. Is there a way of either:

1) setting a subscription to run on this day for the reports
2) set a sql agent job to run on this day

I would ideally like to know both if possible. Is it possible to build custom schedules in sql agent? I have a table of dates and another of holiday dates which can be used to find the 5th working day of the month but I don't know how to apply it to a schedule.
Fraggle-805517
Fraggle-805517
Right there with Babe
Right there with Babe (733 reputation)Right there with Babe (733 reputation)Right there with Babe (733 reputation)Right there with Babe (733 reputation)Right there with Babe (733 reputation)Right there with Babe (733 reputation)Right there with Babe (733 reputation)Right there with Babe (733 reputation)

Group: General Forum Members
Points: 733 Visits: 1509
You could do it with a SQL Agent Job pretty easly. Just setup a pre-populated list of the 5th business day each month. The run an IF statement like below.

IF (select * from 5thdayofmonth) = getdate()
BEGIN


-- Run report logic here.

END

Don't know of a way to do this in SSRS Scheduling Manager.

Fraggle
homebrew01
homebrew01
SSCrazy
SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)

Group: General Forum Members
Points: 2980 Visits: 9071
I have a need to pre-populate a list of the 5th business day each month. Any idea how to do that ? Hehe



Ninja's_RGR'us
Ninja's_RGR'us
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20931 Visits: 9671
Agreed, you'll have to use a calendar table and a simple if statement to block / let the subscription run.


Keep in mind that those jobs are rebuilt every time the subscription changes (this includes password update).

So that solution can get annoying really fast if it's not properly scripted.
Ninja's_RGR'us
Ninja's_RGR'us
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20931 Visits: 9671
homebrew01 (8/2/2011)
I have a need to pre-populate a list of the 5th business day each month. Any idea how to do that ? Hehe



WITH    CTE ( dt, rn )
As (
SELECT
dt
, ROW_NUMBER() OVER ( ORDER BY dt ) AS rn
FROM
dbo.Calendar
WHERE
Y = YEAR(GETDATE())
AND M = MONTH(GETDATE())
AND IsBusDay = 1
)
SELECT
'RUN SUBSCRIPTIONS'
FROM
CTE
WHERE
rn = 5
AND dt = DATEADD(D , 0 , DATEDIFF(D , 0 , GETDATE()))

IF @@ROWCOUNT = 1
SELECT 'sp_startjob'
ELSE
SELECT 'NOTHING TO DO'




Script to load my Calendar table.

http://www.sqlservercentral.com/Forums/Attachment8839.aspx
asheppardwork
asheppardwork
SSC Rookie
SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)

Group: General Forum Members
Points: 39 Visits: 162
Thank you for this script, it was one of the final pieces to my having to run a sub on the 3rd business day of every month.

For anyone who is interested:
Paul Turley has a blog that lists how to get the GUID associated with a individual sub in the SSRS Report Manager.

https://sqlserverbiblog.wordpress.com/2010/03/11/manually-starting-a-report-subscription/#comment-1781

Then you use the command:

use msdb

EXEC sp_start_job @job_name = 'XXXXXXX-8FA9-4DFD-8677-34D451A75C74'

and the subscription fires at the time the script is completed, so it doesn't matter what the days that are in the sub are set for.

Also, I used a Aux_Calendar table from:

http://sqlserver2000.databases.aspfaq.com/why-should-i-consider-using-an-auxiliary-calendar-table.html

(no author listed, but he is one smart cookie)

Basically with his number table and calendar with this CTE script and the GUID I can now send any report on any set of days that a manager can dream up.:-D
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search