I've got a subscription on SSRS showing as disabled, I'd really like to find out which user has disabled it as this was not meant to be disabled. Is there any way of finding out via SSMS? I've not been able to find any of this info so far when trawling the tables. Thanks
CodePudding user response:
The following SQL will return all your subscriptions. I've added a column [IsDisabled]
if the subscription is disabled. [SubscriptionModifiedBy]
is who modified the subscription.
I have a report build using this SQL in my GitHub project.
WITH
report_users
AS
(
SELECT
[UserID]
, [UserName]
, [SimpleUserName] = LOWER(RIGHT([UserName], (LEN([UserName]) - CHARINDEX('\', [UserName]))))
FROM
[dbo].[Users] WITH(NOLOCK)
)
,
report_catalog
AS
(
SELECT
c.[ItemID]
, c.[CreatedById]
, c.[ModifiedById]
, c.[Type]
, c.[Name]
, c.[Description]
, c.[Parameter]
, [ReportCreationDate] = c.[CreationDate]
, [ReportModifiedDate] = c.[ModifiedDate]
, [ReportFolder] =
CASE
WHEN c.Path = '/' c.Name THEN ''
ELSE SUBSTRING(c.[Path], 2, Len(c.[Path])-Len(c.[Name])-2)
END
, [ReportPath] = c.[Path]
, [ReportDefinition] = CONVERT(VARCHAR(MAX),CONVERT(VARBINARY(MAX), c.[content]))
FROM
[dbo].[Catalog] AS c WITH (NOLOCK)
WHERE
1=1
AND c.[Type] IN(2, 4)
)
SELECT
c.[ItemID]
, c.[Name]
, c.[Description]
, c.[Type]
, c.[Parameter]
, c.[ReportFolder]
, c.[ReportPath]
, s.[SubscriptionID]
, s.[Report_OID]
, [SubscriptionDescription] = s.[Description]
, s.[ExtensionSettings]
, s.[EventType]
, [RunTime] = CONVERT(VARCHAR(5), s.[LastRunTime], 8)
, [LastRunDate] = CONVERT(VARCHAR(11), s.[LastRunTime], 13)
, [LastRunTime] = CAST(CONVERT(CHAR(16), s.[LastRunTime], 113) AS DATETIME)
, [SubscriptionType] = CASE WHEN CAST(s.[DataSettings] AS NVARCHAR(50)) IS NOT NULL THEN 'Data-Driven' ELSE 'Standard' END
, s.[DeliveryExtension]
, s.[MatchData]
, [SubscriptionLastStatus] = s.[LastStatus]
, [StatusFail] = CASE WHEN s.[LastStatus] LIKE '%Mail sent%' THEN 'N' ELSE 'Y' END
, [EmailSubject] = CASE CHARINDEX('<Name>SUBJECT</Name><Value>', s.ExtensionSettings) WHEN 0 THEN '' ELSE SUBSTRING(s.ExtensionSettings, LEN('<Name>SUBJECT</Name><Value>') CHARINDEX('<Name>SUBJECT</Name><Value>', s.ExtensionSettings), CHARINDEX('</Value>', s.ExtensionSettings, CHARINDEX('<Name>SUBJECT</Name><Value>', s.ExtensionSettings) 1) - (LEN('<Name>SUBJECT</Name><Value>') CHARINDEX('<Name>SUBJECT</Name><Value>', s.ExtensionSettings))) END
, [EmailTo] = SUBSTRING(s.ExtensionSettings, LEN('<Name>TO</Name><Value>') CHARINDEX('<Name>TO</Name><Value>', s.ExtensionSettings), CHARINDEX('</Value>', s.ExtensionSettings, CHARINDEX('<Name>TO</Name><Value>', s.ExtensionSettings) 1) - (LEN('<Name>TO</Name><Value>') CHARINDEX('<Name>TO</Name><Value>', s.ExtensionSettings)))
, [EmailCc] = CASE CHARINDEX('<Name>CC</Name><Value>', s.ExtensionSettings) WHEN 0 THEN '' ELSE SUBSTRING(s.ExtensionSettings, LEN('<Name>CC</Name><Value>') CHARINDEX('<Name>CC</Name><Value>', s.ExtensionSettings), CHARINDEX('</Value>', s.ExtensionSettings, CHARINDEX('<Name>CC</Name><Value>', s.ExtensionSettings) 1) - (LEN('<Name>CC</Name><Value>') CHARINDEX('<Name>CC</Name><Value>', s.ExtensionSettings))) END
, [EmailBcc] = CASE CHARINDEX('<Name>BCC</Name><Value>', s.ExtensionSettings) WHEN 0 THEN '' ELSE SUBSTRING(s.ExtensionSettings, LEN('<Name>BCC</Name><Value>') CHARINDEX('<Name>BCC</Name><Value>', s.ExtensionSettings), CHARINDEX('</Value>', s.ExtensionSettings, CHARINDEX('<Name>BCC</Name><Value>', s.ExtensionSettings) 1) - (LEN('<Name>BCC</Name><Value>') CHARINDEX('<Name>BCC</Name><Value>', s.ExtensionSettings))) END
, [EmailComment] = CASE CHARINDEX('<Name>Comment</Name><Value>', s.ExtensionSettings) WHEN 0 THEN '' ELSE SUBSTRING(s.ExtensionSettings, LEN('<Name>Comment</Name><Value>') CHARINDEX('<Name>Comment</Name><Value>', s.ExtensionSettings), CHARINDEX('</Value>', s.ExtensionSettings, CHARINDEX('<Name>Comment</Name><Value>', s.ExtensionSettings) 1) - (LEN('<Name>Comment</Name><Value>') CHARINDEX('<Name>Comment</Name><Value>', s.ExtensionSettings))) END
, [EmailIncludeLink] = CASE CHARINDEX('<Name>IncludeLink</Name><Value>', s.ExtensionSettings) WHEN 0 THEN '' ELSE SUBSTRING(s.ExtensionSettings, LEN('<Name>IncludeLink</Name><Value>') CHARINDEX('<Name>IncludeLink</Name><Value>', s.ExtensionSettings), CHARINDEX('</Value>', s.ExtensionSettings, CHARINDEX('<Name>IncludeLink</Name><Value>', s.ExtensionSettings) 1) - (LEN('<Name>IncludeLink</Name><Value>') CHARINDEX('<Name>IncludeLink</Name><Value>', s.ExtensionSettings))) END
, [EmailRenderFormat] = CASE CHARINDEX('<Name>RenderFormat</Name><Value>', s.ExtensionSettings) WHEN 0 THEN '' ELSE SUBSTRING(s.ExtensionSettings, LEN('<Name>RenderFormat</Name><Value>') CHARINDEX('<Name>RenderFormat</Name><Value>', s.ExtensionSettings), CHARINDEX('</Value>', s.ExtensionSettings, CHARINDEX('<Name>RenderFormat</Name><Value>', s.ExtensionSettings) 1) - (LEN('<Name>RenderFormat</Name><Value>') CHARINDEX('<Name>RenderFormat</Name><Value>', s.ExtensionSettings))) END
, [EmailPriority] = CASE CHARINDEX('<Name>Priority</Name><Value>', s.ExtensionSettings) WHEN 0 THEN '' ELSE SUBSTRING(s.ExtensionSettings, LEN('<Name>Priority</Name><Value>') CHARINDEX('<Name>Priority</Name><Value>', s.ExtensionSettings), CHARINDEX('</Value>', s.ExtensionSettings, CHARINDEX('<Name>Priority</Name><Value>', s.ExtensionSettings) 1) - (LEN('<Name>Priority</Name><Value>') CHARINDEX('<Name>Priority</Name><Value>', s.ExtensionSettings))) END
, s.[LastStatus]
, rs.[ScheduleID]
, [IsDisabled] = CASE WHEN s.[LastStatus] = 'Disabled' THEN 1 ELSE 0 END
, [SubscriptionOwner] = usc.[SimpleUserName]
, [SubscriptionModifiedBy] = usm.[SimpleUserName]
, [SubscriptionModifiedDate] = s.[ModifiedDate]
, [ReportCreatedBy] = urc.[SimpleUserName]
, c.[ReportCreationDate]
, [ReportModifiedBy] = urm.[SimpleUserName]
, c.[ReportModifiedDate]
FROM
[dbo].[Subscriptions] AS s WITH (NOLOCK)
LEFT JOIN report_catalog AS c ON s.[Report_OID] = c.[ItemID]
LEFT JOIN [dbo].[Notifications] AS n WITH (NOLOCK) ON n.[SubscriptionID] = s.[SubscriptionID] AND s.[Report_OID] = n.[ReportID]
LEFT JOIN [dbo].[ReportSchedule] AS rs WITH (NOLOCK) ON s.[SubscriptionID] = rs.[SubscriptionID]
LEFT JOIN report_users AS urc ON c.[CreatedById] = urc.[UserID]
LEFT JOIN report_users AS urm ON c.[ModifiedById] = urm.[UserID]
LEFT JOIN report_users AS usc ON s.[OwnerID] = usc.[UserID]
LEFT JOIN report_users AS usm ON s.[ModifiedByID] = usm.[UserID]