@@ -2,11 +2,26 @@ USE DBA_MONITOR
22GO
33DROP PROCEDURE IF EXISTS SP_SEND_INDEXREPORT
44GO
5- CREATE PROCEDURE SP_SEND_INDEXREPORT
5+ CREATE PROCEDURE SP_SEND_INDEXREPORT
6+ @Indexfrag bit = 1 , -- Apresenta fragmentação dos índices
7+ @IndexfragPercent tinyint = 50 , -- Apenas índices com mais de 50% de fragmentação.
8+ @IndexfragPages int = 10000 , -- Apenas índices com mais de 10000 páginas
9+ @IndexLowutilization bit = 1 , -- Índices com baixa utilização
10+ @IndexLowutilizationMonths tinyint = 3 , -- Avaliar últimos 3 meses de coleta
11+ @IndexHighUpdates bit = 1 , -- Índices com bastante escrita
12+ @IndexUtilization bit = 1 , -- Índices com bastante leitura
13+ @QtdIndex bit = 1 , -- Quantidade de índices por banco de dados
14+ @IndexDuplicate bit = 1 , -- Apresenta índices duplicados
15+ @IndexDisabled bit = 1 , -- Apresenta índices desabilitados
16+ @IndexPkNonClustered bit = 1 , -- Apresenta índices PK non clustered
17+ @IndexFillFactor bit = 1 , -- Apresenta fill factor dos índices
18+ @IndexFillFactorPercent tinyint = 98 , -- Índices apenas com Fill factor menor que 98
19+ @IndexCompression bit = 1 -- Apresenta índices com compressão
620AS
721DECLARE @EmailBody VARCHAR (MAX )
822
9-
23+ IF (@Indexfrag = 1 )
24+ BEGIN
1025-- INDICES MAIS FRAGMENTADOS
1126DECLARE @Indicesfragmentados NVARCHAR (MAX )
1227
@@ -22,10 +37,12 @@ CAST(
2237FROM
2338(
2439SELECT DATABASE_NAME ,TABLE_NAME,INDEX_NAME,INDEX_TYPE,AVG_FRAGMENTATION_IN_PERCENT,FILL_FACTOR,PAGE_COUNT FROM RESULTADO_SHOWINDEX WHERE CAST (DATE_COLLECTION AS DATE ) = CAST (GETDATE () AS DATE )
25- AND AVG_FRAGMENTATION_IN_PERCENT > 50
40+ AND AVG_FRAGMENTATION_IN_PERCENT > @IndexfragPercent AND PAGE_COUNT > @IndexfragPages
2641 )TAB FOR XML PATH (' tr' ) , TYPE ) AS VARCHAR (MAX )) + N ' </table>'
42+ END
2743
28-
44+ IF (@IndexLowutilization = 1 )
45+ BEGIN
2946-- INDICES POUCO UTILIZADOS
3047DECLARE @Indicespoucoutilizados NVARCHAR (MAX )
3148
4461(
4562SELECT * FROM (
4663SELECT DATABASE_NAME ,TABLE_NAME,INDEX_NAME,AVG (SEEKS + SCANS) AVG_READ, AVG (UPDATES) AVG_WRITE,MIN (LAST_SEEK) FIRST_SEEK,MAX (LAST_UPDATE) LAST_UPDATE,MIN (DATE_COLLECTION) FIRST_COLLECT,MAX (DATE_COLLECTION) LAST_COLLECT
47- FROM RESULTADO_SHOWINDEX WHERE DATE_COLLECTION > DATEADD (MONTH ,- 3 ,GETDATE ())
64+ FROM RESULTADO_SHOWINDEX WHERE DATE_COLLECTION > DATEADD (MONTH ,- @IndexLowutilizationMonths ,GETDATE ())
4865GROUP BY DATABASE_NAME ,TABLE_NAME,INDEX_NAME
4966) TAB WHERE DATEDIFF (DAY ,FIRST_COLLECT,LAST_COLLECT) > 1 AND AVG_READ < 100 AND AVG_WRITE > 1000
5067 )TAB FOR XML PATH (' tr' ) , TYPE ) AS VARCHAR (MAX )) + N ' </table>'
68+ END
5169
70+ IF (@IndexHighUpdates = 1 )
71+ BEGIN
5272-- INDICES MAIS ATUALIZADOS
5373DECLARE @Indicesatualizados NVARCHAR (MAX )
5474
@@ -83,9 +103,10 @@ GROUP BY A.DATABASE_NAME,A.TABLE_NAME,A.INDEX_NAME
83103) TAB WHERE AVG_WRITE_DIA1 > 100
84104ORDER BY AVG_WRITE_DIA1 DESC
85105 )TAB FOR XML PATH (' tr' ) , TYPE ) AS VARCHAR (MAX )) + N ' </table>'
106+ END
86107
87-
88-
108+ IF (@IndexUtilization = 1 )
109+ BEGIN
89110-- INDICES MAIS UTILIZADOS
90111DECLARE @Indicesutilizados NVARCHAR (MAX )
91112
@@ -120,7 +141,10 @@ GROUP BY A.DATABASE_NAME,A.TABLE_NAME,A.INDEX_NAME
120141) TAB WHERE AVG_READ_DIA1 > 100
121142ORDER BY AVG_READ_DIA1 DESC
122143 )TAB FOR XML PATH (' tr' ) , TYPE ) AS VARCHAR (MAX )) + N ' </table>'
144+ END
123145
146+ IF (@QtdIndex = 1 )
147+ BEGIN
124148-- INDICES POR BANCO DE DADOS
125149DECLARE @Indicesperdb NVARCHAR (MAX )
126150
@@ -133,7 +157,10 @@ FROM
133157SELECT DATABASE_NAME ,COUNT (DISTINCT INDEX_NAME) QTD_INDEX FROM RESULTADO_SHOWINDEX WHERE CAST (DATE_COLLECTION AS DATE ) = CAST (GETDATE () AS DATE )
134158GROUP BY DATABASE_NAME
135159 )TAB FOR XML PATH (' tr' ) , TYPE ) AS VARCHAR (MAX )) + N ' </table>'
160+ END
136161
162+ IF (@IndexDisabled = 1 )
163+ BEGIN
137164-- INDICES DESABILITADOS
138165DECLARE @Indicesdesabilitados NVARCHAR (MAX )
139166
@@ -149,8 +176,10 @@ FROM
149176SELECT DATABASE_NAME ,TABLE_NAME,INDEX_NAME,LAST_SEEK,LAST_UPDATE FROM RESULTADO_SHOWINDEX WHERE CAST (DATE_COLLECTION AS DATE ) = CAST (GETDATE () AS DATE )
150177AND IS_DISABLED = ' YES'
151178 )TAB FOR XML PATH (' tr' ) , TYPE ) AS VARCHAR (MAX )) + N ' </table>'
179+ END
152180
153-
181+ IF (@IndexDuplicate = 1 )
182+ BEGIN
154183-- INDICES DUPLICADOS
155184DECLARE @Indicesdeduplicados NVARCHAR (MAX )
156185
@@ -164,7 +193,10 @@ FROM
164193SELECT DATABASE_NAME ,TABLE_NAME,COUNT (COLUMNS) QTD FROM RESULTADO_SHOWINDEX WHERE CAST (DATE_COLLECTION AS DATE ) = CAST (GETDATE () AS DATE )
165194GROUP BY DATABASE_NAME ,TABLE_NAME,COLUMNS HAVING COUNT (COLUMNS) > 1
166195 )TAB FOR XML PATH (' tr' ) , TYPE ) AS VARCHAR (MAX )) + N ' </table>'
196+ END
167197
198+ IF (@IndexPkNonClustered = 1 )
199+ BEGIN
168200-- INDICES PK NONCLUSTEREDS
169201DECLARE @Indicespknoncluster NVARCHAR (MAX )
170202
@@ -182,7 +214,10 @@ FROM
182214SELECT DATABASE_NAME ,TABLE_NAME,INDEX_NAME,INDEX_TYPE,AVG_FRAGMENTATION_IN_PERCENT,FILL_FACTOR,PAGE_COUNT FROM RESULTADO_SHOWINDEX WHERE CAST (DATE_COLLECTION AS DATE ) = CAST (GETDATE () AS DATE )
183215AND PRIMARY_KEY = 1 AND INDEX_TYPE = ' NONCLUSTERED'
184216 )TAB FOR XML PATH (' tr' ) , TYPE ) AS VARCHAR (MAX )) + N ' </table>'
217+ END
185218
219+ IF (@IndexFillFactor = 1 )
220+ BEGIN
186221-- INDICES FILLFACTOR BAIXO
187222DECLARE @Indicesfillfactor NVARCHAR (MAX )
188223
@@ -198,9 +233,12 @@ CAST(
198233FROM
199234(
200235SELECT DATABASE_NAME ,TABLE_NAME,INDEX_NAME,INDEX_TYPE,AVG_FRAGMENTATION_IN_PERCENT,FILL_FACTOR,PAGE_COUNT FROM RESULTADO_SHOWINDEX WHERE CAST (DATE_COLLECTION AS DATE ) = CAST (GETDATE () AS DATE )
201- AND FILL_FACTOR <> 0
236+ AND FILL_FACTOR <> 0 AND FILL_FACTOR < @IndexFillFactorPercent
202237 )TAB FOR XML PATH (' tr' ) , TYPE ) AS VARCHAR (MAX )) + N ' </table>'
238+ END
203239
240+ IF (@IndexCompression = 1 )
241+ BEGIN
204242-- INDICES COMPACTADOS
205243DECLARE @Indicescompactados NVARCHAR (MAX )
206244
219257SELECT DATABASE_NAME ,TABLE_NAME,INDEX_NAME,INDEX_TYPE,DATA_COMPRESSION ,AVG_FRAGMENTATION_IN_PERCENT,FILL_FACTOR,PAGE_COUNT FROM RESULTADO_SHOWINDEX WHERE CAST (DATE_COLLECTION AS DATE ) = CAST (GETDATE () AS DATE )
220258AND DATA_COMPRESSION <> ' NONE'
221259 )TAB FOR XML PATH (' tr' ) , TYPE ) AS VARCHAR (MAX )) + N ' </table>'
222-
260+ END
223261
224262SELECT @EmailBody =
225263 Isnull (@Indicesperdb,' ' ) + Isnull (@Indicesdesabilitados,' ' ) + ISNULL (@Indicesdeduplicados, ' ' )
0 commit comments