Basit's SQL Server Tips

It is all about passion!

Main menu

Skip to content
  • Home
  • General Tips
  • About Me

Search

  • RSS Feed
  • Twitter
  • Facebook

Tag Archives: quickly update the job owner for all SQL Server Agent jobs

April 4, 2014

Changing SQL Server Agent Jobs Ownership: Who should own SQL Server Agent Jobs

I writing this blog post as a result of the following two questions, which I’ve been asked by one of my blog follower recently.

  • Question#1: Does it matter who is the owner of the SQL Server Agent job?
  • Question#2: Is there a way to quickly update the job owner for all SQL Server Agent jobs?

My replies to his questions are as follow:

Reply to question#1:

Yes, it does matter because when you run the SQL Server Agent job that is owned by a non-sysadmin user, SQL Server Agent logs into SQL Server using its own credentials, then switches the security context of that session to the login who owns the SQL Server Agent job. For example, if you have a SQL Server Agent job that is owned by user called “Joe Blob”.  Joe Blob is not a member of sysadmin fixed server role. When you run the SQL Server Agent job owned by him, the SQL Server Agent job will run under his security context. However, when the SQL Server Agent job is owned by the user who is the member of sysadmin fixed server role, the SQL Server Agent job runs under the security context of SQL Server Agent service account.

It is also a recommendation that individuals should not be set as the owner of the SQL Server Agent jobs, and dedicate account with least privileges assigned should own the SQL Server Agent Jobs. Because, setting individual’s as the job owner can lead to security issues when that individual’s account will be deleted from SQL Server or disabled in Active Directory. As a result, the SQL Server Agent job will stop working.

So be careful when creating or modifying the SQL Server Agent jobs because by default SQL Server Agent jobs are owned by the user who created or edited them. Running SQL Server Agent job with least privilege account is a best practice.

Reply to question#2:

You must be a system administrator to change the owner of a SQL Server Agent job. You can use SQL Server Management Studio to give others ownership of a SQL Server Agent job. For more information, see MSDN resource here.

Changing SQL Server Agent job ownership using SQL Server Management Studio is fairly simple, if you have few SQL Server Agent jobs. However, if you have hundreds of SQL Server Agent Jobs across numerous SQL Servers, then you must write Transact-SQL script using (msdb..sp_manage_jobs_by_login or msdb..sp_update_job), or write PowerShell script to quickly change the ownership of all SQL Server Agent jobs on SQL Server instances.

Change all SQL Server Agent Jobs Ownership (Transact-SQL version)

The following Transact-SQL version of the script, which I use to change the ownership of all SQL Server Agent job to specified user. In this script, I’m using msdb..sp_update_job system stored procedure to change the job ownership.


USE [msdb];

SET NOCOUNT ON;

DECLARE @NewOwnerLoginName [sysname] = N'New_Job_Owner_Login_Name' --// <-- Specify user to own all SQL Server Agent jobs

----------------------------------------------------------------------------------------------------
--// Internal script local variables											               //--
----------------------------------------------------------------------------------------------------
DECLARE @SQLStatementID01	[int] ,
		@CurrentCommand01	[nvarchar](MAX) ,
		@ErrorMessage		[varchar](MAX) 

IF OBJECT_ID(N'TempDb.dbo.#Work_To_Do') IS NOT NULL
    DROP TABLE #Work_To_Do 
CREATE TABLE #Work_To_Do
    (
      [SQLID] [int] IDENTITY(1, 1)
                    PRIMARY KEY ,
      [JobName] [sysname] ,
      [TSQL_Text] [varchar](1024) ,
      [Completed] [bit]
    )

