Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Automatically change the Owner on SQL Agent job


Automatically change the Owner on SQL Agent job

Author
Message
FordMom
FordMom
SSC-Addicted
SSC-Addicted (434 reputation)SSC-Addicted (434 reputation)SSC-Addicted (434 reputation)SSC-Addicted (434 reputation)SSC-Addicted (434 reputation)SSC-Addicted (434 reputation)SSC-Addicted (434 reputation)SSC-Addicted (434 reputation)

Group: General Forum Members
Points: 434 Visits: 284
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!
andrewkane17
andrewkane17
SSC-Addicted
SSC-Addicted (475 reputation)SSC-Addicted (475 reputation)SSC-Addicted (475 reputation)SSC-Addicted (475 reputation)SSC-Addicted (475 reputation)SSC-Addicted (475 reputation)SSC-Addicted (475 reputation)SSC-Addicted (475 reputation)

Group: General Forum Members
Points: 475 Visits: 3223
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



FordMom
FordMom
SSC-Addicted
SSC-Addicted (434 reputation)SSC-Addicted (434 reputation)SSC-Addicted (434 reputation)SSC-Addicted (434 reputation)SSC-Addicted (434 reputation)SSC-Addicted (434 reputation)SSC-Addicted (434 reputation)SSC-Addicted (434 reputation)

Group: General Forum Members
Points: 434 Visits: 284
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
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search