Skip to content

Commit 2515f32

Browse files
authored
Update SSRS.Report_Subscription.sql
1 parent cf0a836 commit 2515f32

File tree

1 file changed

+52
-31
lines changed

1 file changed

+52
-31
lines changed

SSRS.Report_Subscription.sql

+52-31
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,17 @@
44
'------------------------------------------------------------------------
55
*/
66

7+
:setvar _server "Server1"
8+
:setvar _user "***username***"
9+
:setvar _password "***password***"
10+
:setvar _database "ReportServer"
11+
:connect $(_server) -U $(_user) -P $(_password)
12+
13+
USE [$(_database)];
14+
GO
15+
16+
17+
DECLARE @all_value AS VARCHAR(100)
718
DECLARE @ReportFolder AS VARCHAR(100)
819
DECLARE @ReportName AS VARCHAR(100)
920
DECLARE @EmailLike AS VARCHAR(100)
@@ -14,6 +25,7 @@ DECLARE @EventStatus AS VARCHAR(50)
1425
DECLARE @Current AS VARCHAR(50)
1526
DECLARE @LastSubscriptionDate AS DATETIME
1627

28+
SET @all_value = '<ALL>'
1729
SET @ReportFolder = '<ALL>'
1830
SET @ReportName = '<ALL>'
1931
SET @EmailLike = NULL
@@ -24,21 +36,13 @@ SET @EventStatus = '<ALL>' -- status from ReportServer.dbo.ExecutionLog
2436
SET @Current = '<ALL>'
2537
SET @LastSubscriptionDate = NULL --getdate()-1
2638

27-
:setvar _server "Server1"
28-
:setvar _user "***username***"
29-
:setvar _password "***password***"
30-
:setvar _database "ReportServer"
31-
:connect $(_server) -U $(_user) -P $(_password)
32-
33-
USE [$(_database)];
34-
GO
35-
39+
*/
3640

3741
;WITH
3842
report_users
3943
AS
4044
(
41-
SELECT UserID, SimpleUserName = UPPER(RIGHT(UserName,(LEN(UserName)-CHARINDEX('\',UserName)))) FROM dbo.Users
45+
SELECT UserID, UserName, SimpleUserName = UPPER(RIGHT(UserName,(LEN(UserName)-CHARINDEX('\',UserName)))) FROM dbo.Users
4246
)
4347
,
4448
report_catalog
@@ -49,22 +53,22 @@ AS
4953
, c.CreatedById
5054
, c.ModifiedById
5155
, c.[Type]
52-
, c.Name
56+
, c.[Name]
5357
, c.[Description]
5458
, c.Parameter
5559
, ReportCreationDate = CONVERT(DATETIME, CONVERT(VARCHAR(11), c.CreationDate, 13))
5660
, ReportModifiedDate = CONVERT(DATETIME, CONVERT(VARCHAR(11), c.ModifiedDate, 13))
5761
, ReportFolder =
5862
CASE
5963
WHEN c.Path = '/' + c.Name THEN ''
60-
ELSE SUBSTRING(c.Path, 2, Len(c.Path)-Len(c.Name)-2)
64+
ELSE SUBSTRING(c.[Path], 2, Len(c.[Path])-Len(c.[Name])-2)
6165
END
6266
, ReportPath = c.[Path]
6367
, UrlPath = 'http://' + Host_Name() + '/Reports/Pages/Folder.aspx?ItemPath=%2f'
6468
, ReportDefinition = CONVERT(VARCHAR(MAX),CONVERT(VARBINARY(MAX),c.content))
6569
FROM
6670
dbo.Catalog AS c
67-
WHERE c.Type = 2
71+
WHERE c.[Type] = 2
6872
)
6973
,
7074
subscription_days
@@ -252,7 +256,7 @@ AS
252256
, sch.DaysOfMonth
253257
, sch.[Month]
254258
, sch.MonthlyWeek
255-
, JobName = sj.name
259+
--, JobName = sj.name
256260
, sch.ScheduleName
257261
, sch.ScheduleDays
258262
, sch.SchDaySun
@@ -271,7 +275,7 @@ AS
271275
dbo.Subscriptions AS s
272276
LEFT JOIN dbo.Notifications AS n ON n.SubscriptionID = s.SubscriptionID AND s.Report_OID = n.ReportID
273277
LEFT JOIN dbo.ReportSchedule AS rs ON s.SubscriptionID = rs.SubscriptionID
274-
LEFT JOIN MSDB.dbo.sysjobs AS sj ON sj.name = CAST(rs.ScheduleID AS VARCHAR(255))
278+
--LEFT JOIN MSDB.dbo.sysjobs AS sj ON sj.name = CAST(rs.ScheduleID AS VARCHAR(255))
275279
LEFT JOIN subscription_schedule AS sch ON rs.ScheduleID = sch.ScheduleID
276280
WHERE
277281
1=1
@@ -321,7 +325,7 @@ SELECT
321325
, s.DaysOfMonth
322326
, s.[Month]
323327
, s.MonthlyWeek
324-
, s.JobName
328+
, JobName = NULL --, s.JobName
325329
, s.ScheduleName
326330
, s.ScheduleDays
327331
, s.SchDaySun
@@ -336,12 +340,12 @@ SELECT
336340
, s.Flags
337341
, s.RecurrenceType
338342
, s.[State]
339-
, EventStatus = el.Status
343+
, EventStatus = el.[Status]
340344
, EventDateTime = el.TimeEnd
341345
FROM
342346
report_catalog AS c
343347
INNER JOIN report_subscription AS s ON s.Report_OID = c.ItemID
344-
LEFT OUTER JOIN (SELECT b.ReportID, b.Status, b.TimeEnd
348+
LEFT OUTER JOIN (SELECT b.ReportID, b.[Status], b.TimeEnd
345349
FROM dbo.ExecutionLog b
346350
INNER JOIN (SELECT ReportID, MAX(TimeEnd) AS TimeEnd
347351
FROM dbo.ExecutionLog
@@ -351,17 +355,34 @@ FROM
351355
LEFT OUTER JOIN report_users AS urm ON c.ModifiedById = urm.UserID
352356
LEFT OUTER JOIN report_users AS usc ON s.OwnerID = usc.UserID
353357
LEFT OUTER JOIN report_users AS usm ON s.ModifiedByID = usm.UserID
354-
WHERE c.Type = 2
355-
AND (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)))
356-
LIKE '%' + @EmailLike + '%' OR @EmailLike IS NULL
357-
OR 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
358+
WHERE
359+
1=1
360+
AND c.[Type] = 2
361+
AND (@all_value IN (@ReportFolder) OR c.ReportFolder IN(@ReportFolder))
362+
AND (@all_value IN (@ReportFolder) OR CHARINDEX(@ReportFolder, c.ReportPath) > 0)
363+
AND (@all_value IN(@ReportName) OR c.[Name] IN(@ReportName))
364+
AND (@all_value IN(@EventStatus) OR el.[Status] IN(@EventStatus))
365+
AND (@all_value IN(@Current) OR CASE WHEN s.ScheduleEndDate IS NULL THEN 'Current' WHEN s.ScheduleEndDate IS NOT NULL THEN 'Non Current' END = @Current)
366+
AND (@all_value IN(@SubscriptionStatus) OR s.SubscriptionLastStatus LIKE '%' + @SubscriptionStatus + '%')
367+
AND (s.LastRunTime >= @LastSubscriptionDate OR @LastSubscriptionDate IS NULL)
368+
AND
369+
(
370+
(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)))
371+
LIKE '%' + @EmailLike + '%' OR @EmailLike IS NULL
372+
)
373+
OR
374+
(
375+
CASE CHARINDEX('<Name>CC</Name><Value>', s.ExtensionSettings)
376+
WHEN 0 THEN ''
377+
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)))
378+
END
358379
LIKE '%' + @EmailLike + '%'
359-
OR 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
360-
LIKE '%' + @EmailLike + '%') -- search for a name in the email to field
361-
AND ('<ALL>' IN(@EventStatus) OR el.Status IN(@EventStatus))
362-
AND ('ALL' = @SubscriptionStatus OR s.SubscriptionLastStatus LIKE '%' + @SubscriptionStatus + '%')
363-
AND ('<ALL>' IN (@ReportFolder) OR c.ReportFolder IN(@ReportFolder))
364-
AND ('<ALL>' IN (@ReportFolder) OR CHARINDEX(@ReportFolder, c.ReportPath) > 0)
365-
AND ('<ALL>' IN(@ReportName) OR c.Name IN(@ReportName))
366-
AND ('<ALL>' IN(@Current) OR CASE WHEN s.ScheduleEndDate IS NULL THEN 'Current' WHEN s.ScheduleEndDate IS NOT NULL THEN 'Non Current' END = @Current)
367-
AND (s.LastRunTime >= @LastSubscriptionDate OR @LastSubscriptionDate IS NULL)
380+
)
381+
OR
382+
(
383+
CASE CHARINDEX('<Name>BCC</Name><Value>', s.ExtensionSettings)
384+
WHEN 0 THEN ''
385+
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)))
386+
END
387+
LIKE '%' + @EmailLike + '%')
388+
)

0 commit comments

Comments
 (0)