5_job_Maintenance.sql 46 KB

1234567891011121314151617181920212223242526272829303132333435363738394041424344454647484950515253545556575859606162636465666768697071727374757677787980818283848586878889909192939495969798991001011021031041051061071081091101111121131141151161171181191201211221231241251261271281291301311321331341351361371381391401411421431441451461471481491501511521531541551561571581591601611621631641651661671681691701711721731741751761771781791801811821831841851861871881891901911921931941951961971981992002012022032042052062072082092102112122132142152162172182192202212222232242252262272282292302312322332342352362372382392402412422432442452462472482492502512522532542552562572582592602612622632642652662672682692702712722732742752762772782792802812822832842852862872882892902912922932942952962972982993003013023033043053063073083093103113123133143153163173183193203213223233243253263273283293303313323333343353363373383393403413423433443453463473483493503513523533543553563573583593603613623633643653663673683693703713723733743753763773783793803813823833843853863873883893903913923933943953963973983994004014024034044054064074084094104114124134144154164174184194204214224234244254264274284294304314324334344354364374384394404414424434444454464474484494504514524534544554564574584594604614624634644654664674684694704714724734744754764774784794804814824834844854864874884894904914924934944954964974984995005015025035045055065075085095105115125135145155165175185195205215225235245255265275285295305315325335345355365375385395405415425435445455465475485495505515525535545555565575585595605615625635645655665675685695705715725735745755765775785795805815825835845855865875885895905915925935945955965975985996006016026036046056066076086096106116126136146156166176186196206216226236246256266276286296306316326336346356366376386396406416426436446456466476486496506516526536546556566576586596606616626636646656666676686696706716726736746756766776786796806816826836846856866876886896906916926936946956966976986997007017027037047057067077087097107117127137147157167177187197207217227237247257267277287297307317327337347357367377387397407417427437447457467477487497507517527537547557567577587597607617627637647657667677687697707717727737747757767777787797807817827837847857867877887897907917927937947957967977987998008018028038048058068078088098108118128138148158168178188198208218228238248258268278288298308318328338348358368378388398408418428438448458468478488498508518528538548558568578588598608618628638648658668678688698708718728738748758768778788798808818828838848858868878888898908918928938948958968978988999009019029039049059069079089099109119129139149159169179189199209219229239249259269279289299309319329339349359369379389399409419429439449459469479489499509519529539549559569579589599609619629639649659669679689699709719729739749759769779789799809819829839849859869879889899909919929939949959969979989991000100110021003100410051006100710081009101010111012101310141015101610171018101910201021102210231024102510261027102810291030103110321033103410351036103710381039104010411042104310441045104610471048104910501051105210531054105510561057105810591060106110621063106410651066106710681069107010711072107310741075107610771078107910801081108210831084108510861087108810891090109110921093109410951096109710981099110011011102110311041105110611071108110911101111111211131114111511161117111811191120112111221123112411251126112711281129113011311132113311341135113611371138113911401141114211431144
  1. USE [msdb]
  2. GO
  3. IF EXISTS(SELECT [object_id] FROM sys.views WHERE [name] = 'vw_MaintenanceLog')
  4. BEGIN
  5. DROP VIEW vw_MaintenanceLog;
  6. PRINT 'View vw_MaintenanceLog dropped'
  7. END
  8. GO
  9. CREATE VIEW vw_MaintenanceLog AS
  10. SELECT [name]
  11. ,[step_name]
  12. ,(SELECT REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(
  13. [log],
  14. NCHAR(1),N'?'),NCHAR(2),N'?'),NCHAR(3),N'?'),NCHAR(4),N'?'),NCHAR(5),N'?'),NCHAR(6),N'?'),NCHAR(7),N'?'),NCHAR(8),N'?'),NCHAR(11),N'?'),NCHAR(12),N'?'),NCHAR(14),N'?'),NCHAR(15),N'?'),NCHAR(16),N'?'),NCHAR(17),N'?'),NCHAR(18),N'?'),NCHAR(19),N'?'),NCHAR(20),N'?'),NCHAR(21),N'?'),NCHAR(22),N'?'),NCHAR(23),N'?'),NCHAR(24),N'?'),NCHAR(25),N'?'),NCHAR(26),N'?'),NCHAR(27),N'?'),NCHAR(28),N'?'),NCHAR(29),N'?'),NCHAR(30),N'?'),NCHAR(31),N'?')
  15. AS [text()] FROM [msdb].[dbo].[sysjobstepslogs] sjsl2 WHERE sjsl2.log_id = sjsl.log_id FOR XML PATH(''), TYPE) AS 'Log'
  16. ,sjsl.[date_created]
  17. ,sjsl.[date_modified]
  18. ,([log_size]/1024) AS [log_size_kb]
  19. FROM [msdb].[dbo].[sysjobstepslogs] sjsl
  20. INNER JOIN [msdb].[dbo].[sysjobsteps] sjs ON sjs.[step_uid] = sjsl.[step_uid]
  21. INNER JOIN [msdb].[dbo].[sysjobs] sj ON sj.[job_id] = sjs.[job_id]
  22. WHERE [name] = 'Weekly Maintenance';
  23. GO
  24. PRINT 'View vw_MaintenanceLog view created';
  25. GO
  26. IF OBJECTPROPERTY(OBJECT_ID('dbo.usp_CheckIntegrity'), N'IsProcedure') = 1
  27. BEGIN
  28. DROP PROCEDURE dbo.usp_CheckIntegrity;
  29. PRINT 'Procedure usp_CheckIntegrity dropped'
  30. END
  31. GO
  32. CREATE PROCEDURE usp_CheckIntegrity @VLDBMode bit = 1, @SingleUser bit = 0, @CreateSnap bit = 1, @SnapPath NVARCHAR(1000) = NULL, @AO_Secondary bit = 0, @Physical bit = 0
  33. AS
  34. /*
  35. This checks the logical and physical integrity of all the objects in the specified database by performing the following operations:
  36. |-For VLDBs (larger than 1TB):
  37. |- On Sundays, if VLDB Mode = 0, runs DBCC CHECKALLOC.
  38. |- On Sundays, runs DBCC CHECKCATALOG.
  39. |- Everyday, if VLDB Mode = 0, runs DBCC CHECKTABLE or if VLDB Mode = 1, DBCC CHECKFILEGROUP on a subset of tables and views, divided by daily buckets.
  40. |-For DBs smaller than 1TB:
  41. |- Every Sunday a DBCC CHECKDB checks the logical and physical integrity of all the objects in the specified database.
  42. To set how VLDBs are handled, set @VLDBMode to 0 = Bucket by Table Size or 1 = Bucket by Filegroup Size
  43. Buckets are built weekly, on Sunday.
  44. IMPORTANT: Consider running DBCC CHECKDB routinely (at least, weekly). On large databases and for more frequent checks, consider using the PHYSICAL_ONLY parameter.
  45. http://msdn.microsoft.com/en-us/library/ms176064.aspx
  46. http://blogs.msdn.com/b/sqlserverstorageengine/archive/2006/10/20/consistency-checking-options-for-a-vldb.aspx
  47. Excludes all Offline and Read-Only DBs, and works on databases over 1TB
  48. If a database has Read-Only filegroups, any integrity check will fail if there are other open connections to the database.
  49. Setting @CreateSnap = 1 will create a database snapshot before running the check on the snapshot, and drop it at the end (default).
  50. Setting @CreateSnap = 0 means the integrity check might fail if there are other open connection on the database.
  51. Note: set a custom snapshot creation path in @SnapPath or the same path as the database in scope will be used.
  52. Ex.: @SnapPath = 'C:\Program Files\Microsoft SQL Server\MSSQL11.MSSQLSERVER\MSSQL\Data'
  53. If snapshots are not allowed and a database has Read-Only filegroups, any integrity check will fail if there are other openned connections to the database.
  54. Setting @SingleUser = 1 will set the database in single user mode before running the check, and to multi user afterwards.
  55. Setting @SingleUser = 0 means the integrity check might fail if there are other open connection on the database.
  56. If on SQL Server 2012 or above and you are using Availability Replicas:
  57. Setting @AO_Secondary = 0 then AlwaysOn primary replicas are eligible for Integrity Checks, but secondary replicas are skipped.
  58. Setting @AO_Secondary = 1 then AlwaysOn secondary replicas are eligible for Integrity Checks, but primary replicas are skipped.
  59. If more frequent checks are required, consider using the PHYSICAL_ONLY parameter:
  60. Setting @Physical = 0 does not consider PHYSICAL_ONLY option.
  61. Setting @Physical = 1 enables PHYSICAL_ONLY option (where available).
  62. */
  63. SET NOCOUNT ON;
  64. IF @VLDBMode NOT IN (0,1)
  65. BEGIN
  66. RAISERROR('[ERROR: Must set a integrity check strategy for any VLDBs we encounter - 0 = Bucket by Table Size; 1 = Bucket by Filegroup Size]', 16, 1, N'VLDB')
  67. RETURN
  68. END
  69. IF @CreateSnap = 1 AND @SingleUser = 1
  70. BEGIN
  71. RAISERROR('[ERROR: Must select only one method of checking databases with Read-Only FGs]', 16, 1, N'ReadOnlyFGs')
  72. RETURN
  73. END
  74. DECLARE @dbid int, @dbname sysname, @sqlcmdROFG NVARCHAR(1000), @sqlcmd NVARCHAR(max), @sqlcmd_Create NVARCHAR(max), @sqlcmd_Drop NVARCHAR(500)
  75. DECLARE @msg NVARCHAR(500), @params NVARCHAR(500), @sqlcmd_AO NVARCHAR(4000);
  76. DECLARE @filename sysname, @filecreateid int, @Message VARCHAR(1000);
  77. DECLARE @Buckets tinyint, @BucketCnt tinyint, @BucketPages bigint, @TodayBucket tinyint, @dbsize bigint, @fg_id int, @HasROFG bigint, @sqlsnapcmd NVARCHAR(max);
  78. DECLARE @BucketId tinyint, @object_id int, @name sysname, @schema sysname, @type CHAR(2), @type_desc NVARCHAR(60), @used_page_count bigint;
  79. DECLARE @sqlmajorver int, @ErrorMessage NVARCHAR(4000)
  80. IF NOT EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tblDbBuckets')
  81. CREATE TABLE tblDbBuckets (BucketId int, [database_id] int, [object_id] int, [name] sysname, [schema] sysname, [type] CHAR(2), type_desc NVARCHAR(60), used_page_count bigint, isdone bit);
  82. IF NOT EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tblFgBuckets')
  83. CREATE TABLE tblFgBuckets (BucketId int, [database_id] int, [data_space_id] int, [name] sysname, used_page_count bigint, isdone bit);
  84. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpdbs'))
  85. CREATE TABLE #tmpdbs (id int IDENTITY(1,1), [dbid] int, [dbname] sysname, rows_size_MB bigint, isdone bit)
  86. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblBuckets'))
  87. CREATE TABLE #tblBuckets (BucketId int, MaxAmount bigint, CurrentRunTotal bigint)
  88. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblObj'))
  89. CREATE TABLE #tblObj ([object_id] int, [name] sysname, [schema] sysname, [type] CHAR(2), type_desc NVARCHAR(60), used_page_count bigint, isdone bit)
  90. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblFGs'))
  91. CREATE TABLE #tblFGs ([data_space_id] int, [name] sysname, used_page_count bigint, isdone bit)
  92. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblSnapFiles'))
  93. CREATE TABLE #tblSnapFiles ([name] sysname, isdone bit)
  94. SELECT @sqlmajorver = CONVERT(int, (@@microsoftversion / 0x1000000) & 0xff);
  95. SELECT @Message = '** Start: ' + CONVERT(VARCHAR, GETDATE())
  96. RAISERROR(@Message, 0, 42) WITH NOWAIT;
  97. SET @sqlcmd_AO = 'SELECT sd.database_id, sd.name, SUM((size * 8) / 1024) AS rows_size_MB, 0
  98. FROM sys.databases sd (NOLOCK)
  99. INNER JOIN sys.master_files smf (NOLOCK) ON sd.database_id = smf.database_id
  100. WHERE sd.is_read_only = 0 AND sd.state = 0 AND sd.database_id <> 2 AND smf.[type] = 0';
  101. IF @sqlmajorver >= 11 AND @AO_Secondary = 0 -- Skip all local AlwaysOn secondary replicas
  102. BEGIN
  103. SET @sqlcmd_AO = @sqlcmd_AO + CHAR(10) + 'AND sd.[database_id] NOT IN (SELECT dr.database_id FROM sys.dm_hadr_database_replica_states dr
  104. INNER JOIN sys.dm_hadr_availability_replica_states rs ON dr.group_id = rs.group_id
  105. INNER JOIN sys.databases d ON dr.database_id = d.database_id
  106. WHERE rs.role = 2 -- Is Secondary
  107. AND dr.is_local = 1
  108. AND rs.is_local = 1)'
  109. END;
  110. IF @sqlmajorver >= 11 AND @AO_Secondary = 1 -- Skip all local AlwaysOn primary replicas
  111. BEGIN
  112. SET @sqlcmd_AO = @sqlcmd_AO + CHAR(10) + 'AND sd.[database_id] NOT IN (SELECT dr.database_id FROM sys.dm_hadr_database_replica_states dr
  113. INNER JOIN sys.dm_hadr_availability_replica_states rs ON dr.group_id = rs.group_id
  114. INNER JOIN sys.databases d ON dr.database_id = d.database_id
  115. WHERE rs.role = 1 -- Is Primary
  116. AND dr.is_local = 1
  117. AND rs.is_local = 0)'
  118. END;
  119. SET @sqlcmd_AO = @sqlcmd_AO + CHAR(10) + 'GROUP BY sd.database_id, sd.name';
  120. INSERT INTO #tmpdbs ([dbid], [dbname], rows_size_MB, isdone)
  121. EXEC sp_executesql @sqlcmd_AO;
  122. WHILE (SELECT COUNT([dbid]) FROM #tmpdbs WHERE isdone = 0) > 0
  123. BEGIN
  124. SET @dbid = (SELECT TOP 1 [dbid] FROM #tmpdbs WHERE isdone = 0)
  125. SET @dbname = (SELECT TOP 1 [dbname] FROM #tmpdbs WHERE isdone = 0)
  126. SET @dbsize = (SELECT TOP 1 [rows_size_MB] FROM #tmpdbs WHERE isdone = 0)
  127. -- If a snapshot is to be created, set the proper path
  128. IF @SnapPath IS NULL
  129. BEGIN
  130. SELECT TOP 1 @SnapPath = physical_name FROM sys.master_files WHERE database_id = @dbid AND [type] = 0 AND [state] = 0
  131. IF @SnapPath IS NOT NULL
  132. BEGIN
  133. SELECT @SnapPath = LEFT(@SnapPath, LEN(@SnapPath)-CHARINDEX('\',REVERSE(@SnapPath)))
  134. END
  135. END;
  136. -- Find if database has Read-Only FGs
  137. SET @sqlcmd = N'USE [' + @dbname + ']; SELECT @HasROFGOUT = COUNT(data_space_id) FROM sys.filegroups WHERE is_read_only = 1'
  138. SET @params = N'@HasROFGOUT bigint OUTPUT';
  139. EXECUTE sp_executesql @sqlcmd, @params, @HasROFGOUT=@HasROFG OUTPUT;
  140. SET @sqlcmd = ''
  141. IF @dbsize < 1048576 -- smaller than 1TB
  142. BEGIN
  143. -- Is it Sunday yet? If so, start database check
  144. IF (SELECT 1 & POWER(2, DATEPART(weekday, GETDATE())-1)) > 0
  145. BEGIN
  146. IF @HasROFG > 0 AND @CreateSnap = 1 AND @SnapPath IS NOT NULL
  147. SELECT @msg = CHAR(10) + CONVERT(VARCHAR, GETDATE(), 9) + ' - Started integrity checks on ' + @dbname + '_CheckDB_Snapshot';
  148. IF (@HasROFG > 0 AND @SingleUser = 1) OR (@HasROFG = 0)
  149. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Started integrity checks on ' + @dbname;
  150. RAISERROR (@msg, 10, 1) WITH NOWAIT
  151. IF @HasROFG > 0 AND @CreateSnap = 1 AND @SnapPath IS NOT NULL
  152. SET @sqlcmd = 'DBCC CHECKDB (''' + @dbname + '_CheckDB_Snapshot'') WITH '
  153. IF (@HasROFG > 0 AND @SingleUser = 1) OR (@HasROFG = 0)
  154. SET @sqlcmd = 'DBCC CHECKDB (' + CONVERT(NVARCHAR(10),@dbid) + ') WITH '
  155. IF @Physical = 1
  156. BEGIN
  157. SET @sqlcmd = @sqlcmd + 'PHYSICAL_ONLY;'
  158. END
  159. ELSE
  160. BEGIN
  161. SET @sqlcmd = @sqlcmd + 'DATA_PURITY;'
  162. END;
  163. IF @HasROFG > 0 AND @CreateSnap = 1 AND @SnapPath IS NOT NULL
  164. BEGIN
  165. TRUNCATE TABLE #tblSnapFiles;
  166. INSERT INTO #tblSnapFiles
  167. SELECT name, 0 FROM sys.master_files WHERE database_id = @dbid AND [type] = 0;
  168. SET @filecreateid = 1
  169. SET @sqlsnapcmd = ''
  170. WHILE (SELECT COUNT([name]) FROM #tblSnapFiles WHERE isdone = 0) > 0
  171. BEGIN
  172. SELECT TOP 1 @filename = [name] FROM #tblSnapFiles WHERE isdone = 0
  173. SET @sqlsnapcmd = @sqlsnapcmd + CHAR(10) + '(NAME = [' + @filename + '], FILENAME = ''' + @SnapPath + '\' + @dbname + '_CheckDB_Snapshot_Data_' + CONVERT(VARCHAR(10), @filecreateid) + '.ss''),'
  174. SET @filecreateid = @filecreateid + 1
  175. UPDATE #tblSnapFiles
  176. SET isdone = 1 WHERE [name] = @filename;
  177. END;
  178. SELECT @sqlsnapcmd = LEFT(@sqlsnapcmd, LEN(@sqlsnapcmd)-1);
  179. SET @sqlcmd_Create = 'USE master;
  180. IF NOT EXISTS (SELECT 1 FROM sys.databases WHERE [name] = ''' + @dbname + '_CheckDB_Snapshot'')
  181. CREATE DATABASE [' + @dbname + '_CheckDB_Snapshot] ON ' + @sqlsnapcmd + CHAR(10) + 'AS SNAPSHOT OF [' + @dbname + '];'
  182. SET @sqlcmd_Drop = 'USE master;
  183. IF EXISTS (SELECT 1 FROM sys.databases WHERE [name] = ''' + @dbname + '_CheckDB_Snapshot'')
  184. DROP DATABASE [' + @dbname + '_CheckDB_Snapshot];'
  185. END
  186. IF @HasROFG > 0 AND @CreateSnap = 1 AND @SnapPath IS NULL
  187. BEGIN
  188. SET @sqlcmd = NULL
  189. SELECT @Message = '** Skipping database ' + @dbname + ': Could not find a valid path to create DB snapshot - ' + CONVERT(VARCHAR, GETDATE())
  190. RAISERROR(@Message, 0, 42) WITH NOWAIT;
  191. END
  192. IF @HasROFG > 0 AND @SingleUser = 1
  193. BEGIN
  194. SET @sqlcmd = 'USE master;
  195. ALTER DATABASE [' + @dbname + '] SET SINGLE_USER WITH ROLLBACK IMMEDIATE;' + CHAR(10) + @sqlcmd + CHAR(10) +
  196. 'USE master;
  197. ALTER DATABASE [' + @dbname + '] SET MULTI_USER WITH ROLLBACK IMMEDIATE;'
  198. END
  199. IF @sqlcmd_Create IS NOT NULL
  200. BEGIN TRY
  201. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Creating database snapshot ' + @dbname + '_CheckDB_Snapshot';
  202. RAISERROR (@msg, 10, 1) WITH NOWAIT
  203. EXEC sp_executesql @sqlcmd_Create;
  204. END TRY
  205. BEGIN CATCH
  206. EXEC sp_executesql @sqlcmd_Drop;
  207. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  208. SELECT @ErrorMessage = 'Create Snapshot - Error raised in TRY block. ' + ERROR_MESSAGE()
  209. RAISERROR (@ErrorMessage, 16, 1);
  210. END CATCH
  211. IF @sqlcmd IS NOT NULL
  212. BEGIN TRY
  213. EXEC sp_executesql @sqlcmd;
  214. UPDATE tblFgBuckets
  215. SET isdone = 1
  216. FROM tblFgBuckets
  217. WHERE [database_id] = @dbid AND [data_space_id] = @fg_id AND used_page_count = @used_page_count AND isdone = 0 AND BucketId = @TodayBucket
  218. END TRY
  219. BEGIN CATCH
  220. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  221. SELECT @ErrorMessage = 'Check cycle - Error raised in TRY block. ' + ERROR_MESSAGE()
  222. RAISERROR (@ErrorMessage, 16, 1);
  223. RETURN
  224. END CATCH
  225. IF @sqlcmd_Drop IS NOT NULL
  226. BEGIN TRY
  227. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Droping database snapshot ' + @dbname + '_CheckDB_Snapshot';
  228. RAISERROR (@msg, 10, 1) WITH NOWAIT
  229. EXEC sp_executesql @sqlcmd_Drop;
  230. END TRY
  231. BEGIN CATCH
  232. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  233. SELECT @ErrorMessage = 'Drop Snapshot - Error raised in TRY block. ' + ERROR_MESSAGE()
  234. RAISERROR (@ErrorMessage, 16, 1);
  235. END CATCH
  236. END
  237. ELSE
  238. BEGIN
  239. SELECT @Message = '** Skipping database ' + @dbname + ': Today is not Sunday - ' + CONVERT(VARCHAR, GETDATE())
  240. RAISERROR(@Message, 0, 42) WITH NOWAIT;
  241. END
  242. END;
  243. IF @dbsize >= 1048576 -- 1TB or Larger, then create buckets
  244. BEGIN
  245. -- Buckets are built on a weekly basis, so is it Sunday yet? If so, start building
  246. IF (SELECT 1 & POWER(2, DATEPART(weekday, GETDATE())-1)) > 0
  247. BEGIN
  248. TRUNCATE TABLE #tblObj
  249. TRUNCATE TABLE #tblBuckets
  250. TRUNCATE TABLE #tblFGs
  251. TRUNCATE TABLE tblFgBuckets
  252. TRUNCATE TABLE tblDbBuckets
  253. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Creating database snapshot ' + @dbname + '_CheckDB_Snapshot';
  254. RAISERROR (@msg, 10, 1) WITH NOWAIT
  255. IF @VLDBMode = 0 -- Setup to bucketize by Table Size
  256. BEGIN
  257. SET @sqlcmd = 'SELECT so.[object_id], so.[name], ss.name, so.[type], so.type_desc, SUM(sps.used_page_count) AS used_page_count, 0
  258. FROM [' + @dbname + '].sys.objects so
  259. INNER JOIN [' + @dbname + '].sys.dm_db_partition_stats sps ON so.[object_id] = sps.[object_id]
  260. INNER JOIN [' + @dbname + '].sys.indexes si ON so.[object_id] = si.[object_id]
  261. INNER JOIN [' + @dbname + '].sys.schemas ss ON so.[schema_id] = ss.[schema_id]
  262. WHERE so.[type] IN (''S'', ''U'', ''V'')
  263. GROUP BY so.[object_id], so.[name], ss.name, so.[type], so.type_desc
  264. ORDER BY used_page_count DESC'
  265. INSERT INTO #tblObj
  266. EXEC sp_executesql @sqlcmd;
  267. END
  268. IF @VLDBMode = 1 -- Setup to bucketize by Filegroup Size
  269. BEGIN
  270. SET @sqlcmd = 'SELECT fg.data_space_id, fg.name AS [filegroup_name], SUM(sps.used_page_count) AS used_page_count, 0
  271. FROM [' + @dbname + '].sys.dm_db_partition_stats sps
  272. INNER JOIN [' + @dbname + '].sys.indexes i ON sps.object_id = i.object_id
  273. INNER JOIN [' + @dbname + '].sys.partition_schemes ps ON ps.data_space_id = i.data_space_id
  274. INNER JOIN [' + @dbname + '].sys.destination_data_spaces dds ON dds.partition_scheme_id = ps.data_space_id AND dds.destination_id = sps.partition_number
  275. INNER JOIN [' + @dbname + '].sys.filegroups fg ON dds.data_space_id = fg.data_space_id
  276. --WHERE fg.is_read_only = 0
  277. GROUP BY fg.name, ps.name, fg.data_space_id
  278. ORDER BY SUM(sps.used_page_count) DESC, fg.data_space_id'
  279. INSERT INTO #tblFGs
  280. EXEC sp_executesql @sqlcmd;
  281. END
  282. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Bucketizing by ' + CASE WHEN @VLDBMode = 1 THEN 'Filegroup Size' ELSE 'Table Size' END;
  283. RAISERROR (@msg, 10, 1) WITH NOWAIT
  284. -- Create buckets
  285. SET @Buckets = 8
  286. SET @BucketCnt = 1
  287. SET @sqlcmd = N'SELECT @BucketPagesOUT = SUM(used_page_count)/7 FROM ' + CASE WHEN @VLDBMode = 0 THEN '#tblObj' WHEN @VLDBMode = 1 THEN '#tblFGs' END
  288. SET @params = N'@BucketPagesOUT bigint OUTPUT';
  289. EXECUTE sp_executesql @sqlcmd, @params, @BucketPagesOUT=@BucketPages OUTPUT;
  290. WHILE @BucketCnt <> @Buckets
  291. BEGIN
  292. INSERT INTO #tblBuckets VALUES (@BucketCnt, @BucketPages, 0)
  293. SET @BucketCnt = @BucketCnt + 1
  294. END
  295. IF @VLDBMode = 0 -- Populate buckets by Table Size
  296. BEGIN
  297. WHILE (SELECT COUNT(*) FROM #tblObj WHERE isdone = 0) > 0
  298. BEGIN
  299. SELECT TOP 1 @object_id = [object_id], @name = [name], @schema = [schema], @type = [type], @type_desc = type_desc, @used_page_count = used_page_count
  300. FROM #tblObj
  301. WHERE isdone = 0
  302. ORDER BY used_page_count DESC
  303. SELECT TOP 1 @BucketId = BucketId FROM #tblBuckets ORDER BY CurrentRunTotal
  304. INSERT INTO tblDbBuckets
  305. SELECT @BucketId, @dbid, @object_id, @name, @schema, @type, @type_desc, @used_page_count, 0;
  306. UPDATE #tblObj
  307. SET isdone = 1
  308. FROM #tblObj
  309. WHERE [object_id] = @object_id AND used_page_count = @used_page_count AND isdone = 0;
  310. UPDATE #tblBuckets
  311. SET CurrentRunTotal = CurrentRunTotal + @used_page_count
  312. WHERE BucketId = @BucketId;
  313. END
  314. END;
  315. IF @VLDBMode = 1 -- Populate buckets by Filegroup Size
  316. BEGIN
  317. WHILE (SELECT COUNT(*) FROM #tblFGs WHERE isdone = 0) > 0
  318. BEGIN
  319. SELECT TOP 1 @fg_id = [data_space_id], @name = [name], @used_page_count = used_page_count
  320. FROM #tblFGs
  321. WHERE isdone = 0
  322. ORDER BY used_page_count DESC
  323. SELECT TOP 1 @BucketId = BucketId FROM #tblBuckets ORDER BY CurrentRunTotal
  324. INSERT INTO tblFgBuckets
  325. SELECT @BucketId, @dbid, @fg_id, @name, @used_page_count, 0;
  326. UPDATE #tblFGs
  327. SET isdone = 1
  328. FROM #tblFGs
  329. WHERE [data_space_id] = @fg_id AND used_page_count = @used_page_count AND isdone = 0;
  330. UPDATE #tblBuckets
  331. SET CurrentRunTotal = CurrentRunTotal + @used_page_count
  332. WHERE BucketId = @BucketId;
  333. END
  334. END
  335. END;
  336. -- What day is today? 1=Sunday, 2=Monday, 4=Tuesday, 8=Wednesday, 16=Thursday, 32=Friday, 64=Saturday
  337. SELECT @TodayBucket = CASE WHEN 1 & POWER(2, DATEPART(weekday, GETDATE())-1) = 1 THEN 1
  338. WHEN 2 & POWER(2, DATEPART(weekday, GETDATE())-1) = 2 THEN 2
  339. WHEN 4 & POWER(2, DATEPART(weekday, GETDATE())-1) = 4 THEN 3
  340. WHEN 8 & POWER(2, DATEPART(weekday, GETDATE())-1) = 8 THEN 4
  341. WHEN 16 & POWER(2, DATEPART(weekday, GETDATE())-1) = 16 THEN 5
  342. WHEN 32 & POWER(2, DATEPART(weekday, GETDATE())-1) = 32 THEN 6
  343. WHEN 64 & POWER(2, DATEPART(weekday, GETDATE())-1) = 64 THEN 7
  344. END;
  345. -- Is it Sunday yet? If so, start working on allocation and catalog checks on todays bucket
  346. IF (SELECT 1 & POWER(2, DATEPART(weekday, GETDATE())-1)) > 0
  347. BEGIN
  348. IF @VLDBMode = 0
  349. BEGIN
  350. IF @HasROFG > 0 AND @CreateSnap = 1 AND @SnapPath IS NOT NULL
  351. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Started allocation checks on ' + @dbname + '_CheckDB_Snapshot]';
  352. IF (@HasROFG > 0 AND @SingleUser = 1) OR (@HasROFG = 0)
  353. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Started allocation checks on ' + @dbname;
  354. RAISERROR (@msg, 10, 1) WITH NOWAIT
  355. IF @HasROFG > 0 AND @CreateSnap = 1
  356. SET @sqlcmd = 'DBCC CHECKALLOC (''' + @dbname + '_CheckDB_Snapshot'');'
  357. IF (@HasROFG > 0 AND @SingleUser = 1) OR (@HasROFG = 0)
  358. SET @sqlcmd = 'DBCC CHECKALLOC (' + CONVERT(NVARCHAR(10),@dbid) + ');'
  359. IF @HasROFG > 0 AND @CreateSnap = 1 AND @SnapPath IS NOT NULL
  360. BEGIN
  361. TRUNCATE TABLE #tblSnapFiles;
  362. INSERT INTO #tblSnapFiles
  363. SELECT name, 0 FROM sys.master_files WHERE database_id = @dbid AND [type] = 0;
  364. SET @filecreateid = 1
  365. SET @sqlsnapcmd = ''
  366. WHILE (SELECT COUNT([name]) FROM #tblSnapFiles WHERE isdone = 0) > 0
  367. BEGIN
  368. SELECT TOP 1 @filename = [name] FROM #tblSnapFiles WHERE isdone = 0
  369. SET @sqlsnapcmd = @sqlsnapcmd + CHAR(10) + '(NAME = [' + @filename + '], FILENAME = ''' + @SnapPath + '\' + @dbname + '_CheckDB_Snapshot_Data_' + CONVERT(VARCHAR(10), @filecreateid) + '.ss''),'
  370. SET @filecreateid = @filecreateid + 1
  371. UPDATE #tblSnapFiles
  372. SET isdone = 1 WHERE [name] = @filename;
  373. END;
  374. SELECT @sqlsnapcmd = LEFT(@sqlsnapcmd, LEN(@sqlsnapcmd)-1);
  375. SET @sqlcmd_Create = 'USE master;
  376. IF NOT EXISTS (SELECT 1 FROM sys.databases WHERE [name] = ''' + @dbname + '_CheckDB_Snapshot'')
  377. CREATE DATABASE [' + @dbname + '_CheckDB_Snapshot] ON ' + @sqlsnapcmd + CHAR(10) + 'AS SNAPSHOT OF [' + @dbname + '];'
  378. SET @sqlcmd_Drop = 'USE master;
  379. IF EXISTS (SELECT 1 FROM sys.databases WHERE [name] = ''' + @dbname + '_CheckDB_Snapshot'')
  380. DROP DATABASE [' + @dbname + '_CheckDB_Snapshot];'
  381. END
  382. IF @HasROFG > 0 AND @CreateSnap = 1 AND @SnapPath IS NULL
  383. BEGIN
  384. SET @sqlcmd = NULL
  385. SELECT @Message = '** Skipping database ' + @dbname + ': Could not find a valid path to create DB snapshot - ' + CONVERT(VARCHAR, GETDATE())
  386. RAISERROR(@Message, 0, 42) WITH NOWAIT;
  387. END
  388. IF @HasROFG > 0 AND @SingleUser = 1
  389. BEGIN
  390. SET @sqlcmd = 'USE master;
  391. ALTER DATABASE [' + @dbname + '] SET SINGLE_USER WITH ROLLBACK IMMEDIATE;' + CHAR(10) + @sqlcmd + CHAR(10) +
  392. 'USE master;
  393. ALTER DATABASE [' + @dbname + '] SET MULTI_USER WITH ROLLBACK IMMEDIATE;'
  394. END
  395. IF @sqlcmd_Create IS NOT NULL
  396. BEGIN TRY
  397. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Creating database snapshot ' + @dbname + '_CheckDB_Snapshot';
  398. RAISERROR (@msg, 10, 1) WITH NOWAIT
  399. EXEC sp_executesql @sqlcmd_Create;
  400. END TRY
  401. BEGIN CATCH
  402. EXEC sp_executesql @sqlcmd_Drop;
  403. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  404. SELECT @ErrorMessage = 'Create Snapshot - Error raised in TRY block. ' + ERROR_MESSAGE()
  405. RAISERROR (@ErrorMessage, 16, 1);
  406. END CATCH
  407. IF @sqlcmd IS NOT NULL
  408. BEGIN TRY
  409. EXEC sp_executesql @sqlcmd;
  410. UPDATE tblFgBuckets
  411. SET isdone = 1
  412. FROM tblFgBuckets
  413. WHERE [database_id] = @dbid AND [data_space_id] = @fg_id AND used_page_count = @used_page_count AND isdone = 0 AND BucketId = @TodayBucket
  414. END TRY
  415. BEGIN CATCH
  416. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  417. SELECT @ErrorMessage = 'Check cycle - Error raised in TRY block. ' + ERROR_MESSAGE()
  418. RAISERROR (@ErrorMessage, 16, 1);
  419. RETURN
  420. END CATCH
  421. IF @sqlcmd_Drop IS NOT NULL
  422. BEGIN TRY
  423. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Droping database snapshot ' + @dbname + '_CheckDB_Snapshot';
  424. RAISERROR (@msg, 10, 1) WITH NOWAIT
  425. EXEC sp_executesql @sqlcmd_Drop;
  426. END TRY
  427. BEGIN CATCH
  428. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  429. SELECT @ErrorMessage = 'Drop Snapshot - Error raised in TRY block. ' + ERROR_MESSAGE()
  430. RAISERROR (@ErrorMessage, 16, 1);
  431. END CATCH
  432. END;
  433. IF @HasROFG > 0 AND @CreateSnap = 1 AND @SnapPath IS NOT NULL
  434. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Started catalog checks on ' + @dbname + '_CheckDB_Snapshot';
  435. IF (@HasROFG > 0 AND @SingleUser = 1) OR (@HasROFG = 0)
  436. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Started catalog checks on ' + @dbname;
  437. RAISERROR (@msg, 10, 1) WITH NOWAIT
  438. IF @HasROFG > 0 AND @CreateSnap = 1
  439. SET @sqlcmd = 'DBCC CHECKCATALOG (''' + @dbname + '_CheckDB_Snapshot'');'
  440. IF (@HasROFG > 0 AND @SingleUser = 1) OR (@HasROFG = 0)
  441. SET @sqlcmd = 'DBCC CHECKCATALOG (' + CONVERT(NVARCHAR(10),@dbid) + ');'
  442. IF @HasROFG > 0 AND @CreateSnap = 1 AND @SnapPath IS NOT NULL
  443. BEGIN
  444. TRUNCATE TABLE #tblSnapFiles;
  445. INSERT INTO #tblSnapFiles
  446. SELECT name, 0 FROM sys.master_files WHERE database_id = @dbid AND [type] = 0;
  447. SET @filecreateid = 1
  448. SET @sqlsnapcmd = ''
  449. WHILE (SELECT COUNT([name]) FROM #tblSnapFiles WHERE isdone = 0) > 0
  450. BEGIN
  451. SELECT TOP 1 @filename = [name] FROM #tblSnapFiles WHERE isdone = 0
  452. SET @sqlsnapcmd = @sqlsnapcmd + CHAR(10) + '(NAME = [' + @filename + '], FILENAME = ''' + @SnapPath + '\' + @dbname + '_CheckDB_Snapshot_Data_' + CONVERT(VARCHAR(10), @filecreateid) + '.ss''),'
  453. SET @filecreateid = @filecreateid + 1
  454. UPDATE #tblSnapFiles
  455. SET isdone = 1 WHERE [name] = @filename;
  456. END;
  457. SELECT @sqlsnapcmd = LEFT(@sqlsnapcmd, LEN(@sqlsnapcmd)-1);
  458. SET @sqlcmd_Create = 'USE master;
  459. IF NOT EXISTS (SELECT 1 FROM sys.databases WHERE [name] = ''' + @dbname + '_CheckDB_Snapshot'')
  460. CREATE DATABASE [' + @dbname + '_CheckDB_Snapshot] ON ' + @sqlsnapcmd + CHAR(10) + 'AS SNAPSHOT OF [' + @dbname + '];'
  461. SET @sqlcmd_Drop = 'USE master;
  462. IF EXISTS (SELECT 1 FROM sys.databases WHERE [name] = ''' + @dbname + '_CheckDB_Snapshot'')
  463. DROP DATABASE [' + @dbname + '_CheckDB_Snapshot];'
  464. END
  465. IF @HasROFG > 0 AND @CreateSnap = 1 AND @SnapPath IS NULL
  466. BEGIN
  467. SET @sqlcmd = NULL
  468. SELECT @Message = '** Skipping database ' + @dbname + ': Could not find a valid path to create DB snapshot - ' + CONVERT(VARCHAR, GETDATE())
  469. RAISERROR(@Message, 0, 42) WITH NOWAIT;
  470. END
  471. IF @HasROFG > 0 AND @SingleUser = 1
  472. BEGIN
  473. SET @sqlcmd = 'USE master;
  474. ALTER DATABASE [' + @dbname + '] SET SINGLE_USER WITH ROLLBACK IMMEDIATE;' + CHAR(10) + @sqlcmd + CHAR(10) +
  475. 'USE master;
  476. ALTER DATABASE [' + @dbname + '] SET MULTI_USER WITH ROLLBACK IMMEDIATE;'
  477. END
  478. IF @sqlcmd_Create IS NOT NULL
  479. BEGIN TRY
  480. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Creating database snapshot ' + @dbname + '_CheckDB_Snapshot';
  481. RAISERROR (@msg, 10, 1) WITH NOWAIT
  482. EXEC sp_executesql @sqlcmd_Create;
  483. END TRY
  484. BEGIN CATCH
  485. EXEC sp_executesql @sqlcmd_Drop;
  486. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  487. SELECT @ErrorMessage = 'Create Snapshot - Error raised in TRY block. ' + ERROR_MESSAGE()
  488. RAISERROR (@ErrorMessage, 16, 1);
  489. END CATCH
  490. IF @sqlcmd IS NOT NULL
  491. BEGIN TRY
  492. EXEC sp_executesql @sqlcmd;
  493. UPDATE tblFgBuckets
  494. SET isdone = 1
  495. FROM tblFgBuckets
  496. WHERE [database_id] = @dbid AND [data_space_id] = @fg_id AND used_page_count = @used_page_count AND isdone = 0 AND BucketId = @TodayBucket
  497. END TRY
  498. BEGIN CATCH
  499. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  500. SELECT @ErrorMessage = 'Check cycle - Error raised in TRY block. ' + ERROR_MESSAGE()
  501. RAISERROR (@ErrorMessage, 16, 1);
  502. RETURN
  503. END CATCH
  504. IF @sqlcmd_Drop IS NOT NULL
  505. BEGIN TRY
  506. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Droping database snapshot ' + @dbname + '_CheckDB_Snapshot';
  507. RAISERROR (@msg, 10, 1) WITH NOWAIT
  508. EXEC sp_executesql @sqlcmd_Drop;
  509. END TRY
  510. BEGIN CATCH
  511. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  512. SELECT @ErrorMessage = 'Drop Snapshot - Error raised in TRY block. ' + ERROR_MESSAGE()
  513. RAISERROR (@ErrorMessage, 16, 1);
  514. END CATCH
  515. END
  516. IF @VLDBMode = 0 -- Now do table checks on todays bucket
  517. BEGIN
  518. WHILE (SELECT COUNT(*) FROM tblDbBuckets WHERE [database_id] = @dbid AND isdone = 0 AND BucketId = @TodayBucket) > 0
  519. BEGIN
  520. SELECT TOP 1 @name = [name], @schema = [schema], @used_page_count = used_page_count
  521. FROM tblDbBuckets
  522. WHERE [database_id] = @dbid AND isdone = 0 AND BucketId = @TodayBucket
  523. ORDER BY used_page_count DESC
  524. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Started table checks on ' + @dbname + ' - table ' + @schema + '.' + @name;
  525. RAISERROR (@msg, 10, 1) WITH NOWAIT
  526. SET @sqlcmd = 'USE [' + @dbname + '];
  527. DBCC CHECKTABLE (''' + @schema + '.' + @name + ''') WITH '
  528. IF @Physical = 1
  529. BEGIN
  530. SET @sqlcmd = @sqlcmd + 'PHYSICAL_ONLY;'
  531. END
  532. ELSE
  533. BEGIN
  534. SET @sqlcmd = @sqlcmd + 'DATA_PURITY;'
  535. END;
  536. IF @sqlcmd IS NOT NULL
  537. BEGIN TRY
  538. EXEC sp_executesql @sqlcmd;
  539. UPDATE tblDbBuckets
  540. SET isdone = 1
  541. FROM tblDbBuckets
  542. WHERE [database_id] = @dbid AND [name] = @name AND [schema] = @schema AND used_page_count = @used_page_count AND isdone = 0 AND BucketId = @TodayBucket
  543. END TRY
  544. BEGIN CATCH
  545. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  546. SELECT @ErrorMessage = 'Error raised in TRY block. ' + ERROR_MESSAGE()
  547. RAISERROR (@ErrorMessage, 16, 1);
  548. END CATCH
  549. END
  550. END
  551. IF @VLDBMode = 1 -- Now do filegroup checks on todays bucket
  552. BEGIN
  553. WHILE (SELECT COUNT(*) FROM tblFgBuckets WHERE [database_id] = @dbid AND isdone = 0 AND BucketId = @TodayBucket) > 0
  554. BEGIN
  555. SELECT TOP 1 @fg_id = [data_space_id], @name = [name], @used_page_count = used_page_count
  556. FROM tblFgBuckets
  557. WHERE [database_id] = @dbid AND isdone = 0 AND BucketId = @TodayBucket
  558. ORDER BY used_page_count DESC
  559. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Started filegroup checks on [' + @dbname + '] - filegroup ' + @name;
  560. RAISERROR (@msg, 10, 1) WITH NOWAIT
  561. IF @HasROFG > 0 AND @CreateSnap = 1
  562. SET @sqlcmd = 'USE [' + @dbname + '_CheckDB_Snapshot];
  563. DBCC CHECKFILEGROUP (' + CONVERT(NVARCHAR(10), @fg_id) + ')'
  564. IF (@HasROFG > 0 AND @SingleUser = 1) OR (@HasROFG = 0)
  565. SET @sqlcmd = 'USE [' + @dbname + '];
  566. DBCC CHECKFILEGROUP (' + CONVERT(NVARCHAR(10), @fg_id) + ')'
  567. IF @Physical = 1
  568. BEGIN
  569. SET @sqlcmd = @sqlcmd + ' WITH PHYSICAL_ONLY;'
  570. END
  571. ELSE
  572. BEGIN
  573. SET @sqlcmd = @sqlcmd + ';'
  574. END;
  575. IF @HasROFG > 0 AND @CreateSnap = 1 AND @SnapPath IS NOT NULL
  576. BEGIN
  577. TRUNCATE TABLE #tblSnapFiles;
  578. INSERT INTO #tblSnapFiles
  579. SELECT name, 0 FROM sys.master_files WHERE database_id = @dbid AND [type] = 0;
  580. SET @filecreateid = 1
  581. SET @sqlsnapcmd = ''
  582. WHILE (SELECT COUNT([name]) FROM #tblSnapFiles WHERE isdone = 0) > 0
  583. BEGIN
  584. SELECT TOP 1 @filename = [name] FROM #tblSnapFiles WHERE isdone = 0
  585. SET @sqlsnapcmd = @sqlsnapcmd + CHAR(10) + '(NAME = [' + @filename + '], FILENAME = ''' + @SnapPath + '\' + @dbname + '_CheckDB_Snapshot_Data_' + CONVERT(VARCHAR(10), @filecreateid) + '.ss''),'
  586. SET @filecreateid = @filecreateid + 1
  587. UPDATE #tblSnapFiles
  588. SET isdone = 1 WHERE [name] = @filename;
  589. END;
  590. SELECT @sqlsnapcmd = LEFT(@sqlsnapcmd, LEN(@sqlsnapcmd)-1);
  591. SET @sqlcmd_Create = 'USE master;
  592. IF NOT EXISTS (SELECT 1 FROM sys.databases WHERE [name] = ''' + @dbname + '_CheckDB_Snapshot'')
  593. CREATE DATABASE [' + @dbname + '_CheckDB_Snapshot] ON ' + @sqlsnapcmd + CHAR(10) + 'AS SNAPSHOT OF [' + @dbname + '];'
  594. SET @sqlcmd_Drop = 'USE master;
  595. IF EXISTS (SELECT 1 FROM sys.databases WHERE [name] = ''' + @dbname + '_CheckDB_Snapshot'')
  596. DROP DATABASE [' + @dbname + '_CheckDB_Snapshot];'
  597. END;
  598. IF @HasROFG > 0 AND @CreateSnap = 1 AND @SnapPath IS NULL
  599. BEGIN
  600. SET @sqlcmd = NULL
  601. SELECT @Message = '** Skipping database ' + @dbname + ': Could not find a valid path to create DB snapshot - ' + CONVERT(VARCHAR, GETDATE())
  602. RAISERROR(@Message, 0, 42) WITH NOWAIT;
  603. END
  604. IF @HasROFG > 0 AND @SingleUser = 1
  605. BEGIN
  606. SET @sqlcmd = 'USE master;
  607. ALTER DATABASE [' + @dbname + '] SET SINGLE_USER WITH ROLLBACK IMMEDIATE;' + CHAR(10) + @sqlcmd + CHAR(10) +
  608. 'USE master;
  609. ALTER DATABASE [' + @dbname + '] SET MULTI_USER WITH ROLLBACK IMMEDIATE;'
  610. END
  611. IF @sqlcmd_Create IS NOT NULL
  612. BEGIN TRY
  613. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Creating database snapshot ' + @dbname + '_CheckDB_Snapshot';
  614. RAISERROR (@msg, 10, 1) WITH NOWAIT
  615. EXEC sp_executesql @sqlcmd_Create;
  616. END TRY
  617. BEGIN CATCH
  618. EXEC sp_executesql @sqlcmd_Drop;
  619. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  620. SELECT @ErrorMessage = 'Create Snapshot - Error raised in TRY block. ' + ERROR_MESSAGE()
  621. RAISERROR (@ErrorMessage, 16, 1);
  622. END CATCH
  623. IF @sqlcmd IS NOT NULL
  624. BEGIN TRY
  625. EXEC sp_executesql @sqlcmd;
  626. UPDATE tblFgBuckets
  627. SET isdone = 1
  628. FROM tblFgBuckets
  629. WHERE [database_id] = @dbid AND [data_space_id] = @fg_id AND used_page_count = @used_page_count AND isdone = 0 AND BucketId = @TodayBucket
  630. END TRY
  631. BEGIN CATCH
  632. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  633. SELECT @ErrorMessage = 'Check cycle - Error raised in TRY block. ' + ERROR_MESSAGE()
  634. RAISERROR (@ErrorMessage, 16, 1);
  635. RETURN
  636. END CATCH
  637. IF @sqlcmd_Drop IS NOT NULL
  638. BEGIN TRY
  639. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Droping database snapshot ' + @dbname + '_CheckDB_Snapshot';
  640. RAISERROR (@msg, 10, 1) WITH NOWAIT
  641. EXEC sp_executesql @sqlcmd_Drop;
  642. END TRY
  643. BEGIN CATCH
  644. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  645. SELECT @ErrorMessage = 'Drop Snapshot - Error raised in TRY block. ' + ERROR_MESSAGE()
  646. RAISERROR (@ErrorMessage, 16, 1);
  647. END CATCH
  648. END
  649. END
  650. END;
  651. UPDATE #tmpdbs
  652. SET isdone = 1
  653. FROM #tmpdbs
  654. WHERE [dbid] = @dbid AND isdone = 0
  655. END;
  656. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpdbs'))
  657. DROP TABLE #tmpdbs
  658. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblObj'))
  659. DROP TABLE #tblObj;
  660. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblBuckets'))
  661. DROP TABLE #tblBuckets;
  662. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblFGs'))
  663. DROP TABLE #tblFGs;
  664. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblSnapFiles'))
  665. DROP TABLE #tblSnapFiles;
  666. SELECT @Message = '** Finished: ' + CONVERT(VARCHAR, GETDATE())
  667. RAISERROR(@Message, 0, 42) WITH NOWAIT;
  668. GO
  669. PRINT 'Procedure usp_CheckIntegrity created';
  670. GO
  671. ------------------------------------------------------------------------------------------------------------------------------
  672. IF EXISTS (SELECT job_id FROM msdb.dbo.sysjobs_view WHERE name = N'Weekly Maintenance')
  673. EXEC msdb.dbo.sp_delete_job @job_name=N'Weekly Maintenance', @delete_unused_schedule=1
  674. GO
  675. PRINT 'Creating Weekly Maintenance job';
  676. GO
  677. BEGIN TRANSACTION
  678. -- Set the Operator name to receive notifications, if any. Set the job owner, if not sa.
  679. DECLARE @customoper sysname, @jobowner sysname
  680. SET @customoper = 'SQLAdmins'
  681. SET @jobowner = 'sa'
  682. DECLARE @ReturnCode INT
  683. SELECT @ReturnCode = 0
  684. IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'Database Maintenance' AND category_class=1)
  685. BEGIN
  686. EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'Database Maintenance'
  687. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  688. END
  689. DECLARE @jobId BINARY(16)
  690. IF EXISTS (SELECT name FROM msdb.dbo.sysoperators WHERE name = @customoper)
  691. BEGIN
  692. EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'Weekly Maintenance',
  693. @enabled=1,
  694. @notify_level_eventlog=2,
  695. @notify_level_email=3,
  696. @notify_level_netsend=2,
  697. @notify_level_page=2,
  698. @delete_level=0,
  699. @description=N'Runs weekly maintenance cycle. Most steps execute on Sundays only. For integrity checks, depending on whether the database in scope is a VLDB or not, different actions are executed. See job steps for further detail.',
  700. @category_name=N'Database Maintenance',
  701. @owner_login_name=@jobowner,
  702. @notify_email_operator_name=@customoper,
  703. @job_id = @jobId OUTPUT
  704. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  705. END
  706. ELSE
  707. BEGIN
  708. EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'Daily Index Defrag',
  709. @enabled=1,
  710. @notify_level_eventlog=2,
  711. @notify_level_email=3,
  712. @notify_level_netsend=0,
  713. @notify_level_page=0,
  714. @delete_level=0,
  715. @description=N'Inteligent defrag on one or more indexes for one or more databases.',
  716. @category_name=N'Database Maintenance',
  717. @owner_login_name=@jobowner,
  718. @job_id = @jobId OUTPUT
  719. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  720. END
  721. EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'DBCC CheckDB',
  722. @step_id=1,
  723. @cmdexec_success_code=0,
  724. @on_success_action=3,
  725. @on_success_step_id=0,
  726. @on_fail_action=2,
  727. @on_fail_step_id=0,
  728. @retry_attempts=0,
  729. @retry_interval=0,
  730. @os_run_priority=0, @subsystem=N'TSQL',
  731. @command=N'/*
  732. This checks the logical and physical integrity of all the objects in the specified database by performing the following operations:
  733. |-For VLDBs (larger than 1TB):
  734. |- On Sundays, if VLDB Mode = 0, runs DBCC CHECKALLOC.
  735. |- On Sundays, runs DBCC CHECKCATALOG.
  736. |- Everyday, if VLDB Mode = 0, runs DBCC CHECKTABLE or if VLDB Mode = 1, DBCC CHECKFILEGROUP on a subset of tables and views, divided by daily buckets.
  737. |-For DBs smaller than 1TB:
  738. |- Every Sunday a DBCC CHECKDB checks the logical and physical integrity of all the objects in the specified database.
  739. To set how VLDBs are handled, set @VLDBMode to 0 = Bucket by Table Size or 1 = Bucket by Filegroup Size
  740. IMPORTANT: Consider running DBCC CHECKDB routinely (at least, weekly). On large databases and for more frequent checks, consider using the PHYSICAL_ONLY parameter.
  741. http://msdn.microsoft.com/en-us/library/ms176064.aspx
  742. http://blogs.msdn.com/b/sqlserverstorageengine/archive/2006/10/20/consistency-checking-options-for-a-vldb.aspx
  743. If a database has Read-Only filegroups, any integrity check will fail if there are other open connections to the database.
  744. Setting @CreateSnap = 1 will create a database snapshot before running the check on the snapshot, and drop it at the end (default).
  745. Setting @CreateSnap = 0 means the integrity check might fail if there are other open connection on the database.
  746. If snapshots are not allowed and a database has Read-Only filegroups, any integrity check will fail if there are other openned connections to the database.
  747. Setting @SingleUser = 1 will set the database in single user mode before running the check, and to multi user afterwards.
  748. Setting @SingleUser = 0 means the integrity check might fail if there are other open connection on the database.
  749. */
  750. EXEC msdb.dbo.usp_CheckIntegrity @VLDBMode = 1, @SingleUser = 0, @CreateSnap = 1
  751. ',
  752. @database_name=N'master',
  753. @flags=20
  754. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  755. EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'update usage',
  756. @step_id=2,
  757. @cmdexec_success_code=0,
  758. @on_success_action=3,
  759. @on_success_step_id=0,
  760. @on_fail_action=2,
  761. @on_fail_step_id=0,
  762. @retry_attempts=0,
  763. @retry_interval=0,
  764. @os_run_priority=0, @subsystem=N'TSQL',
  765. @command=N'/*
  766. DBCC UPDATEUSAGE corrects the rows, used pages, reserved pages, leaf pages and data page counts for each partition in a table or index.
  767. IMPORTANT: Consider running DBCC UPDATEUSAGE routinely (for example, weekly) only if the database undergoes frequent Data Definition Language (DDL) modifications, such as CREATE, ALTER, or DROP statements.
  768. http://msdn.microsoft.com/en-us/library/ms188414.aspx
  769. Exludes all Offline or Read-Only DBs. Also excludes all databases over 4GB in size.
  770. */
  771. SET NOCOUNT ON;
  772. -- Is it Sunday yet?
  773. IF (SELECT 1 & POWER(2, DATEPART(weekday, GETDATE())-1)) > 0
  774. BEGIN
  775. PRINT ''** Start: '' + CONVERT(VARCHAR, GETDATE())
  776. DECLARE @dbname sysname, @sqlcmd NVARCHAR(500)
  777. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.#tmpdbs''))
  778. CREATE TABLE #tmpdbs (id int IDENTITY(1,1), [dbname] sysname, isdone bit)
  779. INSERT INTO #tmpdbs ([dbname], isdone)
  780. SELECT QUOTENAME(d.name), 0 FROM sys.databases d INNER JOIN sys.master_files smf ON d.database_id = smf.database_id
  781. WHERE d.is_read_only = 0 AND d.state = 0 AND d.database_id <> 2 AND smf.type = 0 AND (smf.size * 8)/1024 < 4096;
  782. WHILE (SELECT COUNT([dbname]) FROM #tmpdbs WHERE isdone = 0) > 0
  783. BEGIN
  784. SET @dbname = (SELECT TOP 1 [dbname] FROM #tmpdbs WHERE isdone = 0)
  785. SET @sqlcmd = ''DBCC UPDATEUSAGE ('' + @dbname + '')''
  786. PRINT CHAR(10) + CONVERT(VARCHAR, GETDATE()) + '' - Started space corrections on '' + @dbname
  787. EXECUTE sp_executesql @sqlcmd
  788. PRINT CONVERT(VARCHAR, GETDATE()) + '' - Ended space corrections on '' + @dbname
  789. UPDATE #tmpdbs
  790. SET isdone = 1
  791. FROM #tmpdbs
  792. WHERE [dbname] = @dbname AND isdone = 0
  793. END;
  794. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.#tmpdbs''))
  795. DROP TABLE #tmpdbs;
  796. PRINT ''** Finished: '' + CONVERT(VARCHAR, GETDATE())
  797. END
  798. ELSE
  799. BEGIN
  800. PRINT ''** Skipping: Today is not Sunday - '' + CONVERT(VARCHAR, GETDATE())
  801. END;',
  802. @database_name=N'master',
  803. @flags=20
  804. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  805. EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'sp_createstats',
  806. @step_id=3,
  807. @cmdexec_success_code=0,
  808. @on_success_action=3,
  809. @on_success_step_id=0,
  810. @on_fail_action=2,
  811. @on_fail_step_id=0,
  812. @retry_attempts=0,
  813. @retry_interval=0,
  814. @os_run_priority=0, @subsystem=N'TSQL',
  815. @command=N'/*
  816. Creates statistics only on columns that are part of an existing index, and are not the first column in any index definition.
  817. Creating single-column statistics increases the number of histograms, which can improve cardinality estimates, query plans, and query performance.
  818. The first column of a statistics object has a histogram; other columns do not have a histogram.
  819. http://msdn.microsoft.com/en-us/library/ms186834.aspx
  820. Exludes all Offline and Read-Only DBs
  821. */
  822. SET NOCOUNT ON;
  823. -- Is it Sunday yet?
  824. IF (SELECT 1 & POWER(2, DATEPART(weekday, GETDATE())-1)) > 0
  825. BEGIN
  826. PRINT ''** Start: '' + CONVERT(VARCHAR, GETDATE())
  827. DECLARE @dbname sysname, @sqlcmd NVARCHAR(500)
  828. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.#tmpdbs''))
  829. CREATE TABLE #tmpdbs (id int IDENTITY(1,1), [dbname] sysname, isdone bit)
  830. INSERT INTO #tmpdbs ([dbname], isdone)
  831. SELECT QUOTENAME(name), 0 FROM sys.databases WHERE is_read_only = 0 AND state = 0 AND database_id > 4 AND is_distributor = 0;
  832. WHILE (SELECT COUNT([dbname]) FROM #tmpdbs WHERE isdone = 0) > 0
  833. BEGIN
  834. SET @dbname = (SELECT TOP 1 [dbname] FROM #tmpdbs WHERE isdone = 0)
  835. SET @sqlcmd = @dbname + ''.dbo.sp_createstats @indexonly = ''''indexonly''''''
  836. SELECT CHAR(10) + CONVERT(VARCHAR, GETDATE()) + '' - Started indexed stats creation on '' + @dbname
  837. EXECUTE sp_executesql @sqlcmd
  838. SELECT CONVERT(VARCHAR, GETDATE()) + '' - Ended indexed stats creation on '' + @dbname
  839. UPDATE #tmpdbs
  840. SET isdone = 1
  841. FROM #tmpdbs
  842. WHERE [dbname] = @dbname AND isdone = 0
  843. END;
  844. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.#tmpdbs''))
  845. DROP TABLE #tmpdbs;
  846. PRINT ''** Finished: '' + CONVERT(VARCHAR, GETDATE())
  847. END
  848. ELSE
  849. BEGIN
  850. PRINT ''** Skipping: Today is not Sunday - '' + CONVERT(VARCHAR, GETDATE())
  851. END;',
  852. @database_name=N'master',
  853. @flags=20
  854. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  855. EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Cleanup Job History',
  856. @step_id=4,
  857. @cmdexec_success_code=0,
  858. @on_success_action=3,
  859. @on_success_step_id=0,
  860. @on_fail_action=2,
  861. @on_fail_step_id=0,
  862. @retry_attempts=0,
  863. @retry_interval=0,
  864. @os_run_priority=0, @subsystem=N'TSQL',
  865. @command=N'-- Cleans msdb job history older than 30 days
  866. SET NOCOUNT ON;
  867. -- Is it Sunday yet?
  868. IF (SELECT 1 & POWER(2, DATEPART(weekday, GETDATE())-1)) > 0
  869. BEGIN
  870. DECLARE @date DATETIME
  871. SET @date = GETDATE()-30
  872. EXEC msdb.dbo.sp_purge_jobhistory @oldest_date=@date;
  873. END
  874. ELSE
  875. BEGIN
  876. PRINT ''** Skipping: Today is not Sunday - '' + CONVERT(VARCHAR, GETDATE())
  877. END;',
  878. @database_name=N'msdb',
  879. @flags=20
  880. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  881. EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Cleanup Maintenance Plan txt reports',
  882. @step_id=5,
  883. @cmdexec_success_code=0,
  884. @on_success_action=1,
  885. @on_success_step_id=0,
  886. @on_fail_action=2,
  887. @on_fail_step_id=0,
  888. @retry_attempts=0,
  889. @retry_interval=0,
  890. @os_run_priority=0, @subsystem=N'TSQL',
  891. @command=N'-- Cleans maintenance plans txt reports older than 30 days
  892. SET NOCOUNT ON;
  893. -- Is it Sunday yet?
  894. IF (SELECT 1 & POWER(2, DATEPART(weekday, GETDATE())-1)) > 0
  895. BEGIN
  896. DECLARE @path NVARCHAR(500), @date DATETIME
  897. DECLARE @sqlcmd NVARCHAR(1000), @params NVARCHAR(100), @sqlmajorver int
  898. SELECT @sqlmajorver = CONVERT(int, (@@microsoftversion / 0x1000000) & 0xff);
  899. SET @date = GETDATE()-30
  900. IF @sqlmajorver < 11
  901. BEGIN
  902. EXEC master..xp_instance_regread N''HKEY_LOCAL_MACHINE'',N''Software\Microsoft\MSSQLServer\Setup'',N''SQLPath'', @path OUTPUT
  903. SET @path = @path + ''\LOG''
  904. END
  905. ELSE
  906. BEGIN
  907. SET @sqlcmd = N''SELECT @pathOUT = LEFT([path], LEN([path])-1) FROM sys.dm_os_server_diagnostics_log_configurations'';
  908. SET @params = N''@pathOUT NVARCHAR(2048) OUTPUT'';
  909. EXECUTE sp_executesql @sqlcmd, @params, @pathOUT=@path OUTPUT;
  910. END
  911. -- Default location for maintenance plan txt files is the Log folder.
  912. -- If you changed from the default location since you last installed SQL Server, uncomment below and set the custom desired path.
  913. --SET @path = ''C:\custom_location''
  914. EXECUTE master..xp_delete_file 1,@path,N''txt'',@date,1
  915. END
  916. ELSE
  917. BEGIN
  918. PRINT ''** Skipping: Today is not Sunday - '' + CONVERT(VARCHAR, GETDATE())
  919. END;',
  920. @database_name=N'master',
  921. @flags=20
  922. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  923. EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
  924. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  925. EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'Weekly Maintenance - Sundays',
  926. @enabled=1,
  927. @freq_type=8,
  928. @freq_interval=1,
  929. @freq_subday_type=1,
  930. @freq_subday_interval=0,
  931. @freq_relative_interval=0,
  932. @freq_recurrence_factor=1,
  933. @active_start_date=20071009,
  934. @active_end_date=99991231,
  935. @active_start_time=83000,
  936. @active_end_time=235959
  937. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  938. EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'Weekly Maintenance - Weekdays and Saturdays',
  939. @enabled=1,
  940. @freq_type=8,
  941. @freq_interval=126,
  942. @freq_subday_type=1,
  943. @freq_subday_interval=0,
  944. @freq_relative_interval=0,
  945. @freq_recurrence_factor=1,
  946. @active_start_date=20131017,
  947. @active_end_date=99991231,
  948. @active_start_time=10000,
  949. @active_end_time=235959
  950. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  951. EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
  952. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  953. COMMIT TRANSACTION
  954. GOTO EndSave
  955. QuitWithRollback:
  956. IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
  957. EndSave:
  958. GO
  959. PRINT 'Weekly Maintenance job created';
  960. GO