SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Need TSQL help to monitor the scheduled jobs in SQL 2012


Need TSQL help to monitor the scheduled jobs in SQL 2012

Author
Message
Mac1986
Mac1986
Mr or Mrs. 500
Mr or Mrs. 500 (561 reputation)Mr or Mrs. 500 (561 reputation)Mr or Mrs. 500 (561 reputation)Mr or Mrs. 500 (561 reputation)Mr or Mrs. 500 (561 reputation)Mr or Mrs. 500 (561 reputation)Mr or Mrs. 500 (561 reputation)Mr or Mrs. 500 (561 reputation)

Group: General Forum Members
Points: 561 Visits: 791
I have a request to monitor couple of scheduled SQL jobs in 2012 version.

Example: There is a SQL job which is scheduled 6 times a day starting 12:55 AM PST. Now for what ever reason, if this job fails or if it is an out of cycle run. Because, we have few scenarios where we need to manually kick off the jobs apart from schedule. I need to differentiate between manually kicked off runs and Scheduled runs of that job.

I checked EXEC msdb.dbo.sp_help_jobactivity but is only giving me requested date and starttime info.

I need prepare a script to dynamically check and differentiate between manually kicked off runs and Scheduled runs of SQL jobs.
Alan.B
Alan.B
SSCertifiable
SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)

Group: General Forum Members
Points: 5140 Visits: 7720
I'm going to take a quick stab at this since nobody has responded yet. What I am showing you here is not a complete solution but should get you moving in the right direction.

First, msdb.dbo.sp_help_jobactivity should give you a number of columns: the query below runs fine for me on 2008 and 2012.

DECLARE @job_hist TABLE 
( session_id int,
job_id varchar(100),
job_name varchar(200),
run_requested_date datetime,
run_requested_source int,
queued_date datetime,
start_execution_date datetime,
last_executed_step_id int,
last_executed_step_date datetime,
stop_execution_date datetime,
next_scheduled_run_date datetime,
job_history_id bigint,
[message] varchar(1000),
run_status int,
operator_id_emailed int,
operator_id_netsent int,
operator_id_paged int)

INSERT @job_hist
EXEC msdb.dbo.sp_help_jobactivity

SELECT 'Scheduled' AS Scheduled_or_manual,
PATINDEX('%The Job was invoked by Schedule%',[message]),
*
FROM @job_hist
WHERE PATINDEX('%The Job was invoked by Schedule%',[message])<>0
UNION ALL
SELECT 'Manual',
PATINDEX('%The Job was invoked by user%',[message]),
*
FROM @job_hist
WHERE PATINDEX('%The Job was invoked by user%',[message])<>0



That said, you can also get this information from msdb..sysjobhistory

SELECT 'manual' AS Scheduled_or_manual, * 
FROM msdb..sysjobhistory
WHERE step_id=0
AND PATINDEX('%The Job was invoked by user%',[message])<>0
UNION
SELECT 'scheduled' AS Scheduled_or_manual, *
FROM msdb..sysjobhistory
WHERE step_id=0
AND PATINDEX('%The Job was invoked by schedule%',[message])<>0



AGAIN: Both the above queries are not complete solutions but should get you started.

-- Alan Burstein



Best practices for getting help on SQLServerCentral
Need to split a string? Try DelimitedSplit8K or DelimitedSplit8K_LEAD (SQL 2012+)
Need a pattern-based splitter? Try PatternSplitCM
Need to remove or replace those unwanted characters? Try PatExclude8K and PatReplace8K.

"I can't stress enough the importance of switching from a 'sequential files' mindset to 'set-based' thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code. " -- Itzek Ben-Gan 2001
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