Learn more about SQL Server tools

solving sql server problems for millions of dbas and developers since 2006
join MSSQLTips for free SQL Server tips







Learn more about SQL Server tools








Learn more about SQL Server tools


Different ways to execute a SQL Agent job

MSSQLTips author Divya Agrawal By:   |   Read Comments (5)   |   Related Tips: More > SQL Server Agent

Problem:
Every database person might have come across the situation of maintenance tasks such as backing up of databases, re-indexing tables and other such tasks. We often schedule jobs for such tasks, so that they execute as per the set schedule. But there is sometimes the need for these tasks to be executed "On Demand". This tip shows various ways of executing such tasks on demand by any user regardless of whether the person is technical or not.

Solution
Let's say I have a job called "BACKUPTEST" which backups the test databases.  I want to be able to execute the job "On Demand", so whenever anyone needs to do the backup this can be done. In this article I will show you how you can execute such Jobs easily through various ways.

In this tip we will look at these four methods:

  1. SQL Server Management Studio
  2. T-SQL commands
  3. DMO (Distributed Management Objects)
  4. OSQL

Also, this tip assumes that the jobs have already been setup.


(1) - SQL Server Management Studio

The first way that most people are probably aware of is to use SQL Server Management Studio.

SQL Server Agent is the job scheduling tool for SQL Server.

To execute a job on demand using the GUI, open the SQL Server Agent tree, expand Jobs, select the job you want to run, right click on that job and click ‘Start Job' and the job will execute.



(2) -T-SQL commands

The second way is through a T-SQL statement using the  'sp_start_job' stored procedure which instructs SQL Server Agent to execute a job immediately. It is a stored procedure in the 'msdb' database.

The syntax for the sp_start_job stored procedure is:

sp_start_job 
  [@job_name] or [@job_id ]
  [,@error_flag ] 
  [,@server_name] 
  [,@step_name ] 
  [,@output_flag ]

Arguments:

[@job_name] | [@job_id ] Is the name of the job to start. Either job_id or job_name must be specified, but both cannot be specified. job_name is sysname, with a default of NULL.
[@error_flag =] error_flag Reserved.
[@server_name =] 'server_name' Is the target server on which to start the job. server_name is nvarchar(30), with a default of NULL. server_name must be one of the target servers to which the job is currently targeted.
[@step_name =] 'step_name' Is the name of the step at which to begin execution of the job. Applies only to local jobs. step_name is sysname, with a default of NULL
[@output_flag =] output_flag Reserved.

When a job run it will have one of two return codes:

  • 0 (success)
  • 1 (failure)

To run the job ‘BACKUPTEST' it can be executed by a single T-SQL statement: such as:

EXEC msdb.dbo.sp_start_job 'BACKUPTEST'


(3) -DMO (Distributed Management Objects)

Another way of executing the job is through a VBS script using Distributed Management Objects (DMO).

Here is the basic script syntax.

On Error Goto 0: Main() 
Sub Main() 
   Set objSQL = CreateObject("SQLDMO.SQLServer") 
   ' Leave as trusted connection 
   objSQL.LoginSecure = True 
   ' Change to match the name of your SQL server 
   objSQL.Connect "Enter Server Name Here" 
   Set objJob = objSQL.JobServer 
   For each job in objJob.Jobs 
      if instr(1,job.Name,"Enter Job Name Here") > 0 then 
         msgbox job.Name 
         job.Start  
         msgbox "Job Started"
      end if 
   Next 
End Sub

Here is sample executing the "BACKUPTEST" job on server "SQLTEST1".  This uses NT authentication to run this script.

On Error Goto 0: Main() 
Sub Main() 
   Set objSQL = CreateObject("SQLDMO.SQLServer") 
   ' Leave as trusted connection 
   objSQL.LoginSecure = True 
   ' Change to match the name of your SQL server 
   objSQL.Connect "SQLTEST1" 
   Set objJob = objSQL.JobServer 
   For each job in objJob.Jobs 
      if instr(1,job.Name,"BACKUPTEST") > 0 then 
         msgbox job.Name 
         job.Start  
         msgbox "Job Started"
      end if 
   Next 
End Sub

This code would then be saved in a file and named something like "RunJob.vbs".  You can then double click on the file to execute it or run the code from a command line.


(4)  - Using osql utility

Lastly, we can start the job using osql commands.

The osql utility allows you to enter T-SQL statements, system procedures, and script files.

Here is the basic script syntax.

osql -S "Enter Server Name Here" -E -Q"exec msdb.dbo.sp_start_job 'Enter Job Name Here'"

Open a command prompt and execute the below osql command in it:, replacing your server name and job name.

osql -S "SQLTEST1" -E -Q"exec msdb.dbo.sp_start_job 'BACKUPTEST'"

The next step is to make a batch file which can be run over and over again.

Open notepad and type the commands as follow:


Save the file as "job.bat".

The batch is now ready for use. Just double click on it and it will do the maintenance work without having any knowledge of SQL Server.


Permissions

You might have noticed in all the four solutions the msdb stored procedure ‘sp_start_job' is used in one way or another.

By default, members of the sysadmin fixed server role can execute this stored procedure.

Other users must be granted one of the following SQL Server Agent fixed database roles in the msdb database:

  • SQLAgentUserRole
  • SQLAgentReaderRole
  • SQLAgentOperatorRole

Members of SQLAgentUserRole and SQLAgentReaderRole can only start jobs that they own.

Members of SQLAgentOperatorRole can start all local jobs including those that are owned by other users.

Members of sysadmin can start all local and multiserver jobs.

For details about the permissions of these roles, see SQL Server Agent Fixed Database Roles. and SQL Server Agent Fixed Database Roles

 

Next Steps



Last Update: 4/15/2009


About the author
MSSQLTips author Divya Agrawal
Related Resources


print tip Print  
Become a paid author




Recommended For You








Learn more about SQL Server tools
Comments and Feedback:
Thursday, April 22, 2010 - 10:28:59 PM - ina.nortje@gmail.com Read The Tip

Good day,

I used the option of the VB Script, and it works very well.  The only thing missing is somehow letting the remote user know that the job has executed successfully.  Is there a way using VBScript that I can query the current status of the job (Just having "Currently Running" or Job Failed at XX:XX" or "Job Succeeded at XX:XX" will be great.

 Thanks

Ina


Tuesday, January 24, 2012 - 3:00:55 PM - Eric Higgins Read The Tip

This is a handy quick ref, thank you.


Monday, July 02, 2012 - 8:53:51 AM - Sonali Read The Tip

 

Nice article


Sunday, November 25, 2012 - 9:26:06 PM - Zoran Read The Tip

Very helpful, thanks a lot.

 


Tuesday, June 11, 2013 - 8:39:10 AM - Mahesh Read The Tip
  • Good Artical. Thanks



Post a Comment or Question

Keep it clean and stay on the subject or we may delete your comment.
Your email address is not published. Required fields are marked with an asterisk (*)

*Name   *Email Notify for updates

Signup for our newsletter


Comments
*Enter Code refresh code


 

Sponsor Information







Copyright (c) 2006-2014 Edgewood Solutions, LLC All rights reserved
privacy | disclaimer | copyright | advertise | about
authors | contribute | feedback | giveaways | user groups | community | events | first timer?
Some names and products listed are the registered trademarks of their respective owners.