Skip to content

Commit 99efe3e

Browse files
committed
Added audit stored procedure for unused report sources
1 parent 360a90c commit 99efe3e

File tree

2 files changed

+141
-0
lines changed

2 files changed

+141
-0
lines changed

Miscellaneous/Miscellaneous.vbproj

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -154,6 +154,7 @@
154154
<Content Include="Scripts\SQL\Report_Datasets.sql" />
155155
<Content Include="Scripts\SQL\Report_Snapshots.sql" />
156156
<Content Include="Scripts\SQL\Source_Control_Current.sql" />
157+
<Content Include="Scripts\SQL\Unused_Stored_Procedures.sql" />
157158
<Content Include="Scripts\SQL\Update_Subscription_Owner.sql" />
158159
</ItemGroup>
159160
<ItemGroup>
Lines changed: 140 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,140 @@
1+
USE [YourDataWarehouse]
2+
GO
3+
4+
CREATE PROCEDURE [admin].[Unused_Stored_Procedures]
5+
AS
6+
BEGIN
7+
8+
DROP TABLE IF EXISTS [#pbirs_report_datasets];
9+
DROP TABLE IF EXISTS [#false_positives];
10+
11+
SELECT tbl.* INTO #false_positives FROM (VALUES
12+
( 'dbo.KeepThisStoredProcedure1')
13+
, ( 'dbo.KeepThisStoredProcedure2')
14+
, ( 'report.KeepThisStoredProcedure1')
15+
, ( 'report.KeepThisStoredProcedure2')
16+
) tbl ([StoredProcedureName]);
17+
18+
WITH
19+
catalog_xml
20+
AS
21+
(
22+
SELECT
23+
*
24+
, [report_folder] =
25+
CASE
26+
WHEN [Path] = '/' + [Name] THEN ''
27+
ELSE SUBSTRING([Path], 2, LEN([Path])-LEN([Name])-2)
28+
END
29+
, [ContentXml] = (CONVERT(XML, CONVERT(VARBINARY(MAX), [Content])))
30+
FROM
31+
[ReportServer].[dbo].[Catalog] WITH(NOLOCK)
32+
WHERE
33+
[Type] = 2
34+
)
35+
,
36+
data_sources
37+
AS
38+
(
39+
SELECT
40+
[r].[ItemID]
41+
, [r].[LocalDataSourceName]
42+
, [DataProvider] = [r].[DataProvider]
43+
, [ConnectionString] = [r].[ConnectionString]
44+
FROM
45+
(
46+
SELECT
47+
[c].*
48+
, [LocalDataSourceName] = [DataSourceXml].value('@Name', 'NVARCHAR(260)')
49+
, [DataProvider] = [DataSourceXml].value('(*:ConnectionProperties/*:DataProvider)[1]', 'NVARCHAR(260)')
50+
, [ConnectionString] = [DataSourceXml].value('(*:ConnectionProperties/*:ConnectString)[1]', 'NVARCHAR(MAX)')
51+
FROM
52+
catalog_xml AS [c]
53+
CROSS APPLY [ContentXml].[nodes]('/*:Report/*:DataSources/*:DataSource') AS [DataSource]([DataSourceXml])
54+
WHERE [c].[Type] = 2 -- limit to reports only
55+
) AS [r]
56+
)
57+
,
58+
datasets
59+
AS
60+
(
61+
SELECT
62+
[ItemID]
63+
, [DataSetName] = [QueryXml].value('@Name', 'NVARCHAR(256)')
64+
, [DataSourceName] = [QueryXml].value('(*:Query/*:DataSourceName)[1]', 'NVARCHAR(260)')
65+
, [CommandType] = [QueryXml].value('(*:Query/*:CommandType)[1]', 'NVARCHAR(15)')
66+
, [CommandText] = [QueryXml].value('(*:Query/*:CommandText)[1]', 'NVARCHAR(MAX)')
67+
, [report_folder]
68+
FROM
69+
catalog_xml
70+
CROSS APPLY [ContentXml].[nodes]('/*:Report/*:DataSets/*:DataSet') AS [QueryData]([QueryXml])
71+
)
72+
SELECT
73+
[Name]
74+
, [Path]
75+
, [LocalDataSourceName]
76+
, [DataSetName]
77+
, [CommandType] = ISNULL([CommandType], 'Text')
78+
, [CommandText]
79+
INTO [#pbirs_report_datasets]
80+
FROM
81+
datasets AS [ds]
82+
INNER JOIN data_sources AS [src] ON [src].[ItemID] = [ds].[ItemID] AND [src].[LocalDataSourceName] = [ds].[DataSourceName]
83+
INNER JOIN [ReportServer].[dbo].[Catalog] AS [c] WITH(NOLOCK) ON [ds].[ItemID] = [c].[ItemID];
84+
85+
WITH
86+
report_stored_procedures
87+
AS
88+
(
89+
SELECT DISTINCT
90+
[StoredProcedureName] = CASE WHEN [CommandText] LIKE 'report.%' THEN [CommandText] ELSE 'dbo.' + [CommandText] END
91+
FROM
92+
[#pbirs_report_datasets]
93+
WHERE
94+
1 = 1
95+
AND [CommandType] = 'StoredProcedure'
96+
AND [LocalDataSourceName] IN('REPORT_DATA_SOURCE1', 'REPORT_DATA_SOURCE2')
97+
)
98+
,
99+
database_stored_procedures
100+
AS
101+
(
102+
SELECT
103+
[SPECIFIC_SCHEMA]
104+
, [SPECIFIC_NAME]
105+
, [StoredProcedureName] = [SPECIFIC_SCHEMA] + '.' + [SPECIFIC_NAME]
106+
, [CreateDate] = [CREATED]
107+
, [ModifiedDate] = [LAST_ALTERED]
108+
FROM [INFORMATION_SCHEMA].[ROUTINES]
109+
WHERE
110+
1=1
111+
AND [ROUTINE_TYPE] = 'PROCEDURE'
112+
AND
113+
(
114+
([SPECIFIC_SCHEMA] = 'dbo' AND [SPECIFIC_NAME] LIKE '%_report_%')
115+
OR
116+
([SPECIFIC_SCHEMA] = 'report')
117+
)
118+
)
119+
SELECT
120+
[dsp].[StoredProcedureName]
121+
, [dsp].[CreateDate]
122+
, [dsp].[ModifiedDate]
123+
FROM
124+
[database_stored_procedures] AS [dsp]
125+
LEFT JOIN [report_stored_procedures] AS [rsp] ON [dsp].[StoredProcedureName] = [rsp].[StoredProcedureName]
126+
LEFT JOIN [#false_positives] AS fp ON [dsp].[StoredProcedureName] = [fp].[StoredProcedureName]
127+
WHERE
128+
1=1
129+
AND [dsp].[StoredProcedureName] NOT LIKE '%zzz%'
130+
--AND [dsp].[StoredProcedureName] LIKE '%zzz%'
131+
AND [rsp].[StoredProcedureName] IS NULL
132+
AND [fp].[StoredProcedureName] IS NULL
133+
ORDER BY 1;
134+
135+
DROP TABLE IF EXISTS [#pbirs_report_datasets];
136+
DROP TABLE IF EXISTS [#false_positives];
137+
138+
END
139+
140+
GO

0 commit comments

Comments
 (0)