TechNet
Export (0) Print
Expand All
Collapse the table of content
Expand the table of content
Expand Minimize

sp_stop_job (Transact-SQL)

 

Updated: August 1, 2016

Instructs SQL Server Agent to stop the execution of a job.

Topic link icon Transact-SQL Syntax Conventions

  
sp_stop_job   
      [@job_name =] 'job_name'  
    | [@job_id =] job_id   
    | [@originating_server =] 'master_server'  
    | [@server_name =] 'target_server'  

[ @job_name =] 'job_name'
The name of the job to stop. job_name is sysname, with a default of NULL.

[ @job_id =] job_id
The identification number of the job to stop. job_id is uniqueidentifier, with a default of NULL.

[ @originating_server =] 'master_server'
The name of the master server. If specified, all multiserver jobs are stopped. master_server is nvarchar(128), with a default of NULL. Specify this parameter only when calling sp_stop_job at a target server.

System_CAPS_ICON_note.jpg Note


Only one of the first three parameters can be specified.

[ @server_name =] 'target_server'
The name of the specific target server on which to stop a multiserver job. target_server is nvarchar(128), with a default of NULL. Specify this parameter only when calling sp_stop_job at a master server for a multiserver job.

0 (success) or 1 (failure)

None

sp_stop_job sends a stop signal to the database. Some processes can be stopped immediately and some must reach a stable point (or an entry point to the code path) before they can stop. Some long-running Transact-SQL statements such as BACKUP, RESTORE, and some DBCC commands can take a long time to finish. When these are running, it may take a while before the job is canceled. Stopping a job causes a "Job Canceled" entry to be recorded in the job history.

If a job is currently executing a step of type CmdExec or PowerShell, the process being run (for example, MyProgram.exe) is forced to end prematurely. Premature ending can result in unpredictable behavior such as files in use by the process being held open. Consequently, sp_stop_job should be used only in extreme circumstances if the job contains steps of type CmdExec or PowerShell.

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

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

Members of SQLAgentUserRole and SQLAgentReaderRole can only stop jobs that they own. Members of SQLAgentOperatorRole can stop all local jobs including those that are owned by other users. Members of sysadmin can stop all local and multiserver jobs.

The following example stops a job named Weekly Sales Data Backup.

USE msdb ;  
GO  
  
EXEC dbo.sp_stop_job  
    N'Weekly Sales Data Backup' ;  
GO  

sp_delete_job (Transact-SQL)
sp_help_job (Transact-SQL)
sp_start_job (Transact-SQL)
sp_update_job (Transact-SQL)
System Stored Procedures (Transact-SQL)

THIS TOPIC APPLIES TO:yesSQL Server (starting with 2008)noAzure SQL DatabasenoAzure SQL Data Warehouse noParallel Data Warehouse

Community Additions

ADD
Show:
© 2016 Microsoft