-
-
Notifications
You must be signed in to change notification settings - Fork 61
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Fix job collection issues on RDS caused by permissions.
- Loading branch information
1 parent
ec7b2c7
commit 8a03295
Showing
7 changed files
with
166 additions
and
130 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,31 +1,66 @@ | ||
SELECT J.job_id, | ||
S.name AS originating_server, | ||
J.name, | ||
J.enabled, | ||
J.description, | ||
J.start_step_id, | ||
J.category_id, | ||
C.name AS category, | ||
SUSER_SNAME(J.owner_sid) AS owner, | ||
J.notify_level_eventlog, | ||
J.notify_level_email, | ||
J.notify_level_netsend, | ||
J.notify_level_page, | ||
ISNULL(EmailOp.name,'') AS notify_email_operator, | ||
ISNULL(NetOp.name,'') AS notify_netsend_operator, | ||
ISNULL(PageOp.name,'') AS notify_page_operator, | ||
J.delete_level, | ||
J.date_created, | ||
J.date_modified, | ||
J.version_number, | ||
CASE WHEN EXISTS(SELECT * FROM msdb.dbo.sysjobschedules JS WHERE JS.job_id = J.job_id) THEN CAST(1 AS BIT) ELSE CAST(0 AS BIT) END AS has_schedule, | ||
CASE WHEN EXISTS(SELECT * FROM msdb.dbo.sysjobservers JS WHERE JS.job_id = J.job_id) THEN CAST(1 AS BIT) ELSE CAST(0 AS BIT) END AS has_server, | ||
CASE WHEN EXISTS(SELECT 1 FROM msdb.dbo.sysjobsteps JS WHERE JS.job_id = J.job_id) THEN CAST(1 AS BIT) ELSE CAST(0 AS BIT) END has_step, | ||
CAST(NULL AS BINARY(32)) AS DDLHash, /* Populated using SMO */ | ||
CAST(NULL AS VARBINARY(MAX)) AS DDL /* Populated using SMO */ | ||
FROM msdb.dbo.sysjobs J | ||
LEFT JOIN [msdb].[sys].[servers] AS S ON J.originating_server_id = S.server_id AND J.originating_server_id<>0 /* Return NULL for this server like SMO */ | ||
LEFT JOIN msdb.dbo.syscategories C ON C.category_id = J.category_id | ||
LEFT JOIN msdb.dbo.sysoperators EmailOp ON J.notify_email_operator_id = EmailOp.id | ||
LEFT JOIN msdb.dbo.sysoperators NetOp ON J.notify_netsend_operator_id = NetOp.id | ||
LEFT JOIN msdb.dbo.sysoperators PageOp ON J.notify_page_operator_id = PageOp.id | ||
IF CAST(SERVERPROPERTY('ComputerNamePhysicalNetBIOS') AS NVARCHAR(128)) LIKE 'EC2AMAZ-%' /* RDS */ | ||
BEGIN | ||
SELECT J.job_id, | ||
S.name AS originating_server, | ||
J.name, | ||
J.enabled, | ||
J.description, | ||
J.start_step_id, | ||
J.category_id, | ||
C.name AS category, | ||
SUSER_SNAME(J.owner_sid) AS owner, | ||
J.notify_level_eventlog, | ||
J.notify_level_email, | ||
J.notify_level_netsend, | ||
J.notify_level_page, | ||
'' AS notify_email_operator, | ||
'' AS notify_netsend_operator, | ||
'' AS notify_page_operator, | ||
J.delete_level, | ||
J.date_created, | ||
J.date_modified, | ||
J.version_number, | ||
CAST(NULL AS BIT) AS has_schedule, | ||
CAST(NULL AS BIT) AS has_server, | ||
CAST(NULL AS BIT) AS has_step, | ||
CAST(NULL AS BINARY(32)) AS DDLHash, /* Populated using SMO */ | ||
CAST(NULL AS VARBINARY(MAX)) AS DDL /* Populated using SMO */ | ||
FROM msdb.dbo.sysjobs J | ||
LEFT JOIN [msdb].[sys].[servers] AS S ON J.originating_server_id = S.server_id AND J.originating_server_id<>0 /* Return NULL for this server like SMO */ | ||
LEFT JOIN msdb.dbo.syscategories C ON C.category_id = J.category_id | ||
WHERE SUSER_SNAME(J.owner_sid) <> 'rdsa' | ||
END | ||
ELSE | ||
BEGIN | ||
SELECT J.job_id, | ||
S.name AS originating_server, | ||
J.name, | ||
J.enabled, | ||
J.description, | ||
J.start_step_id, | ||
J.category_id, | ||
C.name AS category, | ||
SUSER_SNAME(J.owner_sid) AS owner, | ||
J.notify_level_eventlog, | ||
J.notify_level_email, | ||
J.notify_level_netsend, | ||
J.notify_level_page, | ||
ISNULL(EmailOp.name,'') AS notify_email_operator, | ||
ISNULL(NetOp.name,'') AS notify_netsend_operator, | ||
ISNULL(PageOp.name,'') AS notify_page_operator, | ||
J.delete_level, | ||
J.date_created, | ||
J.date_modified, | ||
J.version_number, | ||
CASE WHEN EXISTS(SELECT * FROM msdb.dbo.sysjobschedules JS WHERE JS.job_id = J.job_id) THEN CAST(1 AS BIT) ELSE CAST(0 AS BIT) END AS has_schedule, | ||
CASE WHEN EXISTS(SELECT * FROM msdb.dbo.sysjobservers JS WHERE JS.job_id = J.job_id) THEN CAST(1 AS BIT) ELSE CAST(0 AS BIT) END AS has_server, | ||
CASE WHEN EXISTS(SELECT 1 FROM msdb.dbo.sysjobsteps JS WHERE JS.job_id = J.job_id) THEN CAST(1 AS BIT) ELSE CAST(0 AS BIT) END has_step, | ||
CAST(NULL AS BINARY(32)) AS DDLHash, /* Populated using SMO */ | ||
CAST(NULL AS VARBINARY(MAX)) AS DDL /* Populated using SMO */ | ||
FROM msdb.dbo.sysjobs J | ||
LEFT JOIN [msdb].[sys].[servers] AS S ON J.originating_server_id = S.server_id AND J.originating_server_id<>0 /* Return NULL for this server like SMO */ | ||
LEFT JOIN msdb.dbo.syscategories C ON C.category_id = J.category_id | ||
LEFT JOIN msdb.dbo.sysoperators EmailOp ON J.notify_email_operator_id = EmailOp.id | ||
LEFT JOIN msdb.dbo.sysoperators NetOp ON J.notify_netsend_operator_id = NetOp.id | ||
LEFT JOIN msdb.dbo.sysoperators PageOp ON J.notify_page_operator_id = PageOp.id | ||
END |
Oops, something went wrong.