Fix_VLFs.sql 12 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246
  1. -- 2011-05-24 Pedro Lopes (Microsoft) [email protected] (http://aka.ms/sqlinsights)
  2. --
  3. -- 2012-03-25 Added SQL 2012 support
  4. -- 2012-09-19 Simplified logic
  5. -- 2012-09-20 Changed grow settings if not SQL Server 2012
  6. --
  7. -- Generates the sql statements to preemtively fix VLF issues in all DBs within the server, based on the transaction log current size.
  8. --
  9. SET NOCOUNT ON;
  10. DECLARE @query VARCHAR(1000), @dbname VARCHAR(255), @count int, @usedlogsize bigint, @logsize bigint
  11. DECLARE @sqlcmd NVARCHAR(1000), @sqlparam NVARCHAR(100), @filename VARCHAR(255), @i int, @recmodel NVARCHAR(128)
  12. DECLARE @potsize int, @n_iter int, @n_iter_final int, @initgrow int, @n_init_iter int, @bckpath NVARCHAR(255)
  13. DECLARE @majorver smallint, @minorver smallint, @build smallint
  14. CREATE TABLE #loginfo (dbname varchar(100), num_of_rows int, used_logsize_MB DECIMAL(20,1))
  15. DECLARE @tblvlf TABLE (dbname varchar(100),
  16. Actual_log_size_MB DECIMAL(20,1),
  17. Potential_log_size_MB DECIMAL(20,1),
  18. Actual_VLFs int,
  19. Potential_VLFs int,
  20. Growth_iterations int,
  21. Log_Initial_size_MB DECIMAL(20,1),
  22. File_autogrow_MB DECIMAL(20,1))
  23. SELECT TOP 1 @bckpath = REVERSE(RIGHT(REVERSE(physical_device_name), LEN(physical_device_name)-CHARINDEX('\',REVERSE(physical_device_name),0))) FROM msdb.dbo.backupmediafamily WHERE device_type = 2
  24. SELECT @majorver = (@@microsoftversion / 0x1000000) & 0xff, @minorver = (@@microsoftversion / 0x10000) & 0xff, @build = @@microsoftversion & 0xffff
  25. --DECLARE csr CURSOR FAST_FORWARD FOR SELECT name FROM master..sysdatabases WHERE dbid > 4 AND DATABASEPROPERTYEX(name,'status') = 'ONLINE' AND DATABASEPROPERTYEX(name,'Updateability') = 'READ_WRITE' AND name <> 'tempdb' AND name <> 'ReportServerTempDB'
  26. DECLARE csr CURSOR FAST_FORWARD FOR SELECT name FROM master.sys.databases WHERE is_read_only = 0 AND state = 0 AND database_id <> 2;
  27. OPEN csr
  28. FETCH NEXT FROM csr INTO @dbname
  29. WHILE (@@FETCH_STATUS <> -1)
  30. BEGIN
  31. CREATE TABLE #log_info (recoveryunitid int NULL,
  32. fileid tinyint,
  33. file_size bigint,
  34. start_offset bigint,
  35. FSeqNo int,
  36. [status] tinyint,
  37. parity tinyint,
  38. create_lsn numeric(25,0))
  39. SET @query = 'DBCC LOGINFO (' + '''' + @dbname + ''') WITH NO_INFOMSGS'
  40. IF @majorver < 11
  41. BEGIN
  42. INSERT INTO #log_info (fileid, file_size, start_offset, FSeqNo, [status], parity, create_lsn)
  43. EXEC (@query)
  44. END
  45. ELSE
  46. BEGIN
  47. INSERT INTO #log_info (recoveryunitid, fileid, file_size, start_offset, FSeqNo, [status], parity, create_lsn)
  48. EXEC (@query)
  49. END
  50. SET @count = @@ROWCOUNT
  51. SET @usedlogsize = (SELECT (MIN(l.start_offset) + SUM(CASE WHEN l.status <> 0 THEN l.file_size ELSE 0 END))/1024.00/1024.00 FROM #log_info l)
  52. DROP TABLE #log_info;
  53. INSERT #loginfo
  54. VALUES(@dbname, @count, @usedlogsize);
  55. FETCH NEXT FROM csr INTO @dbname
  56. END
  57. CLOSE csr
  58. DEALLOCATE csr
  59. PRINT '/* Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */' + CHAR(10)
  60. DECLARE cshrk CURSOR FAST_FORWARD FOR SELECT dbname, num_of_rows FROM #loginfo
  61. WHERE num_of_rows >= 50 --My rule of thumb is 50 VLFs. Your mileage may vary.
  62. ORDER BY dbname
  63. OPEN cshrk
  64. FETCH NEXT FROM cshrk INTO @dbname, @count
  65. WHILE (@@FETCH_STATUS <> -1)
  66. BEGIN
  67. SET @sqlcmd = 'SELECT @nameout = name, @logsizeout = (size*8)/1024 FROM [' + @dbname + '].dbo.sysfiles WHERE (64 & status) = 64'
  68. SET @sqlparam = '@nameout NVARCHAR(100) OUTPUT, @logsizeout bigint OUTPUT'
  69. EXEC sp_executesql @sqlcmd, @sqlparam, @nameout = @filename OUTPUT, @logsizeout = @logsize OUTPUT;
  70. PRINT '---------------------------------------------------------------------------------------------------------- '
  71. PRINT CHAR(13) + 'USE ' + QUOTENAME(@dbname) + ';'
  72. PRINT 'DBCC SHRINKFILE (N''' + @filename + ''', 1, TRUNCATEONLY);'
  73. PRINT '--'
  74. PRINT '-- CHECK: if the tlog file has shrunk with the following query:'
  75. PRINT 'SELECT name, (size*8)/1024 AS log_MB FROM [' + @dbname + '].dbo.sysfiles WHERE (64 & status) = 64'
  76. PRINT '--'
  77. SET @recmodel = CONVERT(NVARCHAR, DATABASEPROPERTYEX(@dbname,'Recovery'))
  78. IF @recmodel <> 'SIMPLE'
  79. BEGIN
  80. PRINT '-- If the log has not shrunk, you must backup the transaction log next.'
  81. PRINT '-- Repeat the backup and shrink process alternatively until you get the desired log size (about 1MB).'
  82. PRINT '--'
  83. PRINT '-- METHOD: Backup -> Shrink (repeat the backup and shrink process until the log has shrunk):'
  84. PRINT '--'
  85. PRINT '-- Create example logical backup device.'
  86. PRINT 'USE master;' + CHAR(13) + 'EXEC sp_addumpdevice ''disk'', ''BckLog'', ''' + @bckpath + '\example_bck.trn'';'
  87. PRINT 'USE ' + QUOTENAME(@dbname) + ';'
  88. PRINT '-- Backup Log'
  89. PRINT 'BACKUP LOG ' + QUOTENAME(@dbname) + ' TO BckLog;'
  90. PRINT '-- Shrink'
  91. PRINT 'DBCC SHRINKFILE (N''' + @filename + ''', 1);'
  92. PRINT '--'
  93. PRINT '-- METHOD: Alter recovery model -> Shrink:'
  94. PRINT '-- NOTE: Because the database is in ' + @recmodel + ' recovery model, one alternative is to set it to SIMPLE to truncate the log, shrink it, and reset it to ' + @recmodel + '.'
  95. PRINT '-- NOTE2: This method of setting the recovery model to SIMPLE and back again WILL BREAK log chaining, and thus any log shipping or mirroring.'
  96. PRINT 'USE [master]; ' + CHAR(13) + 'ALTER DATABASE ' + QUOTENAME(@dbname) + ' SET RECOVERY SIMPLE;'
  97. PRINT 'USE ' + QUOTENAME(@dbname) + ';' + CHAR(13) + 'DBCC SHRINKFILE (N''' + @filename + ''', 1);'
  98. PRINT 'USE [master]; ' + CHAR(13) + 'ALTER DATABASE ' + QUOTENAME(@dbname) + ' SET RECOVERY ' + @recmodel + ';'
  99. PRINT '--'
  100. PRINT '-- CHECK: if the tlog file has shrunk with the following query:'
  101. PRINT 'SELECT name, (size*8)/1024 AS log_MB FROM [' + @dbname + '].dbo.sysfiles WHERE (64 & status) = 64'
  102. END
  103. ELSE
  104. BEGIN
  105. PRINT '-- If not, then proceed to the next step (it may be necessary to execute multiple times):'
  106. PRINT 'DBCC SHRINKFILE (N''' + @filename + ''', 1);'
  107. PRINT '-- CHECK: if the tlog file has shrunk with the following query:'
  108. PRINT 'SELECT name, (size*8)/1024 AS log_MB FROM [' + @dbname + '].dbo.sysfiles WHERE (64 & status) = 64'
  109. END
  110. -- We are growing in MB instead of GB because of known issue prior to SQL 2012.
  111. -- More detail here: http://www.sqlskills.com/BLOGS/PAUL/post/Bug-log-file-growth-broken-for-multiples-of-4GB.aspx
  112. -- and http://connect.microsoft.com/SQLServer/feedback/details/481594/log-growth-not-working-properly-with-specific-growth-sizes-vlfs-also-not-created-appropriately
  113. -- or https://connect.microsoft.com/SQLServer/feedback/details/357502/transaction-log-file-size-will-not-grow-exactly-4gb-when-filegrowth-4gb
  114. IF @majorver >= 11
  115. BEGIN
  116. SET @n_iter = (SELECT CASE WHEN @logsize <= 64 THEN 1
  117. WHEN @logsize > 64 AND @logsize < 256 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/256, 0)
  118. WHEN @logsize >= 256 AND @logsize < 1024 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/512, 0)
  119. WHEN @logsize >= 1024 AND @logsize < 4096 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/1024, 0)
  120. WHEN @logsize >= 4096 AND @logsize < 8192 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/2048, 0)
  121. WHEN @logsize >= 8192 AND @logsize < 16384 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/4096, 0)
  122. WHEN @logsize >= 16384 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/8192, 0)
  123. END)
  124. SET @potsize = (SELECT CASE WHEN @logsize <= 64 THEN 1*64
  125. WHEN @logsize > 64 AND @logsize < 256 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/256, 0)*256
  126. WHEN @logsize >= 256 AND @logsize < 1024 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/512, 0)*512
  127. WHEN @logsize >= 1024 AND @logsize < 4096 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/1024, 0)*1024
  128. WHEN @logsize >= 4096 AND @logsize < 8192 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/2048, 0)*2048
  129. WHEN @logsize >= 8192 AND @logsize < 16384 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/4096, 0)*4096
  130. WHEN @logsize >= 16384 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/8192, 0)*8192
  131. END)
  132. END
  133. ELSE
  134. BEGIN
  135. SET @n_iter = (SELECT CASE WHEN @logsize <= 64 THEN 1
  136. WHEN @logsize > 64 AND @logsize < 256 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/256, 0)
  137. WHEN @logsize >= 256 AND @logsize < 1024 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/512, 0)
  138. WHEN @logsize >= 1024 AND @logsize < 4096 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/1024, 0)
  139. WHEN @logsize >= 4096 AND @logsize < 8192 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/2048, 0)
  140. WHEN @logsize >= 8192 AND @logsize < 16384 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/4000, 0)
  141. WHEN @logsize >= 16384 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/8000, 0)
  142. END)
  143. SET @potsize = (SELECT CASE WHEN @logsize <= 64 THEN 1*64
  144. WHEN @logsize > 64 AND @logsize < 256 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/256, 0)*256
  145. WHEN @logsize >= 256 AND @logsize < 1024 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/512, 0)*512
  146. WHEN @logsize >= 1024 AND @logsize < 4096 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/1024, 0)*1024
  147. WHEN @logsize >= 4096 AND @logsize < 8192 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/2048, 0)*2048
  148. WHEN @logsize >= 8192 AND @logsize < 16384 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/4000, 0)*4000
  149. WHEN @logsize >= 16384 THEN ROUND(CONVERT(FLOAT, ROUND(@logsize, -2))/8000, 0)*8000
  150. END)
  151. END
  152. -- If the proposed log size is smaller than current log, and also smaller than 4GB,
  153. -- and there is less than 512MB of diff between the current size and proposed size, add 1 grow.
  154. SET @n_iter_final = @n_iter
  155. IF @logsize > @potsize AND @potsize <= 4096 AND ABS(@logsize - @potsize) < 512
  156. BEGIN
  157. SET @n_iter_final = @n_iter + 1
  158. END
  159. -- If the proposed log size is larger than current log, and also larger than 50GB,
  160. -- and there is less than 1GB of diff between the current size and proposed size, take 1 grow.
  161. ELSE IF @logsize < @potsize AND @potsize <= 51200 AND ABS(@logsize - @potsize) > 1024
  162. BEGIN
  163. SET @n_iter_final = @n_iter - 1
  164. END
  165. IF @potsize = 0
  166. BEGIN
  167. SET @potsize = 64
  168. END
  169. IF @n_iter = 0
  170. BEGIN
  171. SET @n_iter = 1
  172. END
  173. SET @potsize = (SELECT CASE WHEN @n_iter < @n_iter_final THEN @potsize + (@potsize/@n_iter)
  174. WHEN @n_iter > @n_iter_final THEN @potsize - (@potsize/@n_iter)
  175. ELSE @potsize END)
  176. SET @n_init_iter = @n_iter_final
  177. IF @potsize >= 8192
  178. BEGIN
  179. SET @initgrow = @potsize/@n_iter_final
  180. END
  181. IF @potsize >= 64 AND @potsize <= 512
  182. BEGIN
  183. SET @n_init_iter = 1
  184. SET @initgrow = 512
  185. END
  186. IF @potsize > 512 AND @potsize <= 1024
  187. BEGIN
  188. SET @n_init_iter = 1
  189. SET @initgrow = 1023
  190. END
  191. IF @potsize > 1024 AND @potsize < 8192
  192. BEGIN
  193. SET @n_init_iter = 1
  194. SET @initgrow = @potsize
  195. END
  196. INSERT INTO @tblvlf
  197. SELECT @dbname, @logsize, @potsize, @count,
  198. CASE WHEN @potsize <= 64 THEN (@potsize/(@potsize/@n_init_iter))*4
  199. WHEN @potsize > 64 AND @potsize < 1024 THEN (@potsize/(@potsize/@n_init_iter))*8
  200. WHEN @potsize >= 1024 THEN (@potsize/(@potsize/@n_init_iter))*16
  201. END,
  202. @n_init_iter, @initgrow, CASE WHEN (@potsize/@n_iter_final) <= 1024 THEN (@potsize/@n_iter_final) ELSE 1024 END
  203. SET @i = 0
  204. WHILE @i <= @n_init_iter
  205. BEGIN
  206. IF @i = 1
  207. BEGIN
  208. --Log Autogrow should not be above 1GB
  209. PRINT CHAR(13) + '-- Now for the log file growth:'
  210. PRINT 'ALTER DATABASE [' + @dbname + '] MODIFY FILE ( NAME = N''' + @filename + ''', SIZE = ' + CONVERT(VARCHAR, @initgrow) + 'MB , FILEGROWTH = ' + CASE WHEN (@potsize/@n_iter_final) <= 1024 THEN CONVERT(VARCHAR, (@potsize/@n_iter_final)) ELSE '1024' END + 'MB );'
  211. END
  212. IF @i > 1
  213. BEGIN
  214. PRINT 'ALTER DATABASE [' + @dbname + '] MODIFY FILE ( NAME = N''' + @filename + ''', SIZE = ' + CONVERT(VARCHAR, @initgrow*@i)+ 'MB );'
  215. END
  216. SET @i = @i + 1
  217. CONTINUE
  218. END
  219. FETCH NEXT FROM cshrk INTO @dbname, @count
  220. END
  221. CLOSE cshrk
  222. DEALLOCATE cshrk;
  223. DROP TABLE #loginfo;
  224. SELECT dbname AS [Database_Name], Actual_log_size_MB, Potential_log_size_MB, Actual_VLFs,
  225. Potential_VLFs, Growth_iterations, Log_Initial_size_MB, File_autogrow_MB
  226. FROM @tblvlf;
  227. GO