INSERT  INTO #Work_To_Do
        ( [JobName] ,
          [TSQL_Text] ,
          [Completed]
        )
        SELECT  [name] ,
                'EXEC [msdb]..[sp_update_job] @job_name = N''' + [name]
                + N''', owner_login_name = N''' + @NewOwnerLoginName + N''';' ,
                0
        FROM    [msdb].[dbo].[sysjobs]

SELECT  @SQLStatementID01 = MIN([SQLID])
FROM    #Work_To_Do
WHERE   [Completed] = 0

WHILE @SQLStatementID01 IS NOT NULL
    BEGIN

        SELECT  @CurrentCommand01 = [TSQL_TEXT]
        FROM    #Work_To_Do
        WHERE   [SQLID] = @SQLStatementID01

        BEGIN TRY
            EXEC [sys].[sp_executesql] @CurrentCommand01
        END TRY
        BEGIN CATCH

            SET @ErrorMessage = N'"Oops, an error occurred that could not be resolved. For more information, see below:'
                + CHAR(13) + ERROR_MESSAGE() 

            RAISERROR(@ErrorMessage,16,1) WITH NOWAIT

            GOTO ChooseNextCommand
        END CATCH

        ChooseNextCommand:

        UPDATE  #Work_To_Do
        SET     [Completed] = 1
        WHERE   [SQLID] = @SQLStatementID01

        SELECT  @SQLStatementID01 = MIN([SQLID])
        FROM    #Work_To_Do
        WHERE   [Completed] = 0
    END

SET NOCOUNT OFF;

Change all SQL Server Agent Jobs Ownership (PowerShell version)

The following is the PowerShell version of the script, which I use to change the ownership of all SQL Server Agent job to specified user. In this script, I’m using Microsoft.SqlServer.Smo class and its methods to update the SQL Server Agent job ownership to specified user.


Function ChangeSQLAgentJobOwner
{
   # Declare powershell script parameters
   Param
   (
        [String] $SQLServer,
        [String] $NewOwnerLoginName
   )
   Try
   {
        [System.Reflection.Assembly]::LoadWithPartialName(‘Microsoft.SqlServer.Smo’) | Out-Null
        $SMOServer = New-Object (‘Microsoft.SqlServer.Management.Smo.Server’) $SQLServer 
        $SQLAgent = $SMOServer.JobServer;

        $SQLAgent.Jobs | % { 
                                $_.set_OwnerLoginName($NewOwnerLoginName); 
                                $_.Alter(); 
                           }

   }
   	Catch [System.Exception]
	{
		Write-Host "Oops, an error occurred that could not be resolved. For more information, see below:"
		$Error[1]
	}

}

# Executing the powershell function
ChangeSQLAgentJobOwner "W7LAPT120" "New_Job_Owner_Login_Name" # Specify the new SQL Server Agent job owner login name

I hope you liked this post 🙂 . Please feel free to use comment section, If you have any question regarding this post. You can also drop me question via twitter (@BasitAali).

Advertisement

Rate this:

Share this:

  • Tweet
  • Email
  • Print

Like this:

Like Loading...
  • Posted in General Tips
  • Tagged change all sql agent job owner with powershell, dbo.sp_manage_jobs_by_login, dbo.sp_update_job, does it matter who is the owner of the SQL Server Agent job, msdb..sp_manage_jobs_by_login, msdb..sp_update_job, quickly update the job owner for all SQL Server Agent jobs, update Job owner for all SQL Server Agent jobs;
  • 4 Comments

Post navigation

My Book

SQL Server 2014 Development Essentials (ISBN: 978-1782172550) is an easy-to-follow yet comprehensive guide that is full of hands-on examples. This book will provide you with all the skills you need to successfully design, build, and deploy databases using SQL Server 2014. Starting from the beginning, this book gives you an insight into the key stages of the SQL Server database process, provides you with an in-depth knowledge of the SQL Server database architecture, and shares tips to help you design the new database.

By sequentially working through the steps in each chapter, you will gain hands-on experience in designing, creating, and deploying SQL Server databases and objects. You will learn how to use SQL Server 2014 Management Studio and the advanced Transact-SQL queries to retrieve data from the SQL Server database. You will also learn how to add, modify, and delete data stored within a database. You will use Transact-SQL statements to create and manage advanced database objects that include scalar and table-valued functions, views, stored procedures, and triggers. Finally, you will learn about how the SQL Server 2014 relation engine works, how indexes and statistics improve query performance, and the new SQL Server 2014 in-memory technologies.

Latest Tweets

Error: Twitter did not respond. Please wait a few minutes and refresh this page.

Recent Posts

  • Quick Tip – How to fix SQL Server 2017 install error on Ubuntu 18.04: E: Could not get lock /var/lib/dpkg/lock-frontend – open (11: Resource temporarily unavailable)
  • CREATE DATABASE failed on SQL Server FCI cluster: Only formatted files on which the cluster resource of the server has a dependency can be used
  • How to change Integration Services Catalog (SSISDB) database Master Key encryption password?
  • Database Issue: The transaction log for database ‘db_name’ is full due to ‘ACTIVE_BACKUP_OR_RESTORE’.
  • An Overview on SQL Server Checkpoints

Top 5 Posts

  • Find the size of Index in SQL Server
  • Removing part of string before and after specific character using Transact-SQL string functions
  • Determining when statistics were last updated in SQL Server?
  • SQL Server: Converting binary data to a hexadecimal string
  • Availability databases in unhealthy data synchronization state (Error: 35285, Severity: 16, State: 1.)

Category Cloud

General Tips

Click to subscribe to this blog and receive notifications of new posts by email.

Join 3,359 other subscribers

Copyright

All of the entries on this blog are copyright by Basit Farooq. The full content of any post (a post is an entry on the blog) may not be published elsewhere without prior permission from the copyright holder. Excerpts from blog posts may be posted elsewhere providing they are short (around 10% of the article) and are attributed to me by name and with a link back to this blog, currently located at the following address: http://basitaalishan.com.

The following sites currently have full permission to publish complete copies of posts that are published on this web blog:

Disclaimer

This is personal blog and opinions expressed here represent my own thoughts and not those of my employer. For accuracy and official references, refer to MSDN, Microsoft TechNet, Books Online. I or my employer do not endorse any of the tools / applications / books / concepts mentioned here on my blog. I've simply documented my personal experiences on this blog.

Blog Stats

  • 1,919,615 hits
Blog at WordPress.com.
Privacy & Cookies: This site uses cookies. By continuing to use this website, you agree to their use.
To find out more, including how to control cookies, see here: Cookie Policy
  • Follow Following
    • Basit's SQL Server Tips
    • Join 131 other followers
    • Already have a WordPress.com account? Log in now.
    • Basit's SQL Server Tips
    • Customize
    • Follow Following
    • Sign up
    • Log in
    • Report this content
    • View site in Reader
    • Manage subscriptions
    • Collapse this bar
%d bloggers like this: