|
| 1 | +/****************************************************************************** |
| 2 | +Source link: https://blog.waynesheffield.com/wayne/archive/2017/09/registry-sql-server-startup-parameters/ |
| 3 | +Author: Wayne Sheffield |
| 4 | +
|
| 5 | +Globally enable / disable the specified trace flags. |
| 6 | +Use DBCC TRACEON/TRACEOFF to enable disable globally trace flags, then adjust |
| 7 | +the SQL Server instance startup parameters for these trace flags. |
| 8 | + |
| 9 | +SQL Server startup parameters are stored in the registry at: |
| 10 | +HKLM\Software\Microsoft\Microsoft SQL Server\MSSQL12.SQL2014\MSSQLServer\Parameters |
| 11 | + |
| 12 | +To use the xp_instance_reg... XPs, use: |
| 13 | +HKLM\Software\Microsoft\MSSQLSERVER\MSSQLServer\Parameters. |
| 14 | + |
| 15 | +To use: |
| 16 | +1. Add the Trace Flags that you want modified to the @TraceFlags table variable. |
| 17 | +2. Set the @DebugLevel variable to 1 to see what will happen on your system first. |
| 18 | +3. When satisified what will happen, set @DebugLevel to 0 to actually execute the statements. |
| 19 | +******************************************************************************** |
| 20 | + MODIFICATION LOG |
| 21 | +******************************************************************************** |
| 22 | +2016-08-03 WGS Initial Creation. |
| 23 | +*******************************************************************************/ |
| 24 | +SET NOCOUNT ON; |
| 25 | +-- Declare and initialize variables. |
| 26 | +-- To use with SQL 2005, cannot set the variables in the declare statement. |
| 27 | +DECLARE @MaxValue INTEGER, |
| 28 | + @SQLCMD VARCHAR(MAX), |
| 29 | + @RegHive VARCHAR(50), |
| 30 | + @RegKey VARCHAR(100), |
| 31 | + @DebugLevel TINYINT; |
| 32 | + |
| 33 | +SET @RegHive = 'HKEY_LOCAL_MACHINE'; |
| 34 | +SET @RegKey = 'Software\Microsoft\MSSQLSERVER\MSSQLServer\Parameters'; |
| 35 | +SET @DebugLevel = 0; -- only makes changes if set to zero! |
| 36 | + |
| 37 | +-- Add the trace flags that you want changed here. |
| 38 | +-- If enable = 1, DBCC TRACEON will be run; if enable = 0 then DBCC TRACEOFF will be run. |
| 39 | +-- If enable_on_startup = 1, then this TF will be added to start up on service restart; |
| 40 | +-- If enable_on_startup - 0, then this TF will be removed from starting up service restart |
| 41 | +DECLARE @TraceFlags TABLE ( |
| 42 | + TF INTEGER, |
| 43 | + enable BIT, |
| 44 | + enable_on_startup BIT, |
| 45 | + TF2 AS '-T' + CONVERT(VARCHAR(15), TF) |
| 46 | +); |
| 47 | +INSERT INTO @TraceFlags (TF, enable, enable_on_startup) |
| 48 | +-- To work with SQL 2005, cannot use a table value constructor. |
| 49 | +-- So, use SELECT statements with UNION ALL for each TF to modify. |
| 50 | +SELECT 1117, 1, 1 UNION ALL |
| 51 | +SELECT 1118, 1, 1 UNION ALL |
| 52 | +SELECT 1204, 0, 0 UNION ALL |
| 53 | +SELECT 1222, 0, 0; |
| 54 | + |
| 55 | + |
| 56 | +-- Get all of the arguments / parameters when starting up the service. |
| 57 | +DECLARE @SQLArgs TABLE ( |
| 58 | + Value VARCHAR(50), |
| 59 | + Data VARCHAR(500), |
| 60 | + ArgNum AS CONVERT(INTEGER, REPLACE(Value, 'SQLArg', ''))); |
| 61 | +INSERT INTO @SQLArgs |
| 62 | + EXECUTE master.sys.xp_instance_regenumvalues @RegHive, @RegKey; |
| 63 | + |
| 64 | + |
| 65 | +-- Get the highest argument number that is currently set |
| 66 | +SELECT @MaxValue = MAX(ArgNum) |
| 67 | +FROM @SQLArgs; |
| 68 | +RAISERROR('MaxValue: %i', 10, 1, @MaxValue) WITH NOWAIT; |
| 69 | + |
| 70 | +-- Disable specified trace flags |
| 71 | +SELECT @SQLCMD = 'DBCC TRACEOFF(' + |
| 72 | + STUFF((SELECT ',' + CONVERT(VARCHAR(15), TF) |
| 73 | + FROM @TraceFlags |
| 74 | + WHERE enable = 0 |
| 75 | + ORDER BY TF |
| 76 | + FOR XML PATH(''), TYPE).value('.','varchar(max)') |
| 77 | + ,1,1,'') + ', -1);' |
| 78 | + |
| 79 | +IF @DebugLevel = 0 EXECUTE (@SQLCMD); |
| 80 | +RAISERROR('Disable TFs Command: "%s"', 10, 1, @SQLCMD) WITH NOWAIT; |
| 81 | + |
| 82 | +-- Enable specified trace flags |
| 83 | +SELECT @SQLCMD = 'DBCC TRACEON(' + |
| 84 | + STUFF((SELECT ',' + CONVERT(VARCHAR(15), TF) |
| 85 | + FROM @TraceFlags |
| 86 | + WHERE enable = 1 |
| 87 | + ORDER BY TF |
| 88 | + FOR XML PATH(''), TYPE).value('.','varchar(max)') |
| 89 | + ,1,1,'') + ', -1);' |
| 90 | + |
| 91 | +IF @DebugLevel = 0 EXECUTE (@SQLCMD); |
| 92 | +RAISERROR('Enable TFs Command: "%s"', 10, 1, @SQLCMD) WITH NOWAIT; |
| 93 | + |
| 94 | +DECLARE cSQLParams CURSOR LOCAL FAST_FORWARD FOR |
| 95 | +WITH cte AS |
| 96 | +( |
| 97 | + -- Current arguments, with new TFs added at the end. Get a row number to sort by. |
| 98 | + SELECT *, |
| 99 | + ROW_NUMBER() OVER (ORDER BY ISNULL(ArgNum, 999999999), TF) - 1 AS RN |
| 100 | + FROM @SQLArgs arg |
| 101 | + FULL OUTER JOIN @TraceFlags tf ON arg.Data = tf.TF2 |
| 102 | +), cte2 AS |
| 103 | +( |
| 104 | + -- Use the row number to calc the SQLArg# for new TFs. |
| 105 | + -- Use the original Value (SQLArg#) and Data for all rows if possible, |
| 106 | + -- Otherwise use the calculated SQLArg# and the calculated TF2 column. |
| 107 | + -- Only get the original non-TF-matched parameters, and the TFs set to be enabled |
| 108 | + -- (existing startup TFs not in @TraceFlags are left alone). |
| 109 | + SELECT ca.Value, |
| 110 | + ca.Data |
| 111 | + -- in case any TFs are removed, calculate new row numbers in order |
| 112 | + -- to renumber the SQLArg values |
| 113 | + , ROW_NUMBER() OVER (ORDER BY RN) - 1 AS RN2 |
| 114 | + FROM cte |
| 115 | + -- Again, for SQL 2005, use SELECT statement instead of VALUES. |
| 116 | + CROSS APPLY (SELECT ISNULL(Value, 'SQLArg' + CONVERT(VARCHAR(15), RN)), |
| 117 | + ISNULL(Data, TF2) ) ca(Value, Data) |
| 118 | + WHERE ISNULL(enable_on_startup, 1) = 1 -- ISNULL handles non-TF parameters |
| 119 | +) |
| 120 | +-- The first three parameters are the location of the errorlog directory, |
| 121 | +-- and the master database file locations. Ignore these. |
| 122 | +-- This returns the remaining parameters that should be set. |
| 123 | +-- Also return the highest number of parameters, so can determine if any need to be deleted. |
| 124 | +SELECT 'SQLArg' + CONVERT(VARCHAR(15), RN2) AS Value, |
| 125 | + Data, |
| 126 | + MAX(RN2) OVER () AS MaxRN2 |
| 127 | +FROM cte2 |
| 128 | +WHERE RN2 > 2 |
| 129 | +ORDER BY RN2; |
| 130 | + |
| 131 | +DECLARE @Value VARCHAR(50), |
| 132 | + @Data VARCHAR(500), |
| 133 | + @MaxRN2 INTEGER; |
| 134 | +OPEN cSQLParams; |
| 135 | +FETCH NEXT FROM cSQLParams INTO @Value, @Data, @MaxRN2; |
| 136 | +WHILE @@FETCH_STATUS = 0 |
| 137 | +BEGIN |
| 138 | + IF @DebugLevel = 0 EXECUTE master.sys.xp_instance_regwrite @RegHive, @RegKey, @Value, 'REG_SZ', @Data; |
| 139 | + RAISERROR('EXECUTE master.sys.xp_instance_regwrite ''%s'', ''%s'', ''%s'', ''REG_SZ'', ''%s''', 10, 1, @RegHive, @RegKey, @Value, @Data) WITH NOWAIT; |
| 140 | + FETCH NEXT FROM cSQLParams INTO @Value, @Data, @MaxRN2; |
| 141 | +END; |
| 142 | +CLOSE cSQLParams; |
| 143 | +DEALLOCATE cSQLParams; |
| 144 | + |
| 145 | +-- In case deleting more TFs than added, there may be extra SQLArg values left behind. |
| 146 | +-- Need to delete the extras now. |
| 147 | +WHILE @MaxValue > @MaxRN2 |
| 148 | +BEGIN |
| 149 | + SET @Value = 'SQLArg' + CONVERT(VARCHAR(15), @MaxValue); |
| 150 | + IF @DebugLevel = 0 EXECUTE master.sys.xp_instance_regdeletevalue @RegHive, @RegKey, @Value; |
| 151 | + RAISERROR('EXECUTE master.sys.xp_instance_regdeletevalue ''%s'', ''%s'', ''%s''', 10, 1, @RegHive, @RegKey, @Value) WITH NOWAIT; |
| 152 | + SET @MaxValue = @MaxValue - 1; |
| 153 | +END; |
0 commit comments