5_job_Maintenance.sql 48 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815816817818819820821822823824825826827828829830831832833834835836837838839840841842843844845846847848849850851852853854855856857858859860861862863864865866867868869870871872873874875876877878879880881882883884885886887888889890891892893894895896897898899900901902903904905906907908909910911912913914915916917918919920921922923924925926927928929930931932933934935936937938939940941942943944945946947948949950951952953954955956957958959960961962963964965966967968969970971972973974975976977978979980981982983984985986987988989990991992993994995996997998999100010011002100310041005100610071008100910101011101210131014101510161017101810191020102110221023102410251026102710281029103010311032103310341035103610371038103910401041104210431044104510461047104810491050105110521053105410551056105710581059106010611062106310641065106610671068106910701071107210731074107510761077107810791080108110821083108410851086108710881089109010911092109310941095109610971098109911001101110211031104110511061107110811091110111111121113111411151116111711181119112011211122112311241125112611271128112911301131113211331134113511361137113811391140114111421143114411451146114711481149115011511152115311541155
  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((cast(size as bigint) * 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
  519. -- Confirm the table still exists
  520. AND OBJECT_ID(N'[' + DB_NAME(database_id) + '].[' + [schema] + '].[' + [name] + ']') IS NOT NULL) > 0
  521. BEGIN
  522. SELECT TOP 1 @name = [name], @schema = [schema], @used_page_count = used_page_count
  523. FROM tblDbBuckets
  524. WHERE [database_id] = @dbid AND isdone = 0 AND BucketId = @TodayBucket
  525. ORDER BY used_page_count DESC
  526. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Started table checks on ' + @dbname + ' - table ' + @schema + '.' + @name;
  527. RAISERROR (@msg, 10, 1) WITH NOWAIT
  528. SET @sqlcmd = 'USE [' + @dbname + '];
  529. DBCC CHECKTABLE (''' + @schema + '.' + @name + ''') WITH '
  530. IF @Physical = 1
  531. BEGIN
  532. SET @sqlcmd = @sqlcmd + 'PHYSICAL_ONLY;'
  533. END
  534. ELSE
  535. BEGIN
  536. SET @sqlcmd = @sqlcmd + 'DATA_PURITY;'
  537. END;
  538. IF @sqlcmd IS NOT NULL
  539. BEGIN TRY
  540. EXEC sp_executesql @sqlcmd;
  541. UPDATE tblDbBuckets
  542. SET isdone = 1
  543. FROM tblDbBuckets
  544. WHERE [database_id] = @dbid AND [name] = @name AND [schema] = @schema AND used_page_count = @used_page_count AND isdone = 0 AND BucketId = @TodayBucket
  545. END TRY
  546. BEGIN CATCH
  547. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  548. SELECT @ErrorMessage = 'Error raised in TRY block. ' + ERROR_MESSAGE()
  549. RAISERROR (@ErrorMessage, 16, 1);
  550. END CATCH
  551. END
  552. END
  553. IF @VLDBMode = 1 -- Now do filegroup checks on todays bucket
  554. BEGIN
  555. WHILE (SELECT COUNT(*) FROM tblFgBuckets WHERE [database_id] = @dbid AND isdone = 0 AND BucketId = @TodayBucket) > 0
  556. BEGIN
  557. SELECT TOP 1 @fg_id = [data_space_id], @name = [name], @used_page_count = used_page_count
  558. FROM tblFgBuckets
  559. WHERE [database_id] = @dbid AND isdone = 0 AND BucketId = @TodayBucket
  560. ORDER BY used_page_count DESC
  561. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Started filegroup checks on [' + @dbname + '] - filegroup ' + @name;
  562. RAISERROR (@msg, 10, 1) WITH NOWAIT
  563. IF @HasROFG > 0 AND @CreateSnap = 1
  564. SET @sqlcmd = 'USE [' + @dbname + '_CheckDB_Snapshot];
  565. DBCC CHECKFILEGROUP (' + CONVERT(NVARCHAR(10), @fg_id) + ')'
  566. IF (@HasROFG > 0 AND @SingleUser = 1) OR (@HasROFG = 0)
  567. SET @sqlcmd = 'USE [' + @dbname + '];
  568. DBCC CHECKFILEGROUP (' + CONVERT(NVARCHAR(10), @fg_id) + ')'
  569. IF @Physical = 1
  570. BEGIN
  571. SET @sqlcmd = @sqlcmd + ' WITH PHYSICAL_ONLY;'
  572. END
  573. ELSE
  574. BEGIN
  575. SET @sqlcmd = @sqlcmd + ';'
  576. END;
  577. IF @HasROFG > 0 AND @CreateSnap = 1 AND @SnapPath IS NOT NULL
  578. BEGIN
  579. TRUNCATE TABLE #tblSnapFiles;
  580. INSERT INTO #tblSnapFiles
  581. SELECT name, 0 FROM sys.master_files WHERE database_id = @dbid AND [type] = 0;
  582. SET @filecreateid = 1
  583. SET @sqlsnapcmd = ''
  584. WHILE (SELECT COUNT([name]) FROM #tblSnapFiles WHERE isdone = 0) > 0
  585. BEGIN
  586. SELECT TOP 1 @filename = [name] FROM #tblSnapFiles WHERE isdone = 0
  587. SET @sqlsnapcmd = @sqlsnapcmd + CHAR(10) + '(NAME = [' + @filename + '], FILENAME = ''' + @SnapPath + '\' + @dbname + '_CheckDB_Snapshot_Data_' + CONVERT(VARCHAR(10), @filecreateid) + '.ss''),'
  588. SET @filecreateid = @filecreateid + 1
  589. UPDATE #tblSnapFiles
  590. SET isdone = 1 WHERE [name] = @filename;
  591. END;
  592. SELECT @sqlsnapcmd = LEFT(@sqlsnapcmd, LEN(@sqlsnapcmd)-1);
  593. SET @sqlcmd_Create = 'USE master;
  594. IF NOT EXISTS (SELECT 1 FROM sys.databases WHERE [name] = ''' + @dbname + '_CheckDB_Snapshot'')
  595. CREATE DATABASE [' + @dbname + '_CheckDB_Snapshot] ON ' + @sqlsnapcmd + CHAR(10) + 'AS SNAPSHOT OF [' + @dbname + '];'
  596. SET @sqlcmd_Drop = 'USE master;
  597. IF EXISTS (SELECT 1 FROM sys.databases WHERE [name] = ''' + @dbname + '_CheckDB_Snapshot'')
  598. DROP DATABASE [' + @dbname + '_CheckDB_Snapshot];'
  599. END;
  600. IF @HasROFG > 0 AND @CreateSnap = 1 AND @SnapPath IS NULL
  601. BEGIN
  602. SET @sqlcmd = NULL
  603. SELECT @Message = '** Skipping database ' + @dbname + ': Could not find a valid path to create DB snapshot - ' + CONVERT(VARCHAR, GETDATE())
  604. RAISERROR(@Message, 0, 42) WITH NOWAIT;
  605. END
  606. IF @HasROFG > 0 AND @SingleUser = 1
  607. BEGIN
  608. SET @sqlcmd = 'USE master;
  609. ALTER DATABASE [' + @dbname + '] SET SINGLE_USER WITH ROLLBACK IMMEDIATE;' + CHAR(10) + @sqlcmd + CHAR(10) +
  610. 'USE master;
  611. ALTER DATABASE [' + @dbname + '] SET MULTI_USER WITH ROLLBACK IMMEDIATE;'
  612. END
  613. IF @sqlcmd_Create IS NOT NULL
  614. BEGIN TRY
  615. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Creating database snapshot ' + @dbname + '_CheckDB_Snapshot';
  616. RAISERROR (@msg, 10, 1) WITH NOWAIT
  617. EXEC sp_executesql @sqlcmd_Create;
  618. END TRY
  619. BEGIN CATCH
  620. EXEC sp_executesql @sqlcmd_Drop;
  621. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  622. SELECT @ErrorMessage = 'Create Snapshot - Error raised in TRY block. ' + ERROR_MESSAGE()
  623. RAISERROR (@ErrorMessage, 16, 1);
  624. END CATCH
  625. IF @sqlcmd IS NOT NULL
  626. BEGIN TRY
  627. EXEC sp_executesql @sqlcmd;
  628. UPDATE tblFgBuckets
  629. SET isdone = 1
  630. FROM tblFgBuckets
  631. WHERE [database_id] = @dbid AND [data_space_id] = @fg_id AND used_page_count = @used_page_count AND isdone = 0 AND BucketId = @TodayBucket
  632. END TRY
  633. BEGIN CATCH
  634. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  635. SELECT @ErrorMessage = 'Check cycle - Error raised in TRY block. ' + ERROR_MESSAGE()
  636. RAISERROR (@ErrorMessage, 16, 1);
  637. RETURN
  638. END CATCH
  639. IF @sqlcmd_Drop IS NOT NULL
  640. BEGIN TRY
  641. SELECT @msg = CONVERT(VARCHAR, GETDATE(), 9) + ' - Droping database snapshot ' + @dbname + '_CheckDB_Snapshot';
  642. RAISERROR (@msg, 10, 1) WITH NOWAIT
  643. EXEC sp_executesql @sqlcmd_Drop;
  644. END TRY
  645. BEGIN CATCH
  646. SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage;
  647. SELECT @ErrorMessage = 'Drop Snapshot - Error raised in TRY block. ' + ERROR_MESSAGE()
  648. RAISERROR (@ErrorMessage, 16, 1);
  649. END CATCH
  650. END
  651. END
  652. END;
  653. UPDATE #tmpdbs
  654. SET isdone = 1
  655. FROM #tmpdbs
  656. WHERE [dbid] = @dbid AND isdone = 0
  657. END;
  658. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpdbs'))
  659. DROP TABLE #tmpdbs
  660. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblObj'))
  661. DROP TABLE #tblObj;
  662. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblBuckets'))
  663. DROP TABLE #tblBuckets;
  664. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblFGs'))
  665. DROP TABLE #tblFGs;
  666. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblSnapFiles'))
  667. DROP TABLE #tblSnapFiles;
  668. SELECT @Message = '** Finished: ' + CONVERT(VARCHAR, GETDATE())
  669. RAISERROR(@Message, 0, 42) WITH NOWAIT;
  670. GO
  671. PRINT 'Procedure usp_CheckIntegrity created';
  672. GO
  673. ------------------------------------------------------------------------------------------------------------------------------
  674. IF EXISTS (SELECT job_id FROM msdb.dbo.sysjobs_view WHERE name = N'Weekly Maintenance')
  675. EXEC msdb.dbo.sp_delete_job @job_name=N'Weekly Maintenance', @delete_unused_schedule=1
  676. GO
  677. PRINT 'Creating Weekly Maintenance job';
  678. GO
  679. BEGIN TRANSACTION
  680. -- Set the Operator name to receive notifications, if any. Set the job owner, if not sa.
  681. DECLARE @customoper sysname, @jobowner sysname
  682. SET @customoper = 'SQLAdmins'
  683. SET @jobowner = 'sa'
  684. DECLARE @ReturnCode INT
  685. SELECT @ReturnCode = 0
  686. IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'Database Maintenance' AND category_class=1)
  687. BEGIN
  688. EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'Database Maintenance'
  689. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  690. END
  691. DECLARE @jobId BINARY(16)
  692. IF EXISTS (SELECT name FROM msdb.dbo.sysoperators WHERE name = @customoper)
  693. BEGIN
  694. EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'Weekly Maintenance',
  695. @enabled=1,
  696. @notify_level_eventlog=2,
  697. @notify_level_email=3,
  698. @notify_level_netsend=2,
  699. @notify_level_page=2,
  700. @delete_level=0,
  701. @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.',
  702. @category_name=N'Database Maintenance',
  703. @owner_login_name=@jobowner,
  704. @notify_email_operator_name=@customoper,
  705. @job_id = @jobId OUTPUT
  706. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  707. END
  708. ELSE
  709. BEGIN
  710. EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'Weekly Maintenance',
  711. @enabled=1,
  712. @notify_level_eventlog=2,
  713. @notify_level_email=3,
  714. @notify_level_netsend=0,
  715. @notify_level_page=0,
  716. @delete_level=0,
  717. @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.',
  718. @category_name=N'Database Maintenance',
  719. @owner_login_name=@jobowner,
  720. @job_id = @jobId OUTPUT
  721. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  722. END
  723. EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'DBCC CheckDB',
  724. @step_id=1,
  725. @cmdexec_success_code=0,
  726. @on_success_action=3,
  727. @on_success_step_id=0,
  728. @on_fail_action=2,
  729. @on_fail_step_id=0,
  730. @retry_attempts=0,
  731. @retry_interval=0,
  732. @os_run_priority=0, @subsystem=N'TSQL',
  733. @command=N'/*
  734. This checks the logical and physical integrity of all the objects in the specified database by performing the following operations:
  735. |-For VLDBs (larger than 1TB):
  736. |- On Sundays, if VLDB Mode = 0, runs DBCC CHECKALLOC.
  737. |- On Sundays, runs DBCC CHECKCATALOG.
  738. |- 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.
  739. |-For DBs smaller than 1TB:
  740. |- Every Sunday a DBCC CHECKDB checks the logical and physical integrity of all the objects in the specified database.
  741. To set how VLDBs are handled, set @VLDBMode to 0 = Bucket by Table Size or 1 = Bucket by Filegroup Size
  742. IMPORTANT: Consider running DBCC CHECKDB routinely (at least, weekly). On large databases and for more frequent checks, consider using the PHYSICAL_ONLY parameter.
  743. http://msdn.microsoft.com/en-us/library/ms176064.aspx
  744. http://blogs.msdn.com/b/sqlserverstorageengine/archive/2006/10/20/consistency-checking-options-for-a-vldb.aspx
  745. If a database has Read-Only filegroups, any integrity check will fail if there are other open connections to the database.
  746. Setting @CreateSnap = 1 will create a database snapshot before running the check on the snapshot, and drop it at the end (default).
  747. Setting @CreateSnap = 0 means the integrity check might fail if there are other open connection on the database.
  748. 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.
  749. Setting @SingleUser = 1 will set the database in single user mode before running the check, and to multi user afterwards.
  750. Setting @SingleUser = 0 means the integrity check might fail if there are other open connection on the database.
  751. */
  752. EXEC msdb.dbo.usp_CheckIntegrity @VLDBMode = 1, @SingleUser = 0, @CreateSnap = 1
  753. ',
  754. @database_name=N'master',
  755. @flags=20
  756. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  757. EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'update usage',
  758. @step_id=2,
  759. @cmdexec_success_code=0,
  760. @on_success_action=3,
  761. @on_success_step_id=0,
  762. @on_fail_action=2,
  763. @on_fail_step_id=0,
  764. @retry_attempts=0,
  765. @retry_interval=0,
  766. @os_run_priority=0, @subsystem=N'TSQL',
  767. @command=N'/*
  768. DBCC UPDATEUSAGE corrects the rows, used pages, reserved pages, leaf pages and data page counts for each partition in a table or index.
  769. 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.
  770. http://msdn.microsoft.com/en-us/library/ms188414.aspx
  771. Exludes all Offline or Read-Only DBs. Also excludes all databases over 4GB in size.
  772. */
  773. SET NOCOUNT ON;
  774. -- Is it Sunday yet?
  775. IF (SELECT 1 & POWER(2, DATEPART(weekday, GETDATE())-1)) > 0
  776. BEGIN
  777. PRINT ''** Start: '' + CONVERT(VARCHAR, GETDATE())
  778. DECLARE @dbname sysname, @sqlcmd NVARCHAR(500)
  779. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.#tmpdbs''))
  780. CREATE TABLE #tmpdbs (id int IDENTITY(1,1), [dbname] sysname, isdone bit)
  781. INSERT INTO #tmpdbs ([dbname], isdone)
  782. (SELECT DISTINCT QUOTENAME(d.name), 0 FROM sys.databases d
  783. INNER JOIN sys.master_files smf ON d.database_id = smf.database_id
  784. JOIN sys.dm_hadr_database_replica_states hadrdrs ON d.database_id = hadrdrs.database_id
  785. 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 AND hadrdrs.is_primary_replica = 1)
  786. UNION
  787. (SELECT DISTINCT QUOTENAME(d.name), 0 FROM sys.databases d
  788. INNER JOIN sys.master_files smf ON d.database_id = smf.database_id
  789. LEFT JOIN sys.dm_hadr_database_replica_states hadrdrs ON d.database_id = hadrdrs.database_id
  790. 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 AND hadrdrs.database_id IS NULL);
  791. WHILE (SELECT COUNT([dbname]) FROM #tmpdbs WHERE isdone = 0) > 0
  792. BEGIN
  793. SET @dbname = (SELECT TOP 1 [dbname] FROM #tmpdbs WHERE isdone = 0)
  794. SET @sqlcmd = ''DBCC UPDATEUSAGE ('' + @dbname + '')''
  795. PRINT CHAR(10) + CONVERT(VARCHAR, GETDATE()) + '' - Started space corrections on '' + @dbname
  796. EXECUTE sp_executesql @sqlcmd
  797. PRINT CONVERT(VARCHAR, GETDATE()) + '' - Ended space corrections on '' + @dbname
  798. UPDATE #tmpdbs
  799. SET isdone = 1
  800. FROM #tmpdbs
  801. WHERE [dbname] = @dbname AND isdone = 0
  802. END;
  803. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.#tmpdbs''))
  804. DROP TABLE #tmpdbs;
  805. PRINT ''** Finished: '' + CONVERT(VARCHAR, GETDATE())
  806. END
  807. ELSE
  808. BEGIN
  809. PRINT ''** Skipping: Today is not Sunday - '' + CONVERT(VARCHAR, GETDATE())
  810. END;',
  811. @database_name=N'master',
  812. @flags=20
  813. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  814. EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'sp_createstats',
  815. @step_id=3,
  816. @cmdexec_success_code=0,
  817. @on_success_action=3,
  818. @on_success_step_id=0,
  819. @on_fail_action=2,
  820. @on_fail_step_id=0,
  821. @retry_attempts=0,
  822. @retry_interval=0,
  823. @os_run_priority=0, @subsystem=N'TSQL',
  824. @command=N'/*
  825. Creates statistics only on columns that are part of an existing index, and are not the first column in any index definition.
  826. Creating single-column statistics increases the number of histograms, which can improve cardinality estimates, query plans, and query performance.
  827. The first column of a statistics object has a histogram; other columns do not have a histogram.
  828. http://msdn.microsoft.com/en-us/library/ms186834.aspx
  829. Exludes all Offline and Read-Only DBs
  830. */
  831. SET NOCOUNT ON;
  832. -- Is it Sunday yet?
  833. IF (SELECT 1 & POWER(2, DATEPART(weekday, GETDATE())-1)) > 0
  834. BEGIN
  835. PRINT ''** Start: '' + CONVERT(VARCHAR, GETDATE())
  836. DECLARE @dbname sysname, @sqlcmd NVARCHAR(500)
  837. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.#tmpdbs''))
  838. CREATE TABLE #tmpdbs (id int IDENTITY(1,1), [dbname] sysname, isdone bit)
  839. INSERT INTO #tmpdbs ([dbname], isdone)
  840. (SELECT QUOTENAME(name), 0 FROM sys.databases JOIN sys.dm_hadr_database_replica_states hadrdrs ON d.database_id = hadrdrs.database_id WHERE is_read_only = 0 AND state = 0 AND database_id > 4 AND is_distributor = 0 AND hadrdrs.is_primary_replica = 1)
  841. UNION
  842. (SELECT QUOTENAME(name), 0 FROM sys.databases LEFT JOIN sys.dm_hadr_database_replica_states hadrdrs ON d.database_id = hadrdrs.database_id WHERE is_read_only = 0 AND state = 0 AND database_id > 4 AND is_distributor = 0 AND hadrdrs.database_id IS NULL);
  843. WHILE (SELECT COUNT([dbname]) FROM #tmpdbs WHERE isdone = 0) > 0
  844. BEGIN
  845. SET @dbname = (SELECT TOP 1 [dbname] FROM #tmpdbs WHERE isdone = 0)
  846. SET @sqlcmd = @dbname + ''.dbo.sp_createstats @indexonly = ''''indexonly''''''
  847. SELECT CHAR(10) + CONVERT(VARCHAR, GETDATE()) + '' - Started indexed stats creation on '' + @dbname
  848. EXECUTE sp_executesql @sqlcmd
  849. SELECT CONVERT(VARCHAR, GETDATE()) + '' - Ended indexed stats creation on '' + @dbname
  850. UPDATE #tmpdbs
  851. SET isdone = 1
  852. FROM #tmpdbs
  853. WHERE [dbname] = @dbname AND isdone = 0
  854. END;
  855. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.#tmpdbs''))
  856. DROP TABLE #tmpdbs;
  857. PRINT ''** Finished: '' + CONVERT(VARCHAR, GETDATE())
  858. END
  859. ELSE
  860. BEGIN
  861. PRINT ''** Skipping: Today is not Sunday - '' + CONVERT(VARCHAR, GETDATE())
  862. END;',
  863. @database_name=N'master',
  864. @flags=20
  865. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  866. EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Cleanup Job History',
  867. @step_id=4,
  868. @cmdexec_success_code=0,
  869. @on_success_action=3,
  870. @on_success_step_id=0,
  871. @on_fail_action=2,
  872. @on_fail_step_id=0,
  873. @retry_attempts=0,
  874. @retry_interval=0,
  875. @os_run_priority=0, @subsystem=N'TSQL',
  876. @command=N'-- Cleans msdb job history older than 30 days
  877. SET NOCOUNT ON;
  878. -- Is it Sunday yet?
  879. IF (SELECT 1 & POWER(2, DATEPART(weekday, GETDATE())-1)) > 0
  880. BEGIN
  881. DECLARE @date DATETIME
  882. SET @date = GETDATE()-30
  883. EXEC msdb.dbo.sp_purge_jobhistory @oldest_date=@date;
  884. END
  885. ELSE
  886. BEGIN
  887. PRINT ''** Skipping: Today is not Sunday - '' + CONVERT(VARCHAR, GETDATE())
  888. END;',
  889. @database_name=N'msdb',
  890. @flags=20
  891. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  892. EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Cleanup Maintenance Plan txt reports',
  893. @step_id=5,
  894. @cmdexec_success_code=0,
  895. @on_success_action=1,
  896. @on_success_step_id=0,
  897. @on_fail_action=2,
  898. @on_fail_step_id=0,
  899. @retry_attempts=0,
  900. @retry_interval=0,
  901. @os_run_priority=0, @subsystem=N'TSQL',
  902. @command=N'-- Cleans maintenance plans txt reports older than 30 days
  903. SET NOCOUNT ON;
  904. -- Is it Sunday yet?
  905. IF (SELECT 1 & POWER(2, DATEPART(weekday, GETDATE())-1)) > 0
  906. BEGIN
  907. DECLARE @path NVARCHAR(500), @date DATETIME
  908. DECLARE @sqlcmd NVARCHAR(1000), @params NVARCHAR(100), @sqlmajorver int
  909. SELECT @sqlmajorver = CONVERT(int, (@@microsoftversion / 0x1000000) & 0xff);
  910. SET @date = GETDATE()-30
  911. IF @sqlmajorver < 11
  912. BEGIN
  913. EXEC master..xp_instance_regread N''HKEY_LOCAL_MACHINE'',N''Software\Microsoft\MSSQLServer\Setup'',N''SQLPath'', @path OUTPUT
  914. SET @path = @path + ''\LOG''
  915. END
  916. ELSE
  917. BEGIN
  918. SET @sqlcmd = N''SELECT @pathOUT = LEFT([path], LEN([path])-1) FROM sys.dm_os_server_diagnostics_log_configurations'';
  919. SET @params = N''@pathOUT NVARCHAR(2048) OUTPUT'';
  920. EXECUTE sp_executesql @sqlcmd, @params, @pathOUT=@path OUTPUT;
  921. END
  922. -- Default location for maintenance plan txt files is the Log folder.
  923. -- If you changed from the default location since you last installed SQL Server, uncomment below and set the custom desired path.
  924. --SET @path = ''C:\custom_location''
  925. EXECUTE master..xp_delete_file 1,@path,N''txt'',@date,1
  926. END
  927. ELSE
  928. BEGIN
  929. PRINT ''** Skipping: Today is not Sunday - '' + CONVERT(VARCHAR, GETDATE())
  930. END;',
  931. @database_name=N'master',
  932. @flags=20
  933. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  934. EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
  935. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  936. EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'Weekly Maintenance - Sundays',
  937. @enabled=1,
  938. @freq_type=8,
  939. @freq_interval=1,
  940. @freq_subday_type=1,
  941. @freq_subday_interval=0,
  942. @freq_relative_interval=0,
  943. @freq_recurrence_factor=1,
  944. @active_start_date=20071009,
  945. @active_end_date=99991231,
  946. @active_start_time=83000,
  947. @active_end_time=235959
  948. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  949. EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'Weekly Maintenance - Weekdays and Saturdays',
  950. @enabled=1,
  951. @freq_type=8,
  952. @freq_interval=126,
  953. @freq_subday_type=1,
  954. @freq_subday_interval=0,
  955. @freq_relative_interval=0,
  956. @freq_recurrence_factor=1,
  957. @active_start_date=20131017,
  958. @active_end_date=99991231,
  959. @active_start_time=10000,
  960. @active_end_time=235959
  961. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  962. EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
  963. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  964. COMMIT TRANSACTION
  965. GOTO EndSave
  966. QuitWithRollback:
  967. IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
  968. EndSave:
  969. GO
  970. PRINT 'Weekly Maintenance job created';
  971. GO