-
Notifications
You must be signed in to change notification settings - Fork 41
/
sp_ChangeJobOwnerShip.sql
64 lines (48 loc) · 1.98 KB
/
sp_ChangeJobOwnerShip.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
USE [master]
GO
/******************************************************************
Author: Adrian Buckman
Revision date: 22/09/2017
Version: 1
© www.sqlundercover.com
Description: Produce a script that will provide ALTER statements to change the Agent Job
ownerships to the new owner and also ALTER statements to revert back to the old owner
This script is for personal, educational, and internal
corporate purposes, provided that this header is preserved. Redistribution or sale
of this script,in whole or in part, is prohibited without the author's express
written consent.
The software is provided "as is", without warranty of any kind, express or
implied, including but not limited to the warranties of merchantability,
fitness for a particular purpose and noninfringement. in no event shall the
authors or copyright holders be liable for any claim, damages or other
liability, whether in an action of contract, tort or otherwise, arising from,
out of or in connection with the software or the use or other dealings in the
software.
******************************************************************/
CREATE PROCEDURE [dbo].[sp_ChangeJobOwnerShip]
(@JobOwner NVARCHAR(128) = NULL,
@Help BIT = 0
)
AS
IF @Help = 1
BEGIN
PRINT 'Parameters:
@@JobOwner NVARCHAR(128) - Set the new owner name here';
END;
IF @Help = 0
BEGIN
DECLARE @UserSid VARBINARY= SUSER_SID(@JobOwner);
IF @UserSid IS NOT NULL
BEGIN
SELECT [Name] AS [JobName],
COALESCE(SUSER_SNAME([Jobs].[owner_sid]),'') AS [CurrentOwner],
'EXEC msdb.dbo.sp_update_job @job_name=N'''+[Name]+''', @owner_login_name=N'''+@JobOwner+''';' AS [ChangeToNewOwner],
'EXEC msdb.dbo.sp_update_job @job_name=N'''+[Name]+''', @owner_login_name=N'''+COALESCE(SUSER_SNAME([Jobs].[owner_sid]),'')+''';' AS [RevertToOriginalOwner]
FROM [MSDB].[dbo].[sysjobs] [Jobs]
WHERE [Jobs].[owner_sid] != @UserSid;
END;
ELSE
BEGIN
RAISERROR('No SID found for the owner name you have provided - please check the owner name and try again',11,1);
END;
END;