Skip to content

shannonlowder.com

Menu
  • About
  • Biml Interrogator Demo
  • Latest Posts
Menu

Changing Job and Database Owners to SA

Posted on August 6, 2012August 6, 2012 by slowder
I’m the Doctor

One of the services we’re trying to flesh out a bit more over at Hive Mind is our standard health check and resolution script.  Every DBA has his or her own set of scripts they carry around, either in a file, or a link to where to find it online.  Merging the best of all these scripts is difficult when you consider all the great resources within the SQL community.  One of the tasks addressed during a SQL Server health check is ownership of objects.

Whenever you have Jobs owned by users you run the risk of that account being removed, disabled, or corrupted in some way.  When that happens, your job is going to start failing you.  In a similar vein, database ownership gives owner a great deal of permission.  Probably more than is really needed to get the job done.  We can address both of these issues with some simple scripting.

In general, I’ll change the job owners to SA without too much worrying.  I still generate a rollback script and hold onto it until well after the change, just in case.  Database ownership is a bit touchier.  Users could have built code that could break if you suddenly remove ownership, and don’t give the affected users explicit permission to do their job!

My suggestion, work with your developers to determine what the minimum level of permission needed (for both the user and any code built and running against the database).  Generate scripts to grant those permissions.  Apply those first, then once you’ve worked out all the bugs in the permission change, change database owners to SA.

Now for the scripts!

Changing Job Owners

/******************************************************************************
Description:   
        Script that change the Jobs Owner to SA.  This Script will
        identify the non SA jobs, then create a rollback and a roll forward script
        that will change their owner as SA
Compatibility  :     2005 +
Input:
        Folder where rollback and roll forward scripts can be stored
*******************************************************************************/

--internal variables
DECLARE @ScriptList TABLE ( ScriptType VARCHAR(20), Script VARCHAR(MAX))

--rollback scripts
INSERT INTO @ScriptList
SELECT
          'rollback' as ScriptType
        , '-- Revert job: [' + j.name + '] to owned by: ['+ sl.name  + ']' + CHAR(13) + CHAR(10)
        + 'EXEC msdb..sp_update_job @job_id = ''' + CONVERT(VARCHAR(36), j.job_id) + ''''
        + ', @owner_login_name = ''' + sl.name + '''' as Script
FROM msdb.dbo.sysjobs j 
LEFT OUTER JOIN sys.syslogins sl
        ON j.owner_sid = sl.sid 
WHERE j.enabled = 1  AND sl.name <> SUSER_SNAME(0x01);

INSERT INTO @ScriptList
SELECT
          'rollforward' as ScriptType
        , 'EXEC msdb..sp_update_job @job_id = ''' + CONVERT(VARCHAR(36), j.job_id) + ''''
        + ', @owner_login_name = ''SA''' as Script
FROM msdb.dbo.sysjobs j 
LEFT OUTER JOIN sys.syslogins sl
        ON j.owner_sid = sl.sid 
WHERE j.enabled = 1  AND sl.name <> SUSER_SNAME(0x01);

--you can either BCP the following results to a rollback file
--or you can run the script in SSMS with ctrl+shift+F and save the results to a file
SELECT * FROM @scriptlist WHERE ScriptType = 'rollback';

--Once you've saved your rollback script.  Save your roll-forward script
SELECT * FROM @scriptlist WHERE ScriptType = 'rollforward';

Changing Database Owners

/******************************************************************************
Description:   
        Script that change the Database Owner to SA.  This Script will
        identify the non SA owned databases, then create a rollback and a roll forward script
        that will change their owner as SA
Compatibility  :     2005 +
Input:
        Folder where rollback and roll forward scripts can be stored
*******************************************************************************/

--internal variables
DECLARE @ScriptList TABLE ( ScriptType VARCHAR(20), Script VARCHAR(MAX))

INSERT INTO @ScriptList
SELECT
          'rollback' as ScriptType
        , '-- Revert database: [' + d.name + '] to owned by: ['+ SUSER_SNAME(owner_sid)  + ']' + CHAR(13) + CHAR(10)
        + 'ALTER AUTHORIZATION ON DATABASE::' + d.name + ' to [' + SUSER_SNAME(owner_sid) + '];'
FROM sys.databases  d
WHERE
        SUSER_SNAME(owner_sid) <> SUSER_SNAME(0x01);    
INSERT INTO @ScriptList
SELECT
          'rollforward' as ScriptType
        , 'ALTER AUTHORIZATION ON DATABASE::' + d.name + ' to SA;'
FROM sys.databases  d
WHERE
        SUSER_SNAME(owner_sid) <> SUSER_SNAME(0x01);  

--you can either BCP the following results to a rollback file
--or you can run the script in SSMS with ctrl+shift+F and save the results to a file
SELECT * FROM @scriptlist WHERE ScriptType = 'rollback';

--Once you've saved your rollback script.  Save your roll-forward script
SELECT * FROM @scriptlist WHERE ScriptType = 'rollforward';

Conclusion

One of the things we’re looking to do with this script is bundle it up with either PowerShell, SQLDiag, or some other tool, so we can simply deploy this script against a new server, and collect all these scripts automatically, with very little fuss or muss.

Do you have any suggestions for improvements to this script? Do you have a standard script you’d like to share? If so, let us know!

Leave a Reply Cancel reply

Your email address will not be published. Required fields are marked *

Recent Posts

  • A New File Interrogator
  • Using Generative AI in Data Engineering
  • Getting started with Microsoft Fabric
  • Docker-based Spark
  • Network Infrastructure Updates

Recent Comments

  1. slowder on Data Engineering for Databricks
  2. Alex Ott on Data Engineering for Databricks

Archives

  • July 2023
  • June 2023
  • March 2023
  • February 2023
  • January 2023
  • December 2022
  • November 2022
  • October 2022
  • October 2018
  • August 2018
  • May 2018
  • February 2018
  • January 2018
  • November 2017
  • October 2017
  • September 2017
  • August 2017
  • June 2017
  • March 2017
  • February 2014
  • January 2014
  • December 2013
  • November 2013
  • October 2013
  • August 2013
  • July 2013
  • June 2013
  • February 2013
  • January 2013
  • August 2012
  • June 2012
  • May 2012
  • April 2012
  • March 2012
  • February 2012
  • January 2012
  • December 2011
  • November 2011
  • October 2011
  • September 2011
  • August 2011
  • July 2011
  • June 2011
  • May 2011
  • April 2011
  • March 2011
  • February 2011
  • January 2011
  • December 2010
  • November 2010
  • October 2010
  • September 2010
  • August 2010
  • July 2010
  • June 2010
  • May 2010
  • April 2010
  • March 2010
  • January 2010
  • December 2009
  • November 2009
  • October 2009
  • September 2009
  • August 2009
  • July 2009
  • June 2009
  • May 2009
  • April 2009
  • March 2009
  • February 2009
  • January 2009
  • December 2008
  • November 2008
  • October 2008
  • September 2008
  • August 2008
  • July 2008
  • June 2008
  • May 2008
  • April 2008
  • March 2008
  • February 2008
  • January 2008
  • November 2007
  • October 2007
  • September 2007
  • August 2007
  • July 2007
  • June 2007
  • May 2007
  • April 2007
  • March 2007
  • February 2007
  • January 2007
  • December 2006
  • November 2006
  • October 2006
  • September 2006
  • August 2006
  • July 2006
  • June 2006
  • May 2006
  • April 2006
  • March 2006
  • February 2006
  • January 2006
  • December 2005
  • November 2005
  • October 2005
  • September 2005
  • August 2005
  • July 2005
  • June 2005
  • May 2005
  • April 2005
  • March 2005
  • February 2005
  • January 2005
  • November 2004
  • September 2004
  • August 2004
  • July 2004
  • April 2004
  • March 2004
  • June 2002

Categories

  • Career Development
  • Data Engineering
  • Data Science
  • Infrastructure
  • Microsoft SQL
  • Modern Data Estate
  • Personal
  • Random Technology
  • uncategorized
© 2025 shannonlowder.com | Powered by Minimalist Blog WordPress Theme