view_HypObjects.sql 4.1 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455565758596061626364656667686970717273747576777879808182838485868788899091929394
  1. --
  2. -- 2012-06-14 Pedro Lopes (Microsoft) [email protected] (http://aka.ms/sqlinsights/)
  3. --
  4. -- List Hypothetical objects (with drop statements);
  5. --
  6. SET NOCOUNT ON;
  7. DECLARE @i int, @maxi int, @dbname sysname, @sqlcmd NVARCHAR(4000), @dbid int, @ErrorMessage NVARCHAR(500)
  8. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpdbs'))
  9. CREATE TABLE #tmpdbs (id int IDENTITY(1,1), [dbid] int, [dbname] sysname)
  10. INSERT INTO #tmpdbs ([dbid], [dbname])
  11. SELECT database_id, name FROM master.sys.databases WHERE is_read_only = 0 AND state = 0 AND database_id > 4 AND is_distributor = 0;
  12. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblHypObj'))
  13. CREATE TABLE #tblHypObj ([DBName] sysname, [Table] VARCHAR(255), [Object] VARCHAR(255), [Type] VARCHAR(10))
  14. SET @i = 1
  15. SET @maxi = (SELECT MAX(id) FROM #tmpdbs)
  16. WHILE @i <= @maxi
  17. BEGIN
  18. SET @dbname = (SELECT [dbname] FROM #tmpdbs WHERE id = @i)
  19. SET @dbid = (SELECT [dbid] FROM #tmpdbs WHERE id = @i)
  20. SET @sqlcmd = 'SELECT ''' + @dbname + ''' AS [DBName], QUOTENAME(o.[name]), i.name, ''INDEX'' FROM ' + QUOTENAME(@dbname) + '.sys.indexes i
  21. INNER JOIN sys.objects o ON o.[object_id] = i.[object_id]
  22. INNER JOIN sys.tables AS mst ON mst.[object_id] = i.[object_id]
  23. INNER JOIN sys.schemas AS t ON t.[schema_id] = mst.[schema_id]
  24. WHERE i.is_hypothetical = 1
  25. UNION ALL
  26. SELECT ''' + @dbname + ''' AS [DBName], QUOTENAME(o.[name]), s.name, ''STATISTICS'' FROM ' + QUOTENAME(@dbname) + '.sys.stats s
  27. INNER JOIN sys.objects o (NOLOCK) ON o.[object_id] = s.[object_id]
  28. INNER JOIN sys.tables AS mst (NOLOCK) ON mst.[object_id] = s.[object_id]
  29. INNER JOIN sys.schemas AS t (NOLOCK) ON t.[schema_id] = mst.[schema_id]
  30. WHERE (s.name LIKE ''hind_%'' OR s.name LIKE ''_dta_stat%'') AND auto_created = 0
  31. AND s.name NOT IN (SELECT name FROM ' + QUOTENAME(@dbname) + '.sys.indexes)'
  32. BEGIN TRY
  33. INSERT INTO #tblHypObj
  34. EXECUTE sp_executesql @sqlcmd
  35. END TRY
  36. BEGIN CATCH
  37. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  38. SELECT @ErrorMessage = 'Hypothetical objects subsection - Error raised in TRY block. ' + ERROR_MESSAGE()
  39. RAISERROR (@ErrorMessage,16,1);
  40. END CATCH
  41. SET @i = @i + 1
  42. END
  43. IF (SELECT COUNT([Object]) FROM #tblHypObj) > 0
  44. BEGIN
  45. SELECT 'Hypothetical_objects' AS [Information], '[WARNING: Some databases have indexes or statistics that are marked as hypothetical. It is recommended to drop these objects as soon as possible]' AS [Deviation]
  46. SELECT 'Hypothetical_objects' AS [Information], DBName AS [Database Name], [Table] AS [Table Name], [Object] AS [Object Name], [Type] AS [Object Type]
  47. FROM #tblHypObj
  48. ORDER BY 2, 3, 5
  49. DECLARE @strSQL NVARCHAR(4000)
  50. PRINT '--** Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */' + CHAR(10)
  51. PRINT CHAR(10) + '--############# Existing Hypothetical objects drop statements #############' + CHAR(10)
  52. DECLARE ITW_Stats CURSOR FAST_FORWARD FOR SELECT 'USE ' + [DBName] + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM ' + CASE WHEN [Type] = 'STATISTICS' THEN 'sys.stats' ELSE 'sys.indexes' END + ' WHERE name = N'''+ [Object] + ''')' + CHAR(10) +
  53. CASE WHEN [Type] = 'STATISTICS' THEN 'DROP STATISTICS ' + [Table] + '.' + QUOTENAME([Object]) + ';' + CHAR(10) + 'GO' + CHAR(10)
  54. ELSE 'DROP INDEX ' + QUOTENAME([Object]) + ' ON ' + [Table] + ';' + CHAR(10) + 'GO' + CHAR(10)
  55. END
  56. FROM #tblHypObj
  57. ORDER BY DBName, [Table]
  58. OPEN ITW_Stats
  59. FETCH NEXT FROM ITW_Stats INTO @strSQL
  60. WHILE (@@FETCH_STATUS = 0)
  61. BEGIN
  62. PRINT @strSQL
  63. FETCH NEXT FROM ITW_Stats INTO @strSQL
  64. END
  65. CLOSE ITW_Stats
  66. DEALLOCATE ITW_Stats
  67. PRINT '--############# Ended Hypothetical objects drop statements #############' + CHAR(10)
  68. END
  69. ELSE
  70. BEGIN
  71. SELECT 'Hypothetical_objects' AS [Information], '[OK]' AS [Deviation]
  72. END;
  73. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpdbs'))
  74. DROP TABLE #tmpdbs;
  75. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblHypObj'))
  76. DROP TABLE #tblHypObj;
  77. GO