Skip to content

Commit f0f8084

Browse files
Update Adding_Trace_Flags_To_Startup_Parameters.sql
1 parent a7d07f1 commit f0f8084

File tree

1 file changed

+20
-34
lines changed

1 file changed

+20
-34
lines changed

Scripts/Adding_Trace_Flags_To_Startup_Parameters.sql

+20-34
Original file line numberDiff line numberDiff line change
@@ -23,74 +23,61 @@ MODIFICATION LOG
2323
*******************************************************************************/
2424
SET NOCOUNT ON;
2525

26-
-- Declare and initialize variables.
27-
DECLARE @MaxValue INT,
28-
@SQLCMD VARCHAR(MAX),
29-
@RegHive VARCHAR(50),
30-
@RegKey VARCHAR(100),
31-
@DebugLevel TINYINT;
26+
DECLARE @MaxValue INT,
27+
@SQLCMD VARCHAR(MAX),
28+
@RegHive VARCHAR(50) = 'HKEY_LOCAL_MACHINE',
29+
@RegKey VARCHAR(100) = 'Software\Microsoft\MSSQLSERVER\MSSQLServer\Parameters',
30+
@DebugLevel TINYINT = 1;
3231

33-
-- Registry hive and key for SQL Server startup parameters
34-
SET @RegHive = 'HKEY_LOCAL_MACHINE';
35-
SET @RegKey = 'Software\Microsoft\MSSQLSERVER\MSSQLServer\Parameters';
36-
-- Set debug level: 0 to execute changes, 1 to only show what will happen
37-
SET @DebugLevel = 1;
38-
39-
-- Add the trace flags that you want to modify here.
4032
DECLARE @TraceFlags TABLE (
41-
TF INT,
42-
enable BIT,
43-
enable_on_startup BIT,
44-
TF2 AS '-T' + CONVERT(VARCHAR(15), TF)
33+
TF INT,
34+
enable BIT,
35+
enable_on_startup BIT,
36+
TF2 AS '-T' + CONVERT(VARCHAR(15), TF)
4537
);
4638
INSERT INTO @TraceFlags (TF, enable, enable_on_startup)
47-
SELECT 1117, 1, 1 UNION ALL
48-
SELECT 1118, 1, 1 UNION ALL
49-
SELECT 1204, 0, 0 UNION ALL
50-
SELECT 1222, 0, 0;
39+
VALUES (1117, 1, 1),
40+
(1118, 1, 1),
41+
(1204, 0, 0),
42+
(1222, 0, 0);
5143

52-
-- Get all arguments/parameters when starting up the service.
5344
DECLARE @SQLArgs TABLE (
54-
Value VARCHAR(50),
55-
Data VARCHAR(500),
56-
ArgNum AS CONVERT(INT, REPLACE(Value, 'SQLArg', ''))
45+
Value VARCHAR(50),
46+
Data VARCHAR(500),
47+
ArgNum AS CONVERT(INT, REPLACE(Value, 'SQLArg', ''))
5748
);
5849
INSERT INTO @SQLArgs
5950
EXEC master.sys.xp_instance_regenumvalues @RegHive, @RegKey;
6051

61-
-- Get the highest argument number that is currently set
6252
SELECT @MaxValue = MAX(ArgNum) FROM @SQLArgs;
6353
PRINT 'MaxValue: ' + CAST(@MaxValue AS VARCHAR);
6454

65-
-- Disable specified trace flags
6655
SELECT @SQLCMD = 'DBCC TRACEOFF(' +
6756
STUFF((SELECT ',' + CONVERT(VARCHAR(15), TF)
6857
FROM @TraceFlags
6958
WHERE enable = 0
7059
ORDER BY TF
71-
FOR XML PATH(''), TYPE).value('.','varchar(max)'), 1, 1, '') + ', -1);'
60+
FOR XML PATH(''), TYPE).value('.','varchar(max)'), 1, 1, '') + ', -1);';
7261
IF @DebugLevel = 0 EXEC (@SQLCMD);
7362
PRINT 'Disable TFs Command: "' + @SQLCMD + '"';
7463

75-
-- Enable specified trace flags
7664
SELECT @SQLCMD = 'DBCC TRACEON(' +
7765
STUFF((SELECT ',' + CONVERT(VARCHAR(15), TF)
7866
FROM @TraceFlags
7967
WHERE enable = 1
8068
ORDER BY TF
81-
FOR XML PATH(''), TYPE).value('.','varchar(max)'), 1, 1, '') + ', -1);'
69+
FOR XML PATH(''), TYPE).value('.','varchar(max)'), 1, 1, '') + ', -1);';
8270
IF @DebugLevel = 0 EXEC (@SQLCMD);
8371
PRINT 'Enable TFs Command: "' + @SQLCMD + '"';
8472

85-
-- Prepare to update the registry with new trace flags
8673
DECLARE cSQLParams CURSOR LOCAL FAST_FORWARD FOR
8774
WITH cte AS (
88-
SELECT *,
75+
SELECT * ,
8976
ROW_NUMBER() OVER (ORDER BY ISNULL(ArgNum, 999999999), TF) - 1 AS RN
9077
FROM @SQLArgs arg
9178
FULL OUTER JOIN @TraceFlags tf ON arg.Data = tf.TF2
9279
), cte2 AS (
93-
SELECT ca.Value, ca.Data,
80+
SELECT ca.Value, ca.Data,
9481
ROW_NUMBER() OVER (ORDER BY RN) - 1 AS RN2
9582
FROM cte
9683
CROSS APPLY (SELECT ISNULL(Value, 'SQLArg' + CONVERT(VARCHAR(15), RN)), ISNULL(Data, TF2)) ca(Value, Data)
@@ -113,7 +100,6 @@ END;
113100
CLOSE cSQLParams;
114101
DEALLOCATE cSQLParams;
115102

116-
-- Delete extra SQLArg values if more trace flags were removed than added
117103
WHILE @MaxValue > @MaxRN2
118104
BEGIN
119105
SET @Value = 'SQLArg' + CONVERT(VARCHAR(15), @MaxValue);

0 commit comments

Comments
 (0)