-
Notifications
You must be signed in to change notification settings - Fork 16
/
Copy pathОтсутствующие индексы.sql
56 lines (54 loc) · 2.86 KB
/
Отсутствующие индексы.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
--
--Получение отсутствующих индексов по данным статистики SQL Server
--
SELECT
@@ServerName AS ServerName, -- Имя сервера
DB_NAME() AS DBName, -- Имя базы
t.name AS 'Affected_table', -- Имя таблицы
(LEN(ISNULL(ddmid.equality_columns, N'')
+ CASE WHEN ddmid.equality_columns IS NOT NULL
AND ddmid.inequality_columns IS NOT NULL THEN ','
ELSE ''
END) - LEN(REPLACE(ISNULL(ddmid.equality_columns, N'')
+ CASE WHEN ddmid.equality_columns
IS NOT NULL
AND ddmid.inequality_columns
IS NOT NULL
THEN ','
ELSE ''
END, ',', '')) ) + 1 AS K, -- Количество ключей в индексе
COALESCE(ddmid.equality_columns, '')
+ CASE WHEN ddmid.equality_columns IS NOT NULL
AND ddmid.inequality_columns IS NOT NULL THEN ','
ELSE ''
END + COALESCE(ddmid.inequality_columns, '') AS Keys, -- Ключевые столбцы индекса
COALESCE(ddmid.included_columns, '') AS [include], -- Неключевые столбцы индекса
'Create NonClustered Index IX_' + t.name + '_missing_'
+ CAST(ddmid.index_handle AS VARCHAR(20))
+ ' On ' + ddmid.[statement] COLLATE database_default
+ ' (' + ISNULL(ddmid.equality_columns, '')
+ CASE WHEN ddmid.equality_columns IS NOT NULL
AND ddmid.inequality_columns IS NOT NULL THEN ','
ELSE ''
END + ISNULL(ddmid.inequality_columns, '') + ')'
+ ISNULL(' Include (' + ddmid.included_columns + ');', ';')
AS sql_statement, -- Команда для создания индекса
ddmigs.user_seeks, -- Количество операций поиска
ddmigs.user_scans, -- Количество операций сканирования
CAST(( ddmigs.user_seeks + ddmigs.user_scans)
* ddmigs.avg_user_impact AS BIGINT) AS 'est_impact',
avg_user_impact, -- Средний процент выигрыша
ddmigs.last_user_seek, -- Последняя операция поиска
( SELECT DATEDIFF(Second, create_date, GETDATE()) Seconds
FROM sys.databases
WHERE name = 'tempdb'
) SecondsUptime
FROM sys.dm_db_missing_index_groups ddmig
INNER JOIN sys.dm_db_missing_index_group_stats ddmigs
ON ddmigs.group_handle = ddmig.index_group_handle
INNER JOIN sys.dm_db_missing_index_details ddmid
ON ddmig.index_handle = ddmid.index_handle
INNER JOIN sys.tables t ON ddmid.OBJECT_ID = t.OBJECT_ID
WHERE ddmid.database_id = DB_ID()
ORDER BY est_impact DESC;
GO