1
0

view_IndexInformation_CurrentDB.sql 62 KB

1234567891011121314151617181920212223242526272829303132333435363738394041424344454647484950515253545556575859606162636465666768697071727374757677787980818283848586878889909192939495969798991001011021031041051061071081091101111121131141151161171181191201211221231241251261271281291301311321331341351361371381391401411421431441451461471481491501511521531541551561571581591601611621631641651661671681691701711721731741751761771781791801811821831841851861871881891901911921931941951961971981992002012022032042052062072082092102112122132142152162172182192202212222232242252262272282292302312322332342352362372382392402412422432442452462472482492502512522532542552562572582592602612622632642652662672682692702712722732742752762772782792802812822832842852862872882892902912922932942952962972982993003013023033043053063073083093103113123133143153163173183193203213223233243253263273283293303313323333343353363373383393403413423433443453463473483493503513523533543553563573583593603613623633643653663673683693703713723733743753763773783793803813823833843853863873883893903913923933943953963973983994004014024034044054064074084094104114124134144154164174184194204214224234244254264274284294304314324334344354364374384394404414424434444454464474484494504514524534544554564574584594604614624634644654664674684694704714724734744754764774784794804814824834844854864874884894904914924934944954964974984995005015025035045055065075085095105115125135145155165175185195205215225235245255265275285295305315325335345355365375385395405415425435445455465475485495505515525535545555565575585595605615625635645655665675685695705715725735745755765775785795805815825835845855865875885895905915925935945955965975985996006016026036046056066076086096106116126136146156166176186196206216226236246256266276286296306316326336346356366376386396406416426436446456466476486496506516526536546556566576586596606616626636646656666676686696706716726736746756766776786796806816826836846856866876886896906916926936946956966976986997007017027037047057067077087097107117127137147157167177187197207217227237247257267277287297307317327337347357367377387397407417427437447457467477487497507517527537547557567577587597607617627637647657667677687697707717727737747757767777787797807817827837847857867877887897907917927937947957967977987998008018028038048058068078088098108118128138148158168178188198208218228238248258268278288298308318328338348358368378388398408418428438448458468478488498508518528538548558568578588598608618628638648658668678688698708718728738748758768778788798808818828838848858868878888898908918928938948958968978988999009019029039049059069079089099109119129139149159169179189199209219229239249259269279289299309319329339349359369379389399409419429439449459469479489499509519529539549559569579589599609619629639649659669679689699709719729739749759769779789799809819829839849859869879889899909919929939949959969979989991000100110021003100410051006100710081009101010111012101310141015101610171018101910201021102210231024102510261027102810291030103110321033103410351036103710381039104010411042104310441045104610471048104910501051105210531054105510561057105810591060106110621063106410651066106710681069107010711072107310741075107610771078107910801081108210831084108510861087108810891090109110921093109410951096109710981099110011011102110311041105110611071108110911101111111211131114111511161117111811191120112111221123
  1. -- 2012-03-19 Pedro Lopes (Microsoft) [email protected] (http://aka.ms/ezequiel)
  2. --
  3. -- All Databases index info, including duplicate, redundant, rarely used and unused indexes.
  4. --
  5. -- 4/5/2012 Simplified execution by subdividing input queries
  6. -- 4/5/2012 Fixed some collation issues;
  7. -- 4/6/2012 Split in separate listings the unused indexes from rarely used indexes; Split in separate list
  8. -- 6/6/2012 Fixed issue with partition aligned indexes
  9. -- 10/31/2012 Widened search for Redundant Indexes
  10. -- 12/17/2012 Fixed several issues
  11. -- 1/17/2013 Added several index related info
  12. -- 2/1/2013 Fixed issue with Heap identification
  13. -- 2/26/2013 Fixed issue with partition info; Removed alternate keys from search for Unused and Rarely used
  14. -- 4/17/2013 Added more information to duplicate and redundant indexes output, valuable when deciding which
  15. -- 4/19/2013 Fixed issue with potential duplicate index_ids in sys.dm_db_index_operational_stats relating t
  16. -- 5/6/2013 Changed data collection to minimize blocking potential on VLDBs.
  17. -- 5/20/2013 Fixed issue with database names with special characters.
  18. -- 5/29/2013 Fixed issue with large integers in aggregation.
  19. -- 6/20/2013 Added step to avoid entering in loop that generates dump in SQL 2005.
  20. -- 11/10/2013 Added index checks.
  21. -- 2/24/2014 Added info to Unused_IX section.
  22. -- 6/4/2014 Refined search for duplicate and redundant indexes.
  23. -- 11/12/2014 Added SQL 2014 Hash indexes support; changed scan mode to LIMITED; added search for hard coded
  24. -- 11/2/2016 Added support for SQL Server 2016 sys.dm_db_index_operational_stats changes; Added script creation.
  25. /*
  26. NOTE: on SQL Server 2005, be aware that querying sys.dm_db_index_usage_stats when it has large number of rows may lead to performance issues.
  27. URL: http://support.microsoft.com/kb/2003031
  28. */
  29. SET NOCOUNT ON;
  30. DECLARE @UpTime VARCHAR(12), @StartDate DATETIME, @sqlmajorver int, @sqlcmd NVARCHAR(4000), @params NVARCHAR(500)
  31. DECLARE @DatabaseName sysname, @indexName sysname
  32. SELECT @sqlmajorver = CONVERT(int, (@@microsoftversion / 0x1000000) & 0xff);
  33. IF @sqlmajorver = 9
  34. BEGIN
  35. SET @sqlcmd = N'SELECT @StartDateOUT = login_time, @UpTimeOUT = DATEDIFF(mi, login_time, GETDATE()) FROM master..sysprocesses WHERE spid = 1';
  36. END
  37. ELSE
  38. BEGIN
  39. SET @sqlcmd = N'SELECT @StartDateOUT = sqlserver_start_time, @UpTimeOUT = DATEDIFF(mi,sqlserver_start_time,GETDATE()) FROM sys.dm_os_sys_info';
  40. END
  41. SET @params = N'@StartDateOUT DATETIME OUTPUT, @UpTimeOUT VARCHAR(12) OUTPUT';
  42. EXECUTE sp_executesql @sqlcmd, @params, @StartDateOUT=@StartDate OUTPUT, @UpTimeOUT=@UpTime OUTPUT;
  43. SELECT @StartDate AS Collecting_Data_Since, CONVERT(VARCHAR(4),@UpTime/60/24) + 'd ' + CONVERT(VARCHAR(4),@UpTime/60%24) + 'h ' + CONVERT(VARCHAR(4),@UpTime%60) + 'm' AS Collecting_Data_For
  44. RAISERROR (N'Starting...', 10, 1) WITH NOWAIT
  45. DECLARE @dbid int, @dbname NVARCHAR(255)--, @sqlcmd NVARCHAR(4000)
  46. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblDatabases'))
  47. DROP TABLE #tblDatabases;
  48. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblDatabases'))
  49. CREATE TABLE #tblDatabases (database_id int PRIMARY KEY, is_done bit)
  50. SET @dbid = DB_ID()
  51. SELECT @dbname = DB_NAME()
  52. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblWorking'))
  53. DROP TABLE #tblWorking;
  54. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblWorking'))
  55. CREATE TABLE #tblWorking (database_id int, [object_id] int, [object_name] NVARCHAR(255), index_id int, index_name NVARCHAR(255), [schema_name] NVARCHAR(255), partition_number int, is_done bit)
  56. RAISERROR (N'Populating support tables...', 10, 1) WITH NOWAIT
  57. SELECT @sqlcmd = 'USE [' + @dbname + '];
  58. SELECT DISTINCT ' + CONVERT(NVARCHAR(255), @dbid) + ', si.[object_id], mst.[name], si.index_id, si.name, t.name, sp.partition_number, 0
  59. FROM sys.indexes si
  60. INNER JOIN sys.partitions sp ON si.[object_id] = sp.[object_id] AND si.index_id = sp.index_id
  61. INNER JOIN sys.tables AS mst ON mst.[object_id] = si.[object_id]
  62. INNER JOIN sys.schemas AS t ON t.[schema_id] = mst.[schema_id]
  63. WHERE mst.is_ms_shipped = 0'
  64. INSERT INTO #tblWorking
  65. EXEC sp_executesql @sqlcmd;
  66. --------------------------------------------------------
  67. -- Index physical and usage stats
  68. --------------------------------------------------------
  69. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIPS'))
  70. DROP TABLE #tmpIPS;
  71. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIPS'))
  72. CREATE TABLE #tmpIPS (
  73. [database_id] int,
  74. [object_id] int,
  75. [index_id] int,
  76. [partition_number] int,
  77. fragmentation DECIMAL(18,3),
  78. [page_count] bigint,
  79. [size_MB] DECIMAL(26,3),
  80. record_count int,
  81. forwarded_record_count int NULL,
  82. CONSTRAINT PK_IPS PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id], [partition_number]))
  83. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIOS'))
  84. DROP TABLE #tmpIOS;
  85. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIOS'))
  86. CREATE TABLE #tmpIOS (
  87. [database_id] int,
  88. [object_id] int,
  89. [index_id] int,
  90. [partition_number] int,
  91. range_scan_count bigint NULL,
  92. singleton_lookup_count bigint NULL,
  93. forwarded_fetch_count bigint NULL,
  94. row_lock_count bigint NULL,
  95. row_lock_wait_count bigint NULL,
  96. row_lock_pct NUMERIC(15,2) NULL,
  97. row_lock_wait_in_ms bigint NULL,
  98. [avg_row_lock_waits_in_ms] NUMERIC(15,2) NULL,
  99. page_lock_count bigint NULL,
  100. page_lock_wait_count bigint NULL,
  101. page_lock_pct NUMERIC(15,2) NULL,
  102. page_lock_wait_in_ms bigint NULL,
  103. [avg_page_lock_waits_in_ms] NUMERIC(15,2) NULL,
  104. page_io_latch_wait_in_ms bigint NULL,
  105. [avg_page_io_latch_wait_in_ms] NUMERIC(15,2) NULL
  106. CONSTRAINT PK_IOS PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id], [partition_number]));
  107. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIUS'))
  108. DROP TABLE #tmpIUS;
  109. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIUS'))
  110. CREATE TABLE #tmpIUS (
  111. [database_id] int,
  112. [schema_name] VARCHAR(100) COLLATE database_default,
  113. [object_id] int,
  114. [index_id] int,
  115. [Hits] bigint NULL,
  116. [Reads_Ratio] DECIMAL(5,2),
  117. [Writes_Ratio] DECIMAL(5,2),
  118. user_updates bigint,
  119. last_user_seek DATETIME NULL,
  120. last_user_scan DATETIME NULL,
  121. last_user_lookup DATETIME NULL,
  122. last_user_update DATETIME NULL
  123. CONSTRAINT PK_IUS PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id]));
  124. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIxs'))
  125. DROP TABLE #tmpIxs;
  126. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIxs'))
  127. CREATE TABLE #tmpIxs (
  128. [database_id] int,
  129. [database_name] VARCHAR(500),
  130. [object_id] int,
  131. [schema_name] VARCHAR(100) COLLATE database_default,
  132. [table_name] VARCHAR(300) COLLATE database_default,
  133. [index_id] int,
  134. [index_name] VARCHAR(300) COLLATE database_default,
  135. [partition_number] int,
  136. [index_type] tinyint,
  137. type_desc NVARCHAR(30),
  138. is_primary_key bit,
  139. is_unique_constraint bit,
  140. is_disabled bit,
  141. fill_factor tinyint,
  142. is_unique bit,
  143. is_padded bit,
  144. has_filter bit,
  145. filter_definition NVARCHAR(max),
  146. KeyCols VARCHAR(4000),
  147. KeyColsOrdered VARCHAR(4000),
  148. IncludedCols VARCHAR(4000) NULL,
  149. IncludedColsOrdered VARCHAR(4000) NULL,
  150. AllColsOrdered VARCHAR(4000) NULL,
  151. [KeyCols_data_length_bytes] int,
  152. CONSTRAINT PK_Ixs PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id], [partition_number]));
  153. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAgg'))
  154. DROP TABLE #tmpAgg;
  155. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAgg'))
  156. CREATE TABLE #tmpAgg (
  157. [database_id] int,
  158. [database_name] sysname,
  159. [object_id] int,
  160. [schema_name] VARCHAR(100) COLLATE database_default,
  161. [table_name] VARCHAR(300) COLLATE database_default,
  162. [index_id] int,
  163. [index_name] VARCHAR(300) COLLATE database_default,
  164. [partition_number] int,
  165. fragmentation DECIMAL(18,3),
  166. fill_factor tinyint,
  167. [page_count] bigint,
  168. [size_MB] DECIMAL(26,3),
  169. record_count bigint,
  170. forwarded_record_count bigint NULL,
  171. range_scan_count bigint NULL,
  172. singleton_lookup_count bigint NULL,
  173. forwarded_fetch_count bigint NULL,
  174. row_lock_count bigint NULL,
  175. row_lock_wait_count bigint NULL,
  176. row_lock_pct NUMERIC(15,2) NULL,
  177. row_lock_wait_in_ms bigint NULL,
  178. [avg_row_lock_waits_in_ms] NUMERIC(15,2) NULL,
  179. page_lock_count bigint NULL,
  180. page_lock_wait_count bigint NULL,
  181. page_lock_pct NUMERIC(15,2) NULL,
  182. page_lock_wait_in_ms bigint NULL,
  183. [avg_page_lock_waits_in_ms] NUMERIC(15,2) NULL,
  184. page_io_latch_wait_in_ms bigint NULL,
  185. [avg_page_io_latch_wait_in_ms] NUMERIC(15,2) NULL,
  186. [Hits] bigint NULL,
  187. [Reads_Ratio] DECIMAL(5,2),
  188. [Writes_Ratio] DECIMAL(5,2),
  189. user_updates bigint,
  190. last_user_seek DATETIME NULL,
  191. last_user_scan DATETIME NULL,
  192. last_user_lookup DATETIME NULL,
  193. last_user_update DATETIME NULL,
  194. KeyCols VARCHAR(4000) COLLATE database_default,
  195. KeyColsOrdered VARCHAR(4000) COLLATE database_default,
  196. IncludedCols VARCHAR(4000) COLLATE database_default NULL,
  197. IncludedColsOrdered VARCHAR(4000) COLLATE database_default NULL,
  198. AllColsOrdered VARCHAR(4000) COLLATE database_default NULL,
  199. is_unique bit,
  200. [type] tinyint,
  201. type_desc NVARCHAR(30),
  202. is_primary_key bit,
  203. is_unique_constraint bit,
  204. is_padded bit,
  205. has_filter bit,
  206. filter_definition NVARCHAR(max),
  207. is_disabled bit,
  208. [KeyCols_data_length_bytes] int,
  209. CONSTRAINT PK_tmpIxs PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id], [partition_number]));
  210. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblCode'))
  211. DROP TABLE #tblCode;
  212. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblCode'))
  213. CREATE TABLE #tblCode (
  214. [DatabaseName] sysname,
  215. [schemaName] VARCHAR(100),
  216. [objectName] VARCHAR(200),
  217. [indexName] VARCHAR(200),
  218. type_desc NVARCHAR(60));
  219. IF @sqlmajorver >= 12
  220. BEGIN
  221. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXIS'))
  222. DROP TABLE #tmpXIS;
  223. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXIS'))
  224. CREATE TABLE #tmpXIS (
  225. [database_id] int,
  226. [object_id] int,
  227. [schema_name] VARCHAR(100) COLLATE database_default,
  228. [table_name] VARCHAR(300) COLLATE database_default,
  229. [index_id] int,
  230. [index_name] VARCHAR(300) COLLATE database_default,
  231. total_bucket_count bigint,
  232. empty_bucket_count bigint,
  233. avg_chain_length bigint,
  234. max_chain_length bigint,
  235. scans_started bigint,
  236. scans_retries bigint,
  237. rows_returned bigint,
  238. rows_touched bigint,
  239. CONSTRAINT PK_tmpXIS PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id]));
  240. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXNCIS'))
  241. DROP TABLE #tmpXNCIS;
  242. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXNCIS'))
  243. CREATE TABLE #tmpXNCIS (
  244. [database_id] int,
  245. [object_id] int,
  246. [schema_name] VARCHAR(100) COLLATE database_default,
  247. [table_name] VARCHAR(300) COLLATE database_default,
  248. [index_id] int,
  249. [index_name] VARCHAR(300) COLLATE database_default,
  250. delta_pages bigint,
  251. internal_pages bigint,
  252. leaf_pages bigint,
  253. page_update_count bigint,
  254. page_update_retry_count bigint,
  255. page_consolidation_count bigint,
  256. page_consolidation_retry_count bigint,
  257. page_split_count bigint,
  258. page_split_retry_count bigint,
  259. key_split_count bigint,
  260. key_split_retry_count bigint,
  261. page_merge_count bigint,
  262. page_merge_retry_count bigint,
  263. key_merge_count bigint,
  264. key_merge_retry_count bigint,
  265. scans_started bigint,
  266. scans_retries bigint,
  267. rows_returned bigint,
  268. rows_touched bigint,
  269. CONSTRAINT PK_tmpXNCIS PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id]));
  270. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPHash'))
  271. DROP TABLE #tmpAggXTPHash;
  272. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPHash'))
  273. CREATE TABLE #tmpAggXTPHash (
  274. [database_id] int,
  275. [database_name] sysname,
  276. [object_id] int,
  277. [schema_name] VARCHAR(100) COLLATE database_default,
  278. [table_name] VARCHAR(300) COLLATE database_default,
  279. [index_id] int,
  280. [index_name] VARCHAR(300) COLLATE database_default,
  281. total_bucket_count bigint,
  282. empty_bucket_count bigint,
  283. avg_chain_length bigint,
  284. max_chain_length bigint,
  285. scans_started bigint,
  286. scans_retries bigint,
  287. rows_returned bigint,
  288. rows_touched bigint,
  289. KeyCols VARCHAR(4000) COLLATE database_default,
  290. KeyColsOrdered VARCHAR(4000) COLLATE database_default,
  291. IncludedCols VARCHAR(4000) COLLATE database_default NULL,
  292. IncludedColsOrdered VARCHAR(4000) COLLATE database_default NULL,
  293. AllColsOrdered VARCHAR(4000) COLLATE database_default NULL,
  294. is_unique bit,
  295. [type] tinyint,
  296. type_desc NVARCHAR(30),
  297. is_primary_key bit,
  298. is_unique_constraint bit,
  299. is_padded bit,
  300. has_filter bit,
  301. filter_definition NVARCHAR(max),
  302. is_disabled bit,
  303. [KeyCols_data_length_bytes] int,
  304. CONSTRAINT PK_tmpAggXTPHash PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id]));
  305. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPNC'))
  306. DROP TABLE #tmpAggXTPNC;
  307. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPNC'))
  308. CREATE TABLE #tmpAggXTPNC (
  309. [database_id] int,
  310. [database_name] sysname,
  311. [object_id] int,
  312. [schema_name] VARCHAR(100) COLLATE database_default,
  313. [table_name] VARCHAR(300) COLLATE database_default,
  314. [index_id] int,
  315. [index_name] VARCHAR(300) COLLATE database_default,
  316. delta_pages bigint,
  317. internal_pages bigint,
  318. leaf_pages bigint,
  319. page_update_count bigint,
  320. page_update_retry_count bigint,
  321. page_consolidation_count bigint,
  322. page_consolidation_retry_count bigint,
  323. page_split_count bigint,
  324. page_split_retry_count bigint,
  325. key_split_count bigint,
  326. key_split_retry_count bigint,
  327. page_merge_count bigint,
  328. page_merge_retry_count bigint,
  329. key_merge_count bigint,
  330. key_merge_retry_count bigint,
  331. scans_started bigint,
  332. scans_retries bigint,
  333. rows_returned bigint,
  334. rows_touched bigint,
  335. KeyCols VARCHAR(4000) COLLATE database_default,
  336. KeyColsOrdered VARCHAR(4000) COLLATE database_default,
  337. IncludedCols VARCHAR(4000) COLLATE database_default NULL,
  338. IncludedColsOrdered VARCHAR(4000) COLLATE database_default NULL,
  339. AllColsOrdered VARCHAR(4000) COLLATE database_default NULL,
  340. is_unique bit,
  341. [type] tinyint,
  342. type_desc NVARCHAR(30),
  343. is_primary_key bit,
  344. is_unique_constraint bit,
  345. is_padded bit,
  346. has_filter bit,
  347. filter_definition NVARCHAR(max),
  348. is_disabled bit,
  349. [KeyCols_data_length_bytes] int,
  350. CONSTRAINT PK_tmpAggXTPNC PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id]));
  351. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpHashIxs'))
  352. DROP TABLE #tmpHashIxs;
  353. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpHashIxs'))
  354. CREATE TABLE #tmpHashIxs (
  355. [database_id] int,
  356. [database_name] VARCHAR(500),
  357. [object_id] int,
  358. [schema_name] VARCHAR(100) COLLATE database_default,
  359. [table_name] VARCHAR(300) COLLATE database_default,
  360. [index_id] int,
  361. [index_name] VARCHAR(300) COLLATE database_default,
  362. [partition_number] int,
  363. [index_type] tinyint,
  364. type_desc NVARCHAR(30),
  365. is_primary_key bit,
  366. is_unique_constraint bit,
  367. is_disabled bit,
  368. fill_factor tinyint,
  369. is_unique bit,
  370. is_padded bit,
  371. has_filter bit,
  372. filter_definition NVARCHAR(max),
  373. [bucket_count] bigint,
  374. KeyCols VARCHAR(4000),
  375. KeyColsOrdered VARCHAR(4000),
  376. IncludedCols VARCHAR(4000) NULL,
  377. IncludedColsOrdered VARCHAR(4000) NULL,
  378. AllColsOrdered VARCHAR(4000) NULL,
  379. [KeyCols_data_length_bytes] int,
  380. CONSTRAINT PK_HashIxs PRIMARY KEY CLUSTERED(database_id, [object_id], [index_id], [partition_number]));
  381. END;
  382. DECLARE /*@dbid int, */@objectid int, @indexid int, @partition_nr int, /*@dbname NVARCHAR(255),*/ @oname NVARCHAR(255), @iname NVARCHAR(255), @sname NVARCHAR(255)
  383. RAISERROR (N'Gathering sys.dm_db_index_physical_stats and sys.dm_db_index_operational_stats data...', 10, 1) WITH NOWAIT
  384. WHILE (SELECT COUNT(*) FROM #tblWorking WHERE is_done = 0) > 0
  385. BEGIN
  386. SELECT TOP 1 @objectid = [object_id], @indexid = index_id, @partition_nr = partition_number, @oname = [object_name], @iname = index_name, @sname = [schema_name]
  387. FROM #tblWorking WHERE is_done = 0
  388. INSERT INTO #tmpIPS
  389. SELECT ps.database_id,
  390. ps.[object_id],
  391. ps.index_id,
  392. ps.partition_number,
  393. SUM(ps.avg_fragmentation_in_percent),
  394. SUM(ps.page_count),
  395. CAST((SUM(ps.page_count)*8)/1024 AS DECIMAL(26,3)) AS [size_MB],
  396. SUM(ISNULL(ps.record_count,0)),
  397. SUM(ISNULL(ps.forwarded_record_count,0)) -- for heaps
  398. FROM sys.dm_db_index_physical_stats(@dbid, @objectid, @indexid , @partition_nr, 'SAMPLED') AS ps
  399. WHERE /*ps.index_id > 0 -- ignore heaps
  400. AND */ps.index_level = 0 -- leaf-level nodes only
  401. AND ps.alloc_unit_type_desc = 'IN_ROW_DATA'
  402. GROUP BY ps.database_id, ps.[object_id], ps.index_id, ps.partition_number
  403. OPTION (MAXDOP 2);
  404. -- Avoid entering in loop that generates dump in SQL 2005
  405. IF @sqlmajorver = 9
  406. BEGIN
  407. SET @sqlcmd = (SELECT 'USE [' + @dbname + '];
  408. UPDATE STATISTICS ' + QUOTENAME(@sname) + '.' + QUOTENAME(@oname) + CASE WHEN @iname IS NULL THEN '' ELSE ' (' + QUOTENAME(@iname) + ')' END)
  409. EXEC sp_executesql @sqlcmd
  410. END;
  411. SET @sqlcmd = N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
  412. USE [' + @dbname + '];
  413. WITH osCTE (database_id, [object_id], index_id, partition_number, range_scan_count, singleton_lookup_count,
  414. forwarded_fetch_count, row_lock_count, row_lock_wait_count, row_lock_wait_in_ms, page_lock_count,
  415. page_lock_wait_count, page_lock_wait_in_ms, page_io_latch_wait_count, page_io_latch_wait_in_ms)
  416. AS (SELECT os.database_id,
  417. os.[object_id],
  418. os.index_id,
  419. os.partition_number,
  420. SUM(os.range_scan_count),
  421. SUM(os.singleton_lookup_count),
  422. SUM(os.forwarded_fetch_count),
  423. SUM(os.row_lock_count),
  424. SUM(os.row_lock_wait_count),
  425. SUM(os.row_lock_wait_in_ms),
  426. SUM(os.page_lock_count),
  427. SUM(os.page_lock_wait_count),
  428. SUM(os.page_lock_wait_in_ms),
  429. SUM(os.page_io_latch_wait_count),
  430. SUM(os.page_io_latch_wait_in_ms)
  431. FROM sys.dm_db_index_operational_stats(' + CONVERT(NVARCHAR(20), @dbid) + ', ' + CONVERT(NVARCHAR(20), @objectid) + ', ' + CONVERT(NVARCHAR(20), @indexid) + ', ' + CONVERT(NVARCHAR(20), @partition_nr) + ') AS os
  432. INNER JOIN sys.objects AS o WITH (NOLOCK) ON os.[object_id] = o.[object_id]
  433. ' + CASE WHEN @sqlmajorver >= 13 THEN 'LEFT JOIN sys.internal_partitions AS ip WITH (NOLOCK) ON os.hobt_id = ip.hobt_id AND ip.internal_object_type IN (2,3)' ELSE '' END + '
  434. WHERE o.[type] = ''U''
  435. GROUP BY os.database_id, os.[object_id], os.index_id, os.partition_number
  436. )
  437. SELECT osCTE.database_id,
  438. osCTE.[object_id],
  439. osCTE.index_id,
  440. osCTE.partition_number,
  441. osCTE.range_scan_count,
  442. osCTE.singleton_lookup_count,
  443. osCTE.forwarded_fetch_count,
  444. osCTE.row_lock_count,
  445. osCTE.row_lock_wait_count,
  446. CAST(100.0 * osCTE.row_lock_wait_count / (1 + osCTE.row_lock_count) AS numeric(15,2)) AS row_lock_pct,
  447. osCTE.row_lock_wait_in_ms,
  448. CAST(1.0 * osCTE.row_lock_wait_in_ms / (1 + osCTE.row_lock_wait_count) AS numeric(15,2)) AS [avg_row_lock_waits_in_ms],
  449. osCTE.page_lock_count,
  450. osCTE.page_lock_wait_count,
  451. CAST(100.0 * osCTE.page_lock_wait_count / (1 + osCTE.page_lock_count) AS numeric(15,2)) AS page_lock_pct,
  452. osCTE.page_lock_wait_in_ms,
  453. CAST(1.0 * osCTE.page_lock_wait_in_ms / (1 + osCTE.page_lock_wait_count) AS numeric(15,2)) AS [avg_page_lock_waits_in_ms],
  454. osCTE.page_io_latch_wait_in_ms,
  455. CAST(1.0 * osCTE.page_io_latch_wait_in_ms / (1 + osCTE.page_io_latch_wait_count) AS numeric(15,2)) AS [avg_page_io_latch_wait_in_ms]
  456. FROM osCTE
  457. --WHERE os.index_id > 0 -- ignore heaps
  458. OPTION (MAXDOP 2);'
  459. INSERT INTO #tmpIOS
  460. EXEC sp_executesql @sqlcmd
  461. UPDATE #tblWorking
  462. SET is_done = 1
  463. WHERE [object_id] = @objectid AND index_id = @indexid AND partition_number = @partition_nr
  464. END;
  465. IF @sqlmajorver >= 12
  466. BEGIN
  467. RAISERROR (N'Gathering sys.dm_db_xtp_hash_index_stats and sys.dm_db_xtp_nonclustered_index_stats data...', 10, 1) WITH NOWAIT
  468. SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
  469. USE [' + @dbname + '];
  470. SELECT ' + CONVERT(NVARCHAR(20), @dbid) + ' AS [database_id], xis.[object_id], t.name, o.name, xis.index_id, si.name,
  471. xhis.total_bucket_count, xhis.empty_bucket_count, xhis.avg_chain_length, xhis.max_chain_length,
  472. xis.scans_started, xis.scans_retries, xis.rows_returned, xis.rows_touched
  473. FROM sys.dm_db_xtp_hash_index_stats xhis
  474. INNER JOIN sys.dm_db_xtp_index_stats xis ON xis.[object_id] = xhis.[object_id] AND xis.[index_id] = xhis.[index_id]
  475. INNER JOIN sys.indexes AS si WITH (NOLOCK) ON xis.[object_id] = si.[object_id] AND xis.[index_id] = si.[index_id]
  476. INNER JOIN sys.objects AS o WITH (NOLOCK) ON si.[object_id] = o.[object_id]
  477. INNER JOIN sys.tables AS mst WITH (NOLOCK) ON mst.[object_id] = o.[object_id]
  478. INNER JOIN sys.schemas AS t WITH (NOLOCK) ON t.[schema_id] = mst.[schema_id]
  479. WHERE o.[type] = ''U'''
  480. INSERT INTO #tmpXIS
  481. EXECUTE sp_executesql @sqlcmd
  482. SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
  483. USE [' + @dbname + '];
  484. SELECT ' + CONVERT(NVARCHAR(20), @dbid) + ' AS [database_id],
  485. xis.[object_id], t.name, o.name, xis.index_id, si.name,
  486. xnis.delta_pages, xnis.internal_pages, xnis.leaf_pages, xnis.page_update_count,
  487. xnis.page_update_retry_count, xnis.page_consolidation_count,
  488. xnis.page_consolidation_retry_count, xnis.page_split_count, xnis.page_split_retry_count,
  489. xnis.key_split_count, xnis.key_split_retry_count, xnis.page_merge_count, xnis.page_merge_retry_count,
  490. xnis.key_merge_count, xnis.key_merge_retry_count,
  491. xis.scans_started, xis.scans_retries, xis.rows_returned, xis.rows_touched
  492. FROM sys.dm_db_xtp_nonclustered_index_stats AS xnis WITH (NOLOCK)
  493. INNER JOIN sys.dm_db_xtp_index_stats AS xis WITH (NOLOCK) ON xis.[object_id] = xnis.[object_id] AND xis.[index_id] = xnis.[index_id]
  494. INNER JOIN sys.indexes AS si WITH (NOLOCK) ON xis.[object_id] = si.[object_id] AND xis.[index_id] = si.[index_id]
  495. INNER JOIN sys.objects AS o WITH (NOLOCK) ON si.[object_id] = o.[object_id]
  496. INNER JOIN sys.tables AS mst WITH (NOLOCK) ON mst.[object_id] = o.[object_id]
  497. INNER JOIN sys.schemas AS t WITH (NOLOCK) ON t.[schema_id] = mst.[schema_id]
  498. WHERE o.[type] = ''U'''
  499. INSERT INTO #tmpXNCIS
  500. EXECUTE sp_executesql @sqlcmd
  501. END;
  502. RAISERROR (N'Gathering sys.dm_db_index_usage_stats data...', 10, 1) WITH NOWAIT
  503. SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
  504. USE [' + @dbname + '];
  505. SELECT s.database_id, t.name, s.[object_id], s.index_id,
  506. (s.user_seeks + s.user_scans + s.user_lookups) AS [Hits],
  507. RTRIM(CONVERT(NVARCHAR(20),CAST(CASE WHEN (s.user_seeks + s.user_scans + s.user_lookups) = 0 THEN 0 ELSE CONVERT(REAL, (s.user_seeks + s.user_scans + s.user_lookups)) * 100 /
  508. CASE (s.user_seeks + s.user_scans + s.user_lookups + s.user_updates) WHEN 0 THEN 1 ELSE CONVERT(REAL, (s.user_seeks + s.user_scans + s.user_lookups + s.user_updates)) END END AS DECIMAL(18,2))) COLLATE database_default) AS [Reads_Ratio],
  509. RTRIM(CONVERT(NVARCHAR(20),CAST(CASE WHEN s.user_updates = 0 THEN 0 ELSE CONVERT(REAL, s.user_updates) * 100 /
  510. CASE (s.user_seeks + s.user_scans + s.user_lookups + s.user_updates) WHEN 0 THEN 1 ELSE CONVERT(REAL, (s.user_seeks + s.user_scans + s.user_lookups + s.user_updates)) END END AS DECIMAL(18,2))) COLLATE database_default) AS [Writes_Ratio],
  511. s.user_updates,
  512. MAX(s.last_user_seek) AS last_user_seek,
  513. MAX(s.last_user_scan) AS last_user_scan,
  514. MAX(s.last_user_lookup) AS last_user_lookup,
  515. MAX(s.last_user_update) AS last_user_update
  516. FROM sys.dm_db_index_usage_stats AS s WITH (NOLOCK)
  517. INNER JOIN sys.objects AS o WITH (NOLOCK) ON s.[object_id] = o.[object_id]
  518. INNER JOIN sys.tables AS mst WITH (NOLOCK) ON mst.[object_id] = s.[object_id]
  519. INNER JOIN sys.schemas AS t WITH (NOLOCK) ON t.[schema_id] = mst.[schema_id]
  520. WHERE o.[type] = ''U''
  521. AND s.database_id = ' + CONVERT(NVARCHAR(20), @dbid) + '
  522. --AND s.index_id > 0 -- ignore heaps
  523. GROUP BY s.database_id, t.name, s.[object_id], s.index_id, s.user_seeks, s.user_scans, s.user_lookups, s.user_updates
  524. OPTION (MAXDOP 2)'
  525. INSERT INTO #tmpIUS
  526. EXECUTE sp_executesql @sqlcmd
  527. SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
  528. USE [' + @dbname + '];
  529. SELECT ' + CONVERT(NVARCHAR(20), @dbid) + ' AS [database_id], t.name, i.[object_id], i.index_id, 0, 0, 0, NULL, NULL, NULL, NULL, NULL
  530. FROM sys.indexes i WITH (NOLOCK)
  531. INNER JOIN sys.objects o WITH (NOLOCK) ON i.object_id = o.object_id
  532. INNER JOIN sys.tables AS mst WITH (NOLOCK) ON mst.[object_id] = i.[object_id]
  533. INNER JOIN sys.schemas AS t WITH (NOLOCK) ON t.[schema_id] = mst.[schema_id]
  534. WHERE o.[type] = ''U''
  535. AND i.index_id NOT IN (SELECT s.index_id
  536. FROM sys.dm_db_index_usage_stats s WITH (NOLOCK)
  537. WHERE s.object_id = i.object_id
  538. AND i.index_id = s.index_id
  539. AND database_id = ' + CONVERT(NVARCHAR(20), @dbid) + ')
  540. AND i.name IS NOT NULL
  541. AND i.index_id > 1'
  542. INSERT INTO #tmpIUS
  543. EXECUTE sp_executesql @sqlcmd
  544. RAISERROR (N'Gathering index column data...', 10, 1) WITH NOWAIT
  545. SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
  546. USE [' + @dbname + '];
  547. SELECT ' + CONVERT(NVARCHAR(20), @dbid) + ' AS [database_id], ''' + @dbname + ''' AS database_name,
  548. mst.[object_id], t.name, mst.[name],
  549. mi.index_id, mi.[name], p.partition_number,
  550. mi.[type], mi.[type_desc], mi.is_primary_key, mi.is_unique_constraint, mi.is_disabled,
  551. mi.fill_factor, mi.is_unique, mi.is_padded, ' + CASE WHEN @sqlmajorver > 9 THEN 'mi.has_filter, mi.filter_definition,' ELSE 'NULL, NULL,' END + '
  552. SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
  553. INNER JOIN sys.indexes AS i ON st.[object_id] = i.[object_id]
  554. INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
  555. INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
  556. WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 0
  557. ORDER BY ic.key_ordinal
  558. FOR XML PATH('''')), 2, 8000) AS KeyCols,
  559. SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
  560. INNER JOIN sys.indexes AS i ON st.[object_id] = i.[object_id]
  561. INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
  562. INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
  563. WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 0
  564. ORDER BY ac.name
  565. FOR XML PATH('''')), 2, 8000) AS KeyColsOrdered,
  566. SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
  567. INNER JOIN sys.indexes AS i ON st.[object_id] = i.[object_id]
  568. INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
  569. INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
  570. WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 1
  571. ORDER BY ic.key_ordinal
  572. FOR XML PATH('''')), 2, 8000) AS IncludedCols,
  573. SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
  574. INNER JOIN sys.indexes AS i ON st.[object_id] = i.[object_id]
  575. INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
  576. INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
  577. WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 1
  578. ORDER BY ac.name
  579. FOR XML PATH('''')), 2, 8000) AS IncludedColsOrdered,
  580. SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
  581. INNER JOIN sys.indexes AS i ON st.[object_id] = i.[object_id]
  582. INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
  583. INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
  584. WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id
  585. ORDER BY ac.name
  586. FOR XML PATH('''')), 2, 8000) AS AllColsOrdered,
  587. (SELECT SUM(CASE sty.name WHEN ''nvarchar'' THEN sc.max_length/2 ELSE sc.max_length END) FROM sys.indexes AS i
  588. INNER JOIN sys.tables AS t ON t.[object_id] = i.[object_id]
  589. INNER JOIN sys.schemas ss ON ss.[schema_id] = t.[schema_id]
  590. INNER JOIN sys.index_columns AS sic ON sic.object_id = mst.object_id AND sic.index_id = mi.index_id
  591. INNER JOIN sys.columns AS sc ON sc.object_id = t.object_id AND sc.column_id = sic.column_id
  592. INNER JOIN sys.types AS sty ON sc.user_type_id = sty.user_type_id
  593. WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id) AS [KeyCols_data_length_bytes]
  594. FROM sys.indexes AS mi
  595. INNER JOIN sys.tables AS mst ON mst.[object_id] = mi.[object_id]
  596. INNER JOIN sys.schemas AS t ON t.[schema_id] = mst.[schema_id]
  597. INNER JOIN sys.partitions AS p ON p.[object_id] = mi.[object_id] AND p.index_id = mi.index_id
  598. WHERE mi.type IN (0,1,2,5,6) AND mst.is_ms_shipped = 0
  599. OPTION (MAXDOP 2);'
  600. INSERT INTO #tmpIxs
  601. EXECUTE sp_executesql @sqlcmd;
  602. IF @sqlmajorver >= 12
  603. BEGIN
  604. SET @sqlcmd = 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
  605. USE [' + @dbname + '];
  606. SELECT ' + CONVERT(NVARCHAR(20), @dbid) + ' AS [database_id], ''' + @dbname + ''' AS database_name,
  607. mst.[object_id], t.name, mst.[name],
  608. mi.index_id, mi.[name], p.partition_number,
  609. mi.[type], mi.[type_desc], mi.is_primary_key, mi.is_unique_constraint, mi.is_disabled,
  610. mi.fill_factor, mi.is_unique, mi.is_padded, mi.has_filter, mi.filter_definition,[bucket_count],
  611. SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
  612. INNER JOIN sys.hash_indexes AS i ON st.[object_id] = i.[object_id]
  613. INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
  614. INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
  615. WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 0
  616. ORDER BY ic.key_ordinal
  617. FOR XML PATH('''')), 2, 8000) AS KeyCols,
  618. SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
  619. INNER JOIN sys.hash_indexes AS i ON st.[object_id] = i.[object_id]
  620. INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
  621. INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
  622. WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 0
  623. ORDER BY ac.name
  624. FOR XML PATH('''')), 2, 8000) AS KeyColsOrdered,
  625. SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
  626. INNER JOIN sys.hash_indexes AS i ON st.[object_id] = i.[object_id]
  627. INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
  628. INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
  629. WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 1
  630. ORDER BY ic.key_ordinal
  631. FOR XML PATH('''')), 2, 8000) AS IncludedCols,
  632. SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
  633. INNER JOIN sys.hash_indexes AS i ON st.[object_id] = i.[object_id]
  634. INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
  635. INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
  636. WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id AND ic.is_included_column = 1
  637. ORDER BY ac.name
  638. FOR XML PATH('''')), 2, 8000) AS IncludedColsOrdered,
  639. SUBSTRING((SELECT '','' + ac.name FROM sys.tables AS st
  640. INNER JOIN sys.hash_indexes AS i ON st.[object_id] = i.[object_id]
  641. INNER JOIN sys.index_columns AS ic ON i.[object_id] = ic.[object_id] AND i.[index_id] = ic.[index_id]
  642. INNER JOIN sys.all_columns AS ac ON st.[object_id] = ac.[object_id] AND ic.[column_id] = ac.[column_id]
  643. WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id
  644. ORDER BY ac.name
  645. FOR XML PATH('''')), 2, 8000) AS AllColsOrdered,
  646. (SELECT SUM(CASE sty.name WHEN ''nvarchar'' THEN sc.max_length/2 ELSE sc.max_length END) FROM sys.hash_indexes AS i
  647. INNER JOIN sys.tables AS t ON t.[object_id] = i.[object_id]
  648. INNER JOIN sys.schemas ss ON ss.[schema_id] = t.[schema_id]
  649. INNER JOIN sys.index_columns AS sic ON sic.object_id = mst.object_id AND sic.index_id = mi.index_id
  650. INNER JOIN sys.columns AS sc ON sc.object_id = t.object_id AND sc.column_id = sic.column_id
  651. INNER JOIN sys.types AS sty ON sc.user_type_id = sty.user_type_id
  652. WHERE mi.[object_id] = i.[object_id] AND mi.index_id = i.index_id) AS [KeyCols_data_length_bytes]
  653. FROM sys.hash_indexes AS mi
  654. INNER JOIN sys.tables AS mst ON mst.[object_id] = mi.[object_id]
  655. INNER JOIN sys.schemas AS t ON t.[schema_id] = mst.[schema_id]
  656. INNER JOIN sys.partitions AS p ON p.[object_id] = mi.[object_id] AND p.index_id = mi.index_id
  657. WHERE mi.type IN (7) AND mst.is_ms_shipped = 0
  658. ORDER BY mst.name
  659. OPTION (MAXDOP 2);'
  660. INSERT INTO #tmpHashIxs
  661. EXECUTE sp_executesql @sqlcmd;
  662. END;
  663. RAISERROR (N'Aggregating data...', 10, 1) WITH NOWAIT
  664. INSERT INTO #tmpAgg
  665. SELECT ISNULL(ps.database_id, si.[database_id]), si.database_name, ISNULL(ps.[object_id], si.[object_id]),
  666. si.[schema_name], si.table_name, si.index_id, si.index_name, ISNULL(ps.partition_number, si.partition_number),
  667. ps.fragmentation, si.fill_factor, ps.page_count, ps.[size_MB], ps.record_count, ps.forwarded_record_count, -- for heaps
  668. os.range_scan_count, os.singleton_lookup_count, os.forwarded_fetch_count, os.row_lock_count,
  669. os.row_lock_wait_count, os.row_lock_pct, os.row_lock_wait_in_ms, os.[avg_row_lock_waits_in_ms],
  670. os.page_lock_count, os.page_lock_wait_count, os.page_lock_pct, os.page_lock_wait_in_ms,
  671. os.[avg_page_lock_waits_in_ms], os.[page_io_latch_wait_in_ms], os.[avg_page_io_latch_wait_in_ms],
  672. s.[Hits], s.[Reads_Ratio], s.[Writes_Ratio], s.user_updates, s.last_user_seek, s.last_user_scan,
  673. s.last_user_lookup, s.last_user_update, si.KeyCols, si.KeyColsOrdered, si.IncludedCols,
  674. si.IncludedColsOrdered, si.AllColsOrdered, si.is_unique, si.[index_type], si.[type_desc],
  675. si.is_primary_key, si.is_unique_constraint, si.is_padded, si.has_filter, si.filter_definition,
  676. si.is_disabled, si.[KeyCols_data_length_bytes]
  677. FROM #tmpIxs AS si
  678. LEFT JOIN #tmpIPS AS ps ON si.database_id = ps.database_id AND si.index_id = ps.index_id AND si.[object_id] = ps.[object_id] AND si.partition_number = ps.partition_number
  679. LEFT JOIN #tmpIOS AS os ON os.database_id = ps.database_id AND os.index_id = ps.index_id AND os.[object_id] = ps.[object_id] AND os.partition_number = ps.partition_number
  680. LEFT JOIN #tmpIUS AS s ON s.database_id = ps.database_id AND s.index_id = ps.index_id and s.[object_id] = ps.[object_id]
  681. --WHERE si.type > 0 -- ignore heaps
  682. ORDER BY database_name, [table_name], fragmentation DESC, index_id
  683. OPTION (MAXDOP 2);
  684. IF @sqlmajorver >= 12
  685. BEGIN
  686. INSERT INTO #tmpAggXTPHash
  687. SELECT ISNULL(ps.database_id, si.[database_id]), si.database_name, ISNULL(ps.[object_id], si.[object_id]),
  688. si.[schema_name], si.table_name, si.index_id, si.index_name, ps.total_bucket_count, ps.empty_bucket_count,
  689. ps.avg_chain_length, ps.max_chain_length, ps.scans_started, ps.scans_retries, ps.rows_returned,
  690. ps.rows_touched, si.KeyCols, si.KeyColsOrdered, si.IncludedCols, si.IncludedColsOrdered,
  691. si.AllColsOrdered, si.is_unique, si.[index_type], si.[type_desc], si.is_primary_key, si.is_unique_constraint,
  692. si.is_padded, si.has_filter, si.filter_definition, si.is_disabled, si.[KeyCols_data_length_bytes]
  693. FROM #tmpHashIxs AS si
  694. LEFT JOIN #tmpXIS AS ps ON si.database_id = ps.database_id AND si.index_id = ps.index_id AND si.[object_id] = ps.[object_id]
  695. ORDER BY database_name, [table_name], index_id
  696. OPTION (MAXDOP 2);
  697. INSERT INTO #tmpAggXTPNC
  698. SELECT ISNULL(ps.database_id, si.[database_id]), si.database_name, ISNULL(ps.[object_id], si.[object_id]),
  699. si.[schema_name], si.table_name, si.index_id, si.index_name, ps.delta_pages, ps.internal_pages,
  700. ps.leaf_pages, ps.page_update_count, ps.page_update_retry_count,
  701. ps.page_consolidation_count, ps.page_consolidation_retry_count, ps.page_split_count,
  702. ps.page_split_retry_count, ps.key_split_count, ps.key_split_retry_count, ps.page_merge_count,
  703. ps.page_merge_retry_count, ps.key_merge_count, ps.key_merge_retry_count,
  704. ps.scans_started, ps.scans_retries, ps.rows_returned, ps.rows_touched,
  705. si.KeyCols, si.KeyColsOrdered, si.IncludedCols, si.IncludedColsOrdered, si.AllColsOrdered,
  706. si.is_unique, si.[index_type], si.[type_desc], si.is_primary_key, si.is_unique_constraint,
  707. si.is_padded, si.has_filter, si.filter_definition, si.is_disabled, si.[KeyCols_data_length_bytes]
  708. FROM #tmpHashIxs AS si
  709. LEFT JOIN #tmpXNCIS AS ps ON si.database_id = ps.database_id AND si.index_id = ps.index_id AND si.[object_id] = ps.[object_id]
  710. ORDER BY database_name, [table_name], index_id
  711. OPTION (MAXDOP 2);
  712. END;
  713. RAISERROR (N'Output index information', 10, 1) WITH NOWAIT
  714. -- All index information
  715. SELECT 'All_IX_Info' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type,
  716. [partition_number], fragmentation, fill_factor, [page_count], [size_MB], record_count, range_scan_count, singleton_lookup_count, row_lock_count, row_lock_wait_count,
  717. row_lock_pct, row_lock_wait_in_ms, [avg_row_lock_waits_in_ms], page_lock_count, page_lock_wait_count,
  718. page_lock_pct, page_lock_wait_in_ms, [avg_page_lock_waits_in_ms], page_io_latch_wait_in_ms, [avg_page_io_latch_wait_in_ms], [Hits],
  719. CONVERT(NVARCHAR,[Reads_Ratio]) COLLATE database_default + '/' + CONVERT(NVARCHAR,[Writes_Ratio]) COLLATE database_default AS [R/W_Ratio],
  720. user_updates, last_user_seek, last_user_scan, last_user_lookup, last_user_update, KeyCols, IncludedCols,
  721. is_unique, is_primary_key, is_unique_constraint, is_disabled, is_padded, has_filter, filter_definition, KeyCols_data_length_bytes
  722. FROM #tmpAgg
  723. WHERE index_id > 0 -- ignore heaps
  724. ORDER BY [database_name], [schema_name], table_name, [page_count] DESC, forwarded_record_count DESC;
  725. -- All XTP index information
  726. IF @sqlmajorver >= 12
  727. BEGIN
  728. SELECT 'All_XTP_HashIX_Info' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type,
  729. total_bucket_count, empty_bucket_count, FLOOR((CAST(empty_bucket_count AS FLOAT)/total_bucket_count) * 100) AS [empty_bucket_pct], avg_chain_length, max_chain_length,
  730. scans_started, scans_retries, rows_returned, rows_touched, KeyCols, IncludedCols, is_unique, is_primary_key, is_unique_constraint, is_disabled, is_padded, has_filter,
  731. filter_definition, KeyCols_data_length_bytes
  732. FROM #tmpAggXTPHash
  733. ORDER BY [database_name], [schema_name], table_name, [total_bucket_count] DESC;
  734. SELECT 'All_XTP_RangeIX_Info' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type,
  735. delta_pages, internal_pages, leaf_pages, page_update_count, page_update_count, page_update_retry_count, page_consolidation_count, page_consolidation_retry_count,
  736. page_split_count, page_split_retry_count, key_split_count, key_split_retry_count, page_merge_count, page_merge_retry_count, key_merge_count, key_merge_retry_count,
  737. scans_started, scans_retries, rows_returned, rows_touched, KeyCols, IncludedCols, is_unique, is_primary_key, is_unique_constraint, is_disabled, is_padded, has_filter,
  738. filter_definition, KeyCols_data_length_bytes
  739. FROM #tmpAggXTPNC
  740. ORDER BY [database_name], [schema_name], table_name, [leaf_pages] DESC;
  741. END;
  742. -- All Heaps information
  743. SELECT 'All_Heaps_Info' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [type_desc] AS index_type,
  744. [partition_number], fragmentation, [page_count], [size_MB], record_count, forwarded_record_count, forwarded_fetch_count,
  745. range_scan_count, singleton_lookup_count, row_lock_count, row_lock_wait_count,
  746. row_lock_pct, row_lock_wait_in_ms, [avg_row_lock_waits_in_ms], page_lock_count, page_lock_wait_count,
  747. page_lock_pct, page_lock_wait_in_ms, [avg_page_lock_waits_in_ms], page_io_latch_wait_in_ms, [avg_page_io_latch_wait_in_ms]
  748. FROM #tmpAgg
  749. WHERE index_id = 0 -- only heaps
  750. ORDER BY [database_name], [schema_name], table_name, [page_count] DESC, forwarded_record_count DESC;
  751. -- Unused indexes that can possibly be dropped or disabled
  752. SELECT 'Unused_IX_With_Updates' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type, [Hits],
  753. CONVERT(NVARCHAR,[Reads_Ratio]) COLLATE database_default + '/' + CONVERT(NVARCHAR,[Writes_Ratio]) COLLATE database_default AS [R/W_Ratio],
  754. [page_count], [size_MB], record_count, user_updates, last_user_seek, last_user_scan,
  755. last_user_lookup, last_user_update, is_unique, is_padded, has_filter, filter_definition
  756. FROM #tmpAgg
  757. WHERE [Hits] = 0
  758. AND last_user_update > 0
  759. AND type IN (2,6) -- non-clustered and non-clustered columnstore indexes only
  760. AND is_primary_key = 0 -- no primary keys
  761. AND is_unique_constraint = 0 -- no unique constraints
  762. AND is_unique = 0 -- no alternate keys
  763. UNION ALL
  764. SELECT 'Unused_IX_No_Updates' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type, [Hits],
  765. CONVERT(NVARCHAR,[Reads_Ratio]) COLLATE database_default + '/' + CONVERT(NVARCHAR,[Writes_Ratio]) COLLATE database_default AS [R/W_Ratio],
  766. [page_count], [size_MB], record_count, user_updates, last_user_seek, last_user_scan,
  767. last_user_lookup, last_user_update, is_unique, is_padded, has_filter, filter_definition
  768. FROM #tmpAgg
  769. WHERE [Hits] = 0
  770. AND (last_user_update = 0 OR last_user_update IS NULL)
  771. AND type IN (2,6) -- non-clustered and non-clustered columnstore indexes only
  772. AND is_primary_key = 0 -- no primary keys
  773. AND is_unique_constraint = 0 -- no unique constraints
  774. AND is_unique = 0 -- no alternate keys
  775. ORDER BY [table_name], user_updates DESC, [page_count] DESC;
  776. -- Rarely used indexes that can possibly be dropped or disabled
  777. SELECT 'Rarely_Used_IX' AS [Category], [database_id], [database_name], [object_id], [schema_name], [table_name], [index_id], [index_name], [type_desc] AS index_type, [Hits],
  778. CONVERT(NVARCHAR,[Reads_Ratio]) COLLATE database_default + '/' + CONVERT(NVARCHAR,[Writes_Ratio]) COLLATE database_default AS [R/W_Ratio],
  779. [page_count], [size_MB], record_count, user_updates, last_user_seek, last_user_scan,
  780. last_user_lookup, last_user_update, is_unique, is_padded, has_filter, filter_definition
  781. FROM #tmpAgg
  782. WHERE [Hits] > 0 AND [Reads_Ratio] < 5
  783. AND type IN (2,6) -- non-clustered and non-clustered columnstore indexes only
  784. AND is_primary_key = 0 -- no primary keys
  785. AND is_unique_constraint = 0 -- no unique constraints
  786. AND is_unique = 0 -- no alternate keys
  787. ORDER BY [database_name], [table_name], [page_count] DESC;
  788. -- Duplicate Indexes
  789. SELECT 'Duplicate_IX' AS [Category], I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[type_desc] AS index_type, I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition,
  790. I.[Hits], I.[KeyCols], I.IncludedCols, CASE WHEN I.IncludedColsOrdered IS NULL THEN I.[KeyColsOrdered] ELSE I.[KeyColsOrdered] + ',' + I.IncludedColsOrdered END AS [AllColsOrdered]
  791. FROM #tmpAgg I INNER JOIN #tmpAgg I2
  792. ON I.database_id = I2.database_id AND I.[object_id] = I2.[object_id] AND I.[index_id] <> I2.[index_id]
  793. AND I.[KeyCols] = I2.[KeyCols] AND (I.IncludedCols = I2.IncludedCols OR (I.IncludedCols IS NULL AND I2.IncludedCols IS NULL))
  794. AND ((I.filter_definition = I2.filter_definition) OR (I.filter_definition IS NULL AND I2.filter_definition IS NULL))
  795. WHERE I.type IN (1,2,5,6) -- clustered, non-clustered, clustered and non-clustered columnstore indexes only
  796. AND I2.type IN (1,2,5,6) -- clustered, non-clustered, clustered and non-clustered columnstore indexes only
  797. GROUP BY I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[Hits], I.KeyCols, I.IncludedCols, I.[KeyColsOrdered], I.IncludedColsOrdered, I.type_desc, I.[AllColsOrdered], I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition
  798. ORDER BY I.database_name, I.[table_name], I.[index_id];
  799. /*
  800. Note that it is possible that a clustered index (unique or not) is among the duplicate indexes to be dropped,
  801. namely if a non-clustered primary key exists on the table.
  802. In this case, make the appropriate changes in the clustered index (making it unique and/or primary key in this case),
  803. and drop the non-clustered instead.
  804. */
  805. SELECT 'Duplicate_IX_toDrop' AS [Category], I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[type_desc] AS index_type, I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition,
  806. I.[Hits], I.[KeyCols], I.IncludedCols, CASE WHEN I.IncludedColsOrdered IS NULL THEN I.[KeyColsOrdered] ELSE I.[KeyColsOrdered] + ',' + I.IncludedColsOrdered END AS [AllColsOrdered]
  807. FROM #tmpAgg I INNER JOIN #tmpAgg I2
  808. ON I.database_id = I2.database_id AND I.[object_id] = I2.[object_id] AND I.[index_id] <> I2.[index_id]
  809. AND I.[KeyCols] = I2.[KeyCols] AND (I.IncludedCols = I2.IncludedCols OR (I.IncludedCols IS NULL AND I2.IncludedCols IS NULL))
  810. AND ((I.filter_definition = I2.filter_definition) OR (I.filter_definition IS NULL AND I2.filter_definition IS NULL))
  811. WHERE I.[type] IN (1,2,5,6) -- clustered, non-clustered, clustered and non-clustered columnstore indexes only
  812. AND I2.[type] IN (1,2,5,6) -- clustered, non-clustered, clustered and non-clustered columnstore indexes only
  813. AND I.[index_id] NOT IN (
  814. SELECT COALESCE((SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
  815. WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id]
  816. AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
  817. AND (tI3.is_unique = 1 AND tI3.is_primary_key = 1)
  818. GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
  819. (SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
  820. WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id]
  821. AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
  822. AND (tI3.is_unique = 1 OR tI3.is_primary_key = 1)
  823. GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
  824. (SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
  825. WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id]
  826. AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
  827. GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered)
  828. ))
  829. GROUP BY I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[Hits], I.KeyCols, I.IncludedCols, I.[KeyColsOrdered], I.IncludedColsOrdered, I.type_desc, I.[AllColsOrdered], I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition
  830. ORDER BY I.database_name, I.[table_name], I.[index_id];
  831. RAISERROR (N'Starting index search in sql modules...', 10, 1) WITH NOWAIT
  832. DECLARE Dup_Stats CURSOR FAST_FORWARD FOR SELECT I.database_name,I.[index_name]
  833. FROM #tmpAgg I INNER JOIN #tmpAgg I2
  834. ON I.database_id = I2.database_id AND I.[object_id] = I2.[object_id] AND I.[index_id] <> I2.[index_id]
  835. AND I.[KeyCols] = I2.[KeyCols] AND (I.IncludedCols = I2.IncludedCols OR (I.IncludedCols IS NULL AND I2.IncludedCols IS NULL))
  836. AND ((I.filter_definition = I2.filter_definition) OR (I.filter_definition IS NULL AND I2.filter_definition IS NULL))
  837. WHERE I.[type] IN (1,2,5,6) -- clustered, non-clustered, clustered and non-clustered columnstore indexes only
  838. AND I2.[type] IN (1,2,5,6) -- clustered, non-clustered, clustered and non-clustered columnstore indexes only
  839. AND I.[index_id] NOT IN (
  840. SELECT COALESCE((SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
  841. WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id]
  842. AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
  843. AND (tI3.is_unique = 1 AND tI3.is_primary_key = 1)
  844. GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
  845. (SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
  846. WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id]
  847. AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
  848. AND (tI3.is_unique = 1 OR tI3.is_primary_key = 1)
  849. GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
  850. (SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
  851. WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id]
  852. AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
  853. GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered)
  854. ))
  855. GROUP BY I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[Hits], I.KeyCols, I.IncludedCols, I.[KeyColsOrdered], I.IncludedColsOrdered, I.type_desc, I.[AllColsOrdered], I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition
  856. ORDER BY I.database_name, I.[table_name], I.[index_id];
  857. OPEN Dup_Stats
  858. FETCH NEXT FROM Dup_Stats INTO @DatabaseName,@indexName
  859. WHILE (@@FETCH_STATUS = 0)
  860. BEGIN
  861. SET @sqlcmd = 'USE [' + @DatabaseName + '];
  862. SELECT ''' + @DatabaseName + ''' AS [database_name], ss.name AS [schema_name], so.name AS [table_name], ''' + @indexName + ''' AS [index_name], so.type_desc
  863. FROM sys.sql_modules sm
  864. INNER JOIN sys.objects so ON sm.[object_id] = so.[object_id]
  865. INNER JOIN sys.schemas ss ON ss.[schema_id] = so.[schema_id]
  866. WHERE sm.[definition] LIKE ''%' + @indexName + '%'''
  867. INSERT INTO #tblCode
  868. EXECUTE sp_executesql @sqlcmd
  869. FETCH NEXT FROM Dup_Stats INTO @DatabaseName,@indexName
  870. END
  871. CLOSE Dup_Stats
  872. DEALLOCATE Dup_Stats
  873. RAISERROR (N'Ended index search in sql modules', 10, 1) WITH NOWAIT
  874. SELECT 'Duplicate_Indexes_HardCoded' AS [Category], [DatabaseName], [schemaName], [objectName] AS [referedIn_objectName],
  875. indexName AS [referenced_indexName], type_desc AS [refered_objectType]
  876. FROM #tblCode
  877. ORDER BY [DatabaseName], [objectName];
  878. -- Redundant Indexes
  879. SELECT 'Redundant_IX' AS [Category], I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[type_desc] AS index_type, I.is_unique, I.is_padded, I.has_filter, I.filter_definition,
  880. I.[Hits], I.[KeyCols], I.IncludedCols, CASE WHEN I.IncludedColsOrdered IS NULL THEN I.[KeyColsOrdered] ELSE I.[KeyColsOrdered] + ',' + I.IncludedColsOrdered END AS [AllColsOrdered]
  881. FROM #tmpAgg I INNER JOIN #tmpAgg I2
  882. ON I.[database_id] = I2.[database_id] AND I.[object_id] = I2.[object_id] AND I.[index_id] <> I2.[index_id]
  883. AND (((I.[KeyColsOrdered] <> I2.[KeyColsOrdered] OR I.IncludedColsOrdered <> I2.IncludedColsOrdered)
  884. AND ((CASE WHEN I.IncludedColsOrdered IS NULL THEN I.[KeyColsOrdered] ELSE I.[KeyColsOrdered] + ',' + I.IncludedColsOrdered END) = (CASE WHEN I2.IncludedColsOrdered IS NULL THEN I2.[KeyColsOrdered] ELSE I2.[KeyColsOrdered] + ',' + I2.IncludedColsOrdered END)
  885. OR I.[AllColsOrdered] = I2.[AllColsOrdered]))
  886. OR (I.[KeyColsOrdered] <> I2.[KeyColsOrdered] AND I.IncludedColsOrdered = I2.IncludedColsOrdered)
  887. OR (I.[KeyColsOrdered] = I2.[KeyColsOrdered] AND I.IncludedColsOrdered <> I2.IncludedColsOrdered)
  888. OR ((I.[AllColsOrdered] = I2.[AllColsOrdered] AND I.filter_definition IS NULL AND I2.filter_definition IS NOT NULL) OR (I.[AllColsOrdered] = I2.[AllColsOrdered] AND I.filter_definition IS NOT NULL AND I2.filter_definition IS NULL)))
  889. AND I.[index_id] NOT IN (SELECT I3.[index_id]
  890. FROM #tmpIxs I3 INNER JOIN #tmpIxs I4
  891. ON I3.[database_id] = I4.[database_id] AND I3.[object_id] = I4.[object_id] AND I3.[index_id] <> I4.[index_id]
  892. AND I3.[KeyCols] = I4.[KeyCols] AND (I3.IncludedCols = I4.IncludedCols OR (I3.IncludedCols IS NULL AND I4.IncludedCols IS NULL))
  893. WHERE I3.[database_id] = I.[database_id] AND I3.[object_id] = I.[object_id]
  894. GROUP BY I3.[index_id])
  895. WHERE I.[type] IN (1,2,5,6) -- clustered, non-clustered, clustered and non-clustered columnstore indexes only
  896. AND I2.[type] IN (1,2,5,6) -- clustered, non-clustered, clustered and non-clustered columnstore indexes only
  897. AND I.is_unique_constraint = 0 -- no unique constraints
  898. AND I2.is_unique_constraint = 0 -- no unique constraints
  899. GROUP BY I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[Hits], I.KeyCols, I.IncludedCols, I.[KeyColsOrdered], I.IncludedColsOrdered, I.type_desc, I.[AllColsOrdered], I.is_unique, I.is_padded, I.has_filter, I.filter_definition
  900. ORDER BY I.database_name, I.[table_name], I.[AllColsOrdered], I.[index_id];
  901. -- Large IX Keys
  902. SELECT 'Large_Index_Key' AS [Category], I.[database_name], I.[schema_name], I.[table_name], I.[index_id], I.[index_name],
  903. I.KeyCols, [KeyCols_data_length_bytes]
  904. FROM #tmpAgg I
  905. WHERE [KeyCols_data_length_bytes] > 900
  906. ORDER BY I.[database_name], I.[schema_name], I.[table_name], I.[index_id];
  907. -- Low Fill Factor
  908. SELECT 'Low_Fill_Factor' AS [Category], I.[database_name], I.[schema_name], I.[table_name], I.[index_id], I.[index_name],
  909. [fill_factor], I.KeyCols, I.IncludedCols, CASE WHEN I.IncludedCols IS NULL THEN I.[KeyCols] ELSE I.[KeyCols] + ',' + I.IncludedCols END AS [AllColsOrdered]
  910. FROM #tmpAgg I
  911. WHERE [fill_factor] BETWEEN 1 AND 79
  912. ORDER BY I.[database_name], I.[schema_name], I.[table_name], I.[index_id];
  913. --NonUnique Clustered IXs
  914. SELECT 'NonUnique_CIXs' AS [Category], I.[database_name], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[KeyCols]
  915. FROM #tmpAgg I
  916. WHERE [is_unique] = 0
  917. AND I.[index_id] = 1
  918. ORDER BY I.[database_name], I.[schema_name], I.[table_name];
  919. RAISERROR (N'Generating scripts...', 10, 1) WITH NOWAIT
  920. DECLARE @strSQL NVARCHAR(4000)
  921. PRINT CHAR(10) + '/* Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */'
  922. IF (SELECT COUNT(*) FROM #tmpAgg WHERE [Hits] = 0 AND last_user_update > 0) > 0
  923. BEGIN
  924. PRINT CHAR(10) + '--############# Existing unused indexes with updates drop statements #############' + CHAR(10)
  925. DECLARE Un_Stats CURSOR FAST_FORWARD FOR SELECT 'USE ' + [database_name] + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM sys.indexes WHERE name = N'''+ [index_name] + ''')' + CHAR(10) + 'DROP INDEX ' + QUOTENAME([index_name]) + ' ON ' + QUOTENAME([schema_name]) + '.' + QUOTENAME([table_name]) + ';' + CHAR(10) + 'GO' + CHAR(10)
  926. FROM #tmpAgg
  927. WHERE [Hits] = 0 AND last_user_update > 0
  928. ORDER BY [database_name], [table_name], [Reads_Ratio] DESC;
  929. OPEN Un_Stats
  930. FETCH NEXT FROM Un_Stats INTO @strSQL
  931. WHILE (@@FETCH_STATUS = 0)
  932. BEGIN
  933. PRINT @strSQL
  934. FETCH NEXT FROM Un_Stats INTO @strSQL
  935. END
  936. CLOSE Un_Stats
  937. DEALLOCATE Un_Stats
  938. PRINT CHAR(10) + '--############# Ended unused indexes with updates drop statements #############' + CHAR(10)
  939. END;
  940. IF (SELECT COUNT(*) FROM #tmpAgg WHERE [Hits] = 0 AND (last_user_update = 0 OR last_user_update IS NULL)) > 0
  941. BEGIN
  942. PRINT CHAR(10) + '--############# Existing unused indexes with no updates drop statements #############' + CHAR(10)
  943. DECLARE Un_Stats CURSOR FAST_FORWARD FOR SELECT 'USE ' + [database_name] + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM sys.indexes WHERE name = N'''+ [index_name] + ''')' + CHAR(10) + 'DROP INDEX ' + QUOTENAME([index_name]) + ' ON ' + QUOTENAME([schema_name]) + '.' + QUOTENAME([table_name]) + ';' + CHAR(10) + 'GO' + CHAR(10)
  944. FROM #tmpAgg
  945. WHERE [Hits] = 0 AND (last_user_update = 0 OR last_user_update IS NULL)
  946. ORDER BY [database_name], [table_name], [Reads_Ratio] DESC;
  947. OPEN Un_Stats
  948. FETCH NEXT FROM Un_Stats INTO @strSQL
  949. WHILE (@@FETCH_STATUS = 0)
  950. BEGIN
  951. PRINT @strSQL
  952. FETCH NEXT FROM Un_Stats INTO @strSQL
  953. END
  954. CLOSE Un_Stats
  955. DEALLOCATE Un_Stats
  956. PRINT CHAR(10) + '--############# Ended unused indexes with no updates drop statements #############' + CHAR(10)
  957. END;
  958. IF (SELECT COUNT(*) FROM #tmpAgg WHERE [Hits] > 0 AND [Reads_Ratio] < 5) > 0
  959. BEGIN
  960. PRINT CHAR(10) + '/* Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */'
  961. PRINT CHAR(10) + '--############# Existing rarely used indexes drop statements #############' + CHAR(10)
  962. DECLARE curRarUsed CURSOR FAST_FORWARD FOR SELECT 'USE ' + [database_name] + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM sys.indexes WHERE name = N'''+ [index_name] + ''')' + CHAR(10) + 'DROP INDEX ' + QUOTENAME([index_name]) + ' ON ' + QUOTENAME([schema_name]) + '.' + QUOTENAME([table_name]) + ';' + CHAR(10) + 'GO' + CHAR(10)
  963. FROM #tmpAgg
  964. WHERE [Hits] > 0 AND [Reads_Ratio] < 5
  965. ORDER BY [database_name], [table_name], [Reads_Ratio] DESC
  966. OPEN curRarUsed
  967. FETCH NEXT FROM curRarUsed INTO @strSQL
  968. WHILE (@@FETCH_STATUS = 0)
  969. BEGIN
  970. PRINT @strSQL
  971. FETCH NEXT FROM curRarUsed INTO @strSQL
  972. END
  973. CLOSE curRarUsed
  974. DEALLOCATE curRarUsed
  975. PRINT '--############# Ended rarely used indexes drop statements #############' + CHAR(10)
  976. END;
  977. PRINT CHAR(10) + '/* Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */'
  978. PRINT CHAR(10) + '/*
  979. NOTE: It is possible that a clustered index (unique or not) is among the duplicate indexes to be dropped, namely if a non-clustered primary key exists on the table.
  980. In this case, make the appropriate changes in the clustered index (making it unique and/or primary key in this case), and drop the non-clustered instead.
  981. */'
  982. PRINT CHAR(10) + '--############# Existing Duplicate indexes drop statements #############' + CHAR(10)
  983. DECLARE Dup_Stats CURSOR FAST_FORWARD FOR SELECT 'USE ' + I.[database_name] + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM sys.indexes WHERE name = N'''+ I.[index_name] + ''')' + CHAR(10) + 'DROP INDEX ' + QUOTENAME(I.[index_name]) + ' ON ' + QUOTENAME(I.[schema_name]) + '.' + QUOTENAME(I.[table_name]) + ';' + CHAR(10) + 'GO' + CHAR(10)
  984. FROM #tmpAgg I INNER JOIN #tmpAgg I2
  985. ON I.database_id = I2.database_id AND I.[object_id] = I2.[object_id] AND I.[index_id] <> I2.[index_id]
  986. AND I.[KeyCols] = I2.[KeyCols] AND (I.IncludedCols = I2.IncludedCols OR (I.IncludedCols IS NULL AND I2.IncludedCols IS NULL))
  987. AND ((I.filter_definition = I2.filter_definition) OR (I.filter_definition IS NULL AND I2.filter_definition IS NULL))
  988. WHERE I.[type] IN (1,2,5,6) -- clustered, non-clustered, clustered and non-clustered columnstore indexes only
  989. AND I2.[type] IN (1,2,5,6) -- clustered, non-clustered, clustered and non-clustered columnstore indexes only
  990. AND I.[index_id] NOT IN (
  991. SELECT COALESCE((SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
  992. WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id]
  993. AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
  994. AND (tI3.is_unique = 1 AND tI3.is_primary_key = 1)
  995. GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
  996. (SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
  997. WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id]
  998. AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
  999. AND (tI3.is_unique = 1 OR tI3.is_primary_key = 1)
  1000. GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered),
  1001. (SELECT MIN(tI3.[index_id]) FROM #tmpAgg tI3
  1002. WHERE tI3.[database_id] = I.[database_id] AND tI3.[object_id] = I.[object_id]
  1003. AND tI3.[KeyCols] = I.[KeyCols] AND (tI3.IncludedCols = I.IncludedCols OR (tI3.IncludedCols IS NULL AND I.IncludedCols IS NULL))
  1004. GROUP BY tI3.[object_id], tI3.KeyCols, tI3.IncludedCols, tI3.[KeyColsOrdered], tI3.IncludedColsOrdered)
  1005. ))
  1006. GROUP BY I.[database_id], I.[database_name], I.[object_id], I.[schema_name], I.[table_name], I.[index_id], I.[index_name], I.[Hits], I.KeyCols, I.IncludedCols, I.[KeyColsOrdered], I.IncludedColsOrdered, I.type_desc, I.[AllColsOrdered], I.is_primary_key, I.is_unique_constraint, I.is_unique, I.is_padded, I.has_filter, I.filter_definition
  1007. ORDER BY I.database_name, I.[table_name], I.[index_id];
  1008. OPEN Dup_Stats
  1009. FETCH NEXT FROM Dup_Stats INTO @strSQL
  1010. WHILE (@@FETCH_STATUS = 0)
  1011. BEGIN
  1012. PRINT @strSQL
  1013. FETCH NEXT FROM Dup_Stats INTO @strSQL
  1014. END
  1015. CLOSE Dup_Stats
  1016. DEALLOCATE Dup_Stats
  1017. PRINT '--############# Ended Duplicate indexes drop statements #############' + CHAR(10)
  1018. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIPS'))
  1019. DROP TABLE #tmpIPS;
  1020. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIOS'))
  1021. DROP TABLE #tmpIOS;
  1022. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIUS'))
  1023. DROP TABLE #tmpIUS;
  1024. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXIS'))
  1025. DROP TABLE #tmpXIS;
  1026. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpXNCIS'))
  1027. DROP TABLE #tmpXNCIS;
  1028. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpIxs'))
  1029. DROP TABLE #tmpIxs;
  1030. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpHashIxs'))
  1031. DROP TABLE #tmpHashIxs;
  1032. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAgg'))
  1033. DROP TABLE #tmpAgg;
  1034. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPHash'))
  1035. DROP TABLE #tmpAggXTPHash;
  1036. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpAggXTPNC'))
  1037. DROP TABLE #tmpAggXTPNC;
  1038. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblWorking'))
  1039. DROP TABLE #tblWorking;
  1040. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblCode'))
  1041. DROP TABLE #tblCode;
  1042. GO