Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Automatically change the Owner on SQL Agent job Expand / Collapse
Author
Message
Posted Monday, November 02, 2009 7:45 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Friday, April 04, 2014 12:14 PM
Points: 361, Visits: 251
We have a number of maintenance plans built in Management Studio. We change the owner on the Agent jobs that run the maintenance plans to a be a "AgentService" login so all our Agent jobs run under this one global login (each server has their own). But whenever I change a maintenance plan, the owner of the Agent job changes. I need to remember to change each step back to the "AgentService" owner.

First of all, is there a way to change this so the Owner stays intact? Second, if not, does anybody know why SQL Server has this built in their system this way? It drives me crazy.


Thanks for your help!
Post #812372
Posted Tuesday, November 03, 2009 2:35 PM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Today @ 10:28 AM
Points: 414, Visits: 2,859
You can use these two snippets, I got them from a bog I believe:

--SQL 2005
UPDATE msdb.dbo.sysdtspackages90
SET ownersid = 0x01
where packagetype = 6

--SQL 2008
UPDATE msdb.dbo.sysssispackages
SET [ownersid] = SUSER_SID('sa')
where packagetype = 6

Andrew



Post #813242
Posted Wednesday, November 04, 2009 6:36 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Friday, April 04, 2014 12:14 PM
Points: 361, Visits: 251
Thank you! This is a huge help. I am posting the little script I wrote (for SQL2005) for anyone's additional reference.

--To view all the packages and their owners.
SELECT dts.name AS package_name
,SUSER_SNAME(dts.ownersid) AS package_owner
FROM msdb.dbo.sysdtspackages90 dts
ORDER BY package_name

--To view all the info on the maintenance plans
SELECT *
FROM msdb.dbo.sysdtspackages90
WHERE packagetype = 6

--Find out the OwnersId for the login you want to use.
SELECT loginname, sid
FROM syslogins

--To Update the owner
UPDATE msdb.dbo.sysdtspackages90 SET
ownersid = 0x0105000000000005150000000421C9C7B2AB5D056CCD5020D82A0000 --Copy/Pasted from above script
--WHERE name = 'UserBackup' --Change a specific SSIS package
WHERE packagetype = 6 --To change all maintenance plans
Post #813562
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse