1
0

5_job_Maintenance_MEA.sql 47 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455565758596061626364656667686970717273747576777879808182838485868788899091929394959697989910010110210310410510610710810911011111211311411511611711811912012112212312412512612712812913013113213313413513613713813914014114214314414514614714814915015115215315415515615715815916016116216316416516616716816917017117217317417517617717817918018118218318418518618718818919019119219319419519619719819920020120220320420520620720820921021121221321421521621721821922022122222322422522622722822923023123223323423523623723823924024124224324424524624724824925025125225325425525625725825926026126226326426526626726826927027127227327427527627727827928028128228328428528628728828929029129229329429529629729829930030130230330430530630730830931031131231331431531631731831932032132232332432532632732832933033133233333433533633733833934034134234334434534634734834935035135235335435535635735835936036136236336436536636736836937037137237337437537637737837938038138238338438538638738838939039139239339439539639739839940040140240340440540640740840941041141241341441541641741841942042142242342442542642742842943043143243343443543643743843944044144244344444544644744844945045145245345445545645745845946046146246346446546646746846947047147247347447547647747847948048148248348448548648748848949049149249349449549649749849950050150250350450550650750850951051151251351451551651751851952052152252352452552652752852953053153253353453553653753853954054154254354454554654754854955055155255355455555655755855956056156256356456556656756856957057157257357457557657757857958058158258358458558658758858959059159259359459559659759859960060160260360460560660760860961061161261361461561661761861962062162262362462562662762862963063163263363463563663763863964064164264364464564664764864965065165265365465565665765865966066166266366466566666766866967067167267367467567667767867968068168268368468568668768868969069169269369469569669769869970070170270370470570670770870971071171271371471571671771871972072172272372472572672772872973073173273373473573673773873974074174274374474574674774874975075175275375475575675775875976076176276376476576676776876977077177277377477577677777877978078178278378478578678778878979079179279379479579679779879980080180280380480580680780880981081181281381481581681781881982082182282382482582682782882983083183283383483583683783883984084184284384484584684784884985085185285385485585685785885986086186286386486586686786886987087187287387487587687787887988088188288388488588688788888989089189289389489589689789889990090190290390490590690790890991091191291391491591691791891992092192292392492592692792892993093193293393493593693793893994094194294394494594694794894995095195295395495595695795895996096196296396496596696796896997097197297397497597697797897998098198298398498598698798898999099199299399499599699799899910001001100210031004100510061007100810091010101110121013101410151016101710181019102010211022102310241025102610271028102910301031103210331034103510361037103810391040104110421043104410451046104710481049105010511052105310541055105610571058105910601061106210631064106510661067106810691070107110721073107410751076107710781079108010811082108310841085108610871088108910901091109210931094109510961097109810991100110111021103110411051106110711081109111011111112111311141115111611171118111911201121112211231124112511261127112811291130113111321133113411351136113711381139114011411142
  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 Fridays, if VLDB Mode = 0, runs DBCC CHECKALLOC.
  38. |- On Fridays, 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 Friday 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 Friday.
  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 Friday yet? If so, start database check
  144. IF (SELECT 32 & 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 Friday yet? If so, start building
  246. IF (SELECT 32 & 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 Friday yet? If so, start working on allocation and catalog checks on todays bucket
  346. IF (SELECT 32 & 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 END
  650. END
  651. END;
  652. UPDATE #tmpdbs
  653. SET isdone = 1
  654. FROM #tmpdbs
  655. WHERE [dbid] = @dbid AND isdone = 0
  656. END;
  657. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tmpdbs'))
  658. DROP TABLE #tmpdbs
  659. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblObj'))
  660. DROP TABLE #tblObj;
  661. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblBuckets'))
  662. DROP TABLE #tblBuckets;
  663. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblFGs'))
  664. DROP TABLE #tblFGs;
  665. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblSnapFiles'))
  666. DROP TABLE #tblSnapFiles;
  667. SELECT @Message = '** Finished: ' + CONVERT(VARCHAR, GETDATE())
  668. RAISERROR(@Message, 0, 42) WITH NOWAIT;
  669. GO
  670. PRINT 'Procedure usp_CheckIntegrity created';
  671. GO
  672. ------------------------------------------------------------------------------------------------------------------------------
  673. IF EXISTS (SELECT job_id FROM msdb.dbo.sysjobs_view WHERE name = N'Weekly Maintenance')
  674. EXEC msdb.dbo.sp_delete_job @job_name=N'Weekly Maintenance', @delete_unused_schedule=1
  675. GO
  676. PRINT 'Creating Weekly Maintenance job';
  677. GO
  678. BEGIN TRANSACTION
  679. -- Set the Operator name to receive notifications, if any. Set the job owner, if not sa.
  680. DECLARE @customoper sysname, @jobowner sysname
  681. SET @customoper = 'SQLAdmins'
  682. SET @jobowner = 'sa'
  683. DECLARE @ReturnCode INT
  684. SELECT @ReturnCode = 0
  685. IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'Database Maintenance' AND category_class=1)
  686. BEGIN
  687. EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'Database Maintenance'
  688. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  689. END
  690. DECLARE @jobId BINARY(16)
  691. IF EXISTS (SELECT name FROM msdb.dbo.sysoperators WHERE name = @customoper)
  692. BEGIN
  693. EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'Weekly Maintenance',
  694. @enabled=1,
  695. @notify_level_eventlog=2,
  696. @notify_level_email=3,
  697. @notify_level_netsend=2,
  698. @notify_level_page=2,
  699. @delete_level=0,
  700. @description=N'Runs weekly maintenance cycle. Most steps execute on Fridays 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.',
  701. @category_name=N'Database Maintenance',
  702. @owner_login_name=@jobowner,
  703. @notify_email_operator_name=@customoper,
  704. @job_id = @jobId OUTPUT
  705. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  706. END
  707. ELSE
  708. BEGIN
  709. EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'Weekly Maintenance',
  710. @enabled=1,
  711. @notify_level_eventlog=2,
  712. @notify_level_email=3,
  713. @notify_level_netsend=0,
  714. @notify_level_page=0,
  715. @delete_level=0,
  716. @description=N'Runs weekly maintenance cycle. Most steps execute on Fridays 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.',
  717. @category_name=N'Database Maintenance',
  718. @owner_login_name=@jobowner,
  719. @job_id = @jobId OUTPUT
  720. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  721. END
  722. EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'DBCC CheckDB',
  723. @step_id=1,
  724. @cmdexec_success_code=0,
  725. @on_success_action=3,
  726. @on_success_step_id=0,
  727. @on_fail_action=2,
  728. @on_fail_step_id=0,
  729. @retry_attempts=0,
  730. @retry_interval=0,
  731. @os_run_priority=0, @subsystem=N'TSQL',
  732. @command=N'/*
  733. This checks the logical and physical integrity of all the objects in the specified database by performing the following operations:
  734. |-For VLDBs (larger than 1TB):
  735. |- On Fridays, if VLDB Mode = 0, runs DBCC CHECKALLOC.
  736. |- On Fridays, runs DBCC CHECKCATALOG.
  737. |- 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.
  738. |-For DBs smaller than 1TB:
  739. |- Every Friday a DBCC CHECKDB checks the logical and physical integrity of all the objects in the specified database.
  740. To set how VLDBs are handled, set @VLDBMode to 0 = Bucket by Table Size or 1 = Bucket by Filegroup Size
  741. IMPORTANT: Consider running DBCC CHECKDB routinely (at least, weekly). On large databases and for more frequent checks, consider using the PHYSICAL_ONLY parameter.
  742. http://msdn.microsoft.com/en-us/library/ms176064.aspx
  743. http://blogs.msdn.com/b/sqlserverstorageengine/archive/2006/10/20/consistency-checking-options-for-a-vldb.aspx
  744. If a database has Read-Only filegroups, any integrity check will fail if there are other open connections to the database.
  745. Setting @CreateSnap = 1 will create a database snapshot before running the check on the snapshot, and drop it at the end (default).
  746. Setting @CreateSnap = 0 means the integrity check might fail if there are other open connection on the database.
  747. 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.
  748. Setting @SingleUser = 1 will set the database in single user mode before running the check, and to multi user afterwards.
  749. Setting @SingleUser = 0 means the integrity check might fail if there are other open connection on the database.
  750. */
  751. EXEC msdb.dbo.usp_CheckIntegrity @VLDBMode = 1, @SingleUser = 0, @CreateSnap = 1
  752. ',
  753. @database_name=N'master',
  754. @flags=20
  755. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  756. EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'update usage',
  757. @step_id=2,
  758. @cmdexec_success_code=0,
  759. @on_success_action=3,
  760. @on_success_step_id=0,
  761. @on_fail_action=2,
  762. @on_fail_step_id=0,
  763. @retry_attempts=0,
  764. @retry_interval=0,
  765. @os_run_priority=0, @subsystem=N'TSQL',
  766. @command=N'/*
  767. DBCC UPDATEUSAGE corrects the rows, used pages, reserved pages, leaf pages and data page counts for each partition in a table or index.
  768. 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.
  769. http://msdn.microsoft.com/en-us/library/ms188414.aspx
  770. Exludes all Offline or Read-Only DBs. Also excludes all databases over 4GB in size.
  771. */
  772. SET NOCOUNT ON;
  773. -- Is it Friday yet?
  774. IF (SELECT 32 & POWER(2, DATEPART(weekday, GETDATE())-1)) > 0
  775. BEGIN
  776. PRINT ''** Start: '' + CONVERT(VARCHAR, GETDATE())
  777. DECLARE @dbname sysname, @sqlcmd NVARCHAR(500)
  778. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.#tmpdbs''))
  779. CREATE TABLE #tmpdbs (id int IDENTITY(1,1), [dbname] sysname, isdone bit)
  780. INSERT INTO #tmpdbs ([dbname], isdone)
  781. SELECT QUOTENAME(d.name), 0 FROM sys.databases d INNER JOIN sys.master_files smf ON d.database_id = smf.database_id
  782. 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;
  783. WHILE (SELECT COUNT([dbname]) FROM #tmpdbs WHERE isdone = 0) > 0
  784. BEGIN
  785. SET @dbname = (SELECT TOP 1 [dbname] FROM #tmpdbs WHERE isdone = 0)
  786. SET @sqlcmd = ''DBCC UPDATEUSAGE ('' + @dbname + '')''
  787. PRINT CHAR(10) + CONVERT(VARCHAR, GETDATE()) + '' - Started space corrections on '' + @dbname
  788. EXECUTE sp_executesql @sqlcmd
  789. PRINT CONVERT(VARCHAR, GETDATE()) + '' - Ended space corrections on '' + @dbname
  790. UPDATE #tmpdbs
  791. SET isdone = 1
  792. FROM #tmpdbs
  793. WHERE [dbname] = @dbname AND isdone = 0
  794. END;
  795. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.#tmpdbs''))
  796. DROP TABLE #tmpdbs;
  797. PRINT ''** Finished: '' + CONVERT(VARCHAR, GETDATE())
  798. END
  799. ELSE
  800. BEGIN
  801. PRINT ''** Skipping: Today is not Friday - '' + CONVERT(VARCHAR, GETDATE())
  802. END;',
  803. @database_name=N'master',
  804. @flags=20
  805. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  806. EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'sp_createstats',
  807. @step_id=3,
  808. @cmdexec_success_code=0,
  809. @on_success_action=3,
  810. @on_success_step_id=0,
  811. @on_fail_action=2,
  812. @on_fail_step_id=0,
  813. @retry_attempts=0,
  814. @retry_interval=0,
  815. @os_run_priority=0, @subsystem=N'TSQL',
  816. @command=N'/*
  817. Creates statistics only on columns that are part of an existing index, and are not the first column in any index definition.
  818. Creating single-column statistics increases the number of histograms, which can improve cardinality estimates, query plans, and query performance.
  819. The first column of a statistics object has a histogram; other columns do not have a histogram.
  820. http://msdn.microsoft.com/en-us/library/ms186834.aspx
  821. Exludes all Offline and Read-Only DBs
  822. */
  823. SET NOCOUNT ON;
  824. -- Is it Friday yet?
  825. IF (SELECT 32 & POWER(2, DATEPART(weekday, GETDATE())-1)) > 0
  826. BEGIN
  827. PRINT ''** Start: '' + CONVERT(VARCHAR, GETDATE())
  828. DECLARE @dbname sysname, @sqlcmd NVARCHAR(500)
  829. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.#tmpdbs''))
  830. CREATE TABLE #tmpdbs (id int IDENTITY(1,1), [dbname] sysname, isdone bit)
  831. INSERT INTO #tmpdbs ([dbname], isdone)
  832. SELECT QUOTENAME(name), 0 FROM sys.databases WHERE is_read_only = 0 AND state = 0 AND database_id > 4 AND is_distributor = 0;
  833. WHILE (SELECT COUNT([dbname]) FROM #tmpdbs WHERE isdone = 0) > 0
  834. BEGIN
  835. SET @dbname = (SELECT TOP 1 [dbname] FROM #tmpdbs WHERE isdone = 0)
  836. SET @sqlcmd = @dbname + ''.dbo.sp_createstats @indexonly = ''''indexonly''''''
  837. SELECT CHAR(10) + CONVERT(VARCHAR, GETDATE()) + '' - Started indexed stats creation on '' + @dbname
  838. EXECUTE sp_executesql @sqlcmd
  839. SELECT CONVERT(VARCHAR, GETDATE()) + '' - Ended indexed stats creation on '' + @dbname
  840. UPDATE #tmpdbs
  841. SET isdone = 1
  842. FROM #tmpdbs
  843. WHERE [dbname] = @dbname AND isdone = 0
  844. END;
  845. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.#tmpdbs''))
  846. DROP TABLE #tmpdbs;
  847. PRINT ''** Finished: '' + CONVERT(VARCHAR, GETDATE())
  848. END
  849. ELSE
  850. BEGIN
  851. PRINT ''** Skipping: Today is not Friday - '' + CONVERT(VARCHAR, GETDATE())
  852. END;',
  853. @database_name=N'master',
  854. @flags=20
  855. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  856. EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Cleanup Job History',
  857. @step_id=4,
  858. @cmdexec_success_code=0,
  859. @on_success_action=3,
  860. @on_success_step_id=0,
  861. @on_fail_action=2,
  862. @on_fail_step_id=0,
  863. @retry_attempts=0,
  864. @retry_interval=0,
  865. @os_run_priority=0, @subsystem=N'TSQL',
  866. @command=N'-- Cleans msdb job history older than 30 days
  867. SET NOCOUNT ON;
  868. -- Is it Friday yet?
  869. IF (SELECT 32 & POWER(2, DATEPART(weekday, GETDATE())-1)) > 0
  870. BEGIN
  871. DECLARE @date DATETIME
  872. SET @date = GETDATE()-30
  873. EXEC msdb.dbo.sp_purge_jobhistory @oldest_date=@date;
  874. END
  875. ELSE
  876. BEGIN
  877. PRINT ''** Skipping: Today is not Friday - '' + CONVERT(VARCHAR, GETDATE())
  878. END;',
  879. @database_name=N'msdb',
  880. @flags=20
  881. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  882. EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Cleanup Maintenance Plan txt reports',
  883. @step_id=5,
  884. @cmdexec_success_code=0,
  885. @on_success_action=1,
  886. @on_success_step_id=0,
  887. @on_fail_action=2,
  888. @on_fail_step_id=0,
  889. @retry_attempts=0,
  890. @retry_interval=0,
  891. @os_run_priority=0, @subsystem=N'TSQL',
  892. @command=N'-- Cleans maintenance plans txt reports older than 30 days
  893. SET NOCOUNT ON;
  894. -- Is it Friday yet?
  895. IF (SELECT 32 & POWER(2, DATEPART(weekday, GETDATE())-1)) > 0
  896. BEGIN
  897. DECLARE @path NVARCHAR(500), @date DATETIME
  898. DECLARE @sqlcmd NVARCHAR(1000), @params NVARCHAR(100), @sqlmajorver int
  899. SELECT @sqlmajorver = CONVERT(int, (@@microsoftversion / 0x1000000) & 0xff);
  900. SET @date = GETDATE()-30
  901. IF @sqlmajorver < 11
  902. BEGIN
  903. EXEC master..xp_instance_regread N''HKEY_LOCAL_MACHINE'',N''Software\Microsoft\MSSQLServer\Setup'',N''SQLPath'', @path OUTPUT
  904. SET @path = @path + ''\LOG''
  905. END
  906. ELSE
  907. BEGIN
  908. SET @sqlcmd = N''SELECT @pathOUT = LEFT([path], LEN([path])-1) FROM sys.dm_os_server_diagnostics_log_configurations'';
  909. SET @params = N''@pathOUT NVARCHAR(2048) OUTPUT'';
  910. EXECUTE sp_executesql @sqlcmd, @params, @pathOUT=@path OUTPUT;
  911. END
  912. -- Default location for maintenance plan txt files is the Log folder.
  913. -- If you changed from the default location since you last installed SQL Server, uncomment below and set the custom desired path.
  914. --SET @path = ''C:\custom_location''
  915. EXECUTE master..xp_delete_file 1,@path,N''txt'',@date,1
  916. END
  917. ELSE
  918. BEGIN
  919. PRINT ''** Skipping: Today is not Friday - '' + CONVERT(VARCHAR, GETDATE())
  920. END;',
  921. @database_name=N'master',
  922. @flags=20
  923. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  924. EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
  925. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  926. EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'Weekly Maintenance - Fridays',
  927. @enabled=1,
  928. @freq_type=8,
  929. @freq_interval=1,
  930. @freq_subday_type=1,
  931. @freq_subday_interval=0,
  932. @freq_relative_interval=0,
  933. @freq_recurrence_factor=1,
  934. @active_start_date=20071009,
  935. @active_end_date=99991231,
  936. @active_start_time=83000,
  937. @active_end_time=235959
  938. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  939. EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'Weekly Maintenance - Weekdays and Saturdays',
  940. @enabled=1,
  941. @freq_type=8,
  942. @freq_interval=126,
  943. @freq_subday_type=1,
  944. @freq_subday_interval=0,
  945. @freq_relative_interval=0,
  946. @freq_recurrence_factor=1,
  947. @active_start_date=20131017,
  948. @active_end_date=99991231,
  949. @active_start_time=10000,
  950. @active_end_time=235959
  951. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  952. EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
  953. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  954. COMMIT TRANSACTION
  955. GOTO EndSave
  956. QuitWithRollback:
  957. IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
  958. EndSave:
  959. GO
  960. PRINT 'Weekly Maintenance job created';
  961. GO