|
| 1 | + |
| 2 | + |
| 3 | +/******************************************************************************************************* |
| 4 | + |
| 5 | + SQL SERVER - Initial Checks. |
| 6 | + |
| 7 | +******************************************************************************************************** |
| 8 | + |
| 9 | + Description: |
| 10 | + Purpose: |
| 11 | + Author: Ian Stirk. |
| 12 | + Date: May 2013. |
| 13 | + |
| 14 | + Notes: 1. Some steps may fail if you dont have permissions. |
| 15 | + |
| 16 | +*********************************************************************************************************/ |
| 17 | + |
| 18 | +-- Do not lock anything, and do not get held up by any locks. |
| 19 | +SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED |
| 20 | + |
| 21 | +-- Get SQL Version |
| 22 | +DECLARE @SQLVersion INT |
| 23 | +SELECT @SQLVersion = CAST(SUBSTRING(@@VERSION, 22, 4) AS INT) -- Example @@Version: Microsoft SQL Server 2008 (SP3) - 10.0.5768.0 (X64) |
| 24 | + |
| 25 | +-- This routine needs SQL Server 2005 or higher to run. |
| 26 | +IF @SQLVersion < 2005 |
| 27 | +BEGIN |
| 28 | + RAISERROR('This routine needs SQL Server 2005 or higher to run. Routine has exited', 16,1) |
| 29 | + RETURN |
| 30 | +END |
| 31 | + |
| 32 | + |
| 33 | +-- Step counter value, used to separate pieces of outout. |
| 34 | +DECLARE @StepCounter AS INT |
| 35 | +SET @StepCounter = 0 |
| 36 | + |
| 37 | + |
| 38 | +/************************************************************************************/ |
| 39 | +/* */ |
| 40 | +/* Purpose: Show datetime of run. */ |
| 41 | +/* Notes: 1. xxxxx */ |
| 42 | +/* */ |
| 43 | +/************************************************************************************/ |
| 44 | +SET @StepCounter = @StepCounter + 1 |
| 45 | +SELECT 'Step ' + CAST(@StepCounter AS VARCHAR(10)) + ': ' + 'DateTime of run' |
| 46 | + |
| 47 | +SELECT CONVERT(VARCHAR(33), GetDate(), 109) AS RunDateTime |
| 48 | + |
| 49 | + |
| 50 | +/************************************************************************************/ |
| 51 | +/* */ |
| 52 | +/* Purpose: Show the version of SQL Server. */ |
| 53 | +/* Notes: 1. Running the expected version of SQL Server? */ |
| 54 | +/* */ |
| 55 | +/************************************************************************************/ |
| 56 | +SET @StepCounter = @StepCounter + 1 |
| 57 | +SELECT 'Step ' + CAST(@StepCounter AS VARCHAR(10)) + ': ' + 'SQL Server version' |
| 58 | + |
| 59 | +SELECT @@VERSION |
| 60 | + |
| 61 | + |
| 62 | +/************************************************************************************/ |
| 63 | +/* */ |
| 64 | +/* Purpose: Get property info about server instance. */ |
| 65 | +/* Notes: 1. IsIntegratedSecurityOnly: 1 = windows only */ |
| 66 | +/* 2. ProductLevel - contains RTM or SP level. Is SP the correct one?! */ |
| 67 | +/* 3. ProductVersion - major.minor.build */ |
| 68 | +/* */ |
| 69 | +/************************************************************************************/ |
| 70 | +SET @StepCounter = @StepCounter + 1 |
| 71 | +SELECT 'Step ' + CAST(@StepCounter AS VARCHAR(10)) + ': ' + 'Property info about server instance' |
| 72 | + |
| 73 | +SELECT SERVERPROPERTY('ServerName') AS [ServerName] |
| 74 | + ,SERVERPROPERTY('InstanceName') AS [InstanceName] |
| 75 | + ,SERVERPROPERTY('MachineName') AS [MachineName] |
| 76 | + ,SERVERPROPERTY('Edition') AS [Edition] |
| 77 | + ,SERVERPROPERTY('ProductVersion') AS [ProductVersion] |
| 78 | + ,SERVERPROPERTY('ProductLevel') AS [ProductLevel] |
| 79 | + ,SERVERPROPERTY('IsIntegratedSecurityOnly') AS [IsIntegratedSecurityOnly] |
| 80 | + ,SERVERPROPERTY('IsClustered') AS [IsClustered] |
| 81 | + |
| 82 | + |
| 83 | +/************************************************************************************/ |
| 84 | +/* */ |
| 85 | +/* Purpose: Get OS information. */ |
| 86 | +/* Notes: 1. CPU/Memory/last reboot time useful. */ |
| 87 | +/* */ |
| 88 | +/************************************************************************************/ |
| 89 | +SET @StepCounter = @StepCounter + 1 |
| 90 | +SELECT 'Step ' + CAST(@StepCounter AS VARCHAR(10)) + ': ' + 'OS information' |
| 91 | + |
| 92 | +SELECT cpu_count AS [Logical CPUs] |
| 93 | +, cpu_count / hyperthread_ratio AS [Physical CPUs] |
| 94 | +, CAST(physical_memory_kb / 1024.0 /1024.0 AS DECIMAL(28,2)) AS [Memory (GB)] |
| 95 | +, DATEADD(ss, -(ms_ticks / 1000), GetDate()) AS [Start DateTime] |
| 96 | +-- , sqlserver_start_time AS [Start DateTime] -- In 2008+ |
| 97 | + FROM sys.dm_os_sys_info |
| 98 | + |
| 99 | + |
| 100 | +/************************************************************************************/ |
| 101 | +/* */ |
| 102 | +/* Purpose: Show SQL Server configuration info. */ |
| 103 | +/* Notes: 1. priority boost - should be off (0) */ |
| 104 | +/* 2. cost threshold for parallelism (evaluate with MAXDOP) */ |
| 105 | +/* 3. max degree of parallelism (1 or 8?) */ |
| 106 | +/* 4. max server memory (MB) - evaluate in context of server memory */ |
| 107 | +/* 5. clr enabled - generally disable, unless needed */ |
| 108 | +/* 6. optimize for ad hoc workloads - often recommended to have on. */ |
| 109 | +/* */ |
| 110 | +/************************************************************************************/ |
| 111 | +SET @StepCounter = @StepCounter + 1 |
| 112 | +SELECT 'Step ' + CAST(@StepCounter AS VARCHAR(10)) + ': ' + 'Configuration - specifics' |
| 113 | + |
| 114 | +SELECT name, description, value_in_use |
| 115 | +FROM sys.configurations |
| 116 | +WHERE NAME IN( |
| 117 | + 'clr enabled' |
| 118 | +, 'max degree of parallelism' |
| 119 | +, 'cost threshold for parallelism' |
| 120 | +, 'max server memory (MB)' -- Set appropriately |
| 121 | +, 'optimize for ad hoc workloads' -- should be 1. |
| 122 | +, 'priority boost' -- should be 0 |
| 123 | +) |
| 124 | +ORDER BY name |
| 125 | + |
| 126 | + |
| 127 | +/************************************************************************************/ |
| 128 | +/* */ |
| 129 | +/* Purpose: Identify what is causing the waits. */ |
| 130 | +/* Notes: 1. Check Tom Davidson's 2005 article to decode WAIT Types. */ |
| 131 | +/* */ |
| 132 | +/************************************************************************************/ |
| 133 | +SET @StepCounter = @StepCounter + 1 |
| 134 | +SELECT 'Step ' + CAST(@StepCounter AS VARCHAR(10)) + ': ' + 'Most common waits' |
| 135 | + |
| 136 | +;WITH Waits AS |
| 137 | +(SELECT wait_type, wait_time_ms / 1000. AS wait_time_s, |
| 138 | +100. * wait_time_ms / SUM(wait_time_ms) OVER() AS pct, |
| 139 | +ROW_NUMBER() OVER(ORDER BY wait_time_ms DESC) AS rn |
| 140 | +FROM sys.dm_os_wait_stats |
| 141 | +WHERE wait_type NOT IN ('CLR_SEMAPHORE','LAZYWRITER_SLEEP','RESOURCE_QUEUE','SLEEP_TASK' |
| 142 | +,'SLEEP_SYSTEMTASK','SQLTRACE_BUFFER_FLUSH','WAITFOR', 'LOGMGR_QUEUE','CHECKPOINT_QUEUE' |
| 143 | +,'REQUEST_FOR_DEADLOCK_SEARCH','XE_TIMER_EVENT','BROKER_TO_FLUSH','BROKER_TASK_STOP','CLR_MANUAL_EVENT' |
| 144 | +,'CLR_AUTO_EVENT','DISPATCHER_QUEUE_SEMAPHORE', 'FT_IFTS_SCHEDULER_IDLE_WAIT' |
| 145 | +,'XE_DISPATCHER_WAIT', 'XE_DISPATCHER_JOIN', 'SQLTRACE_INCREMENTAL_FLUSH_SLEEP','ONDEMAND_TASK_QUEUE')) |
| 146 | + |
| 147 | +SELECT W1.wait_type, |
| 148 | +CAST(W1.wait_time_s AS DECIMAL(12, 2)) AS wait_time_s, |
| 149 | +CAST(W1.pct AS DECIMAL(12, 2)) AS pct, |
| 150 | +CAST(SUM(W2.pct) AS DECIMAL(12, 2)) AS running_pct |
| 151 | +FROM Waits AS W1 |
| 152 | +INNER JOIN Waits AS W2 |
| 153 | +ON W2.rn <= W1.rn |
| 154 | +GROUP BY W1.rn, W1.wait_type, W1.wait_time_s, W1.pct |
| 155 | +HAVING SUM(W2.pct) - W1.pct < 99; -- percentage threshold |
| 156 | + |
| 157 | + |
| 158 | +/************************************************************************************/ |
| 159 | +/* */ |
| 160 | +/* Purpose: Signal Waits - CPU pressure. */ |
| 161 | +/* Notes: 1. How much time is spent swapping threads - above 20% is bad */ |
| 162 | +/* */ |
| 163 | +/************************************************************************************/ |
| 164 | +SET @StepCounter = @StepCounter + 1 |
| 165 | +SELECT 'Step ' + CAST(@StepCounter AS VARCHAR(10)) + ': ' + 'Signal Waits - CPU pressure' |
| 166 | + |
| 167 | +-- Signal Waits for instance |
| 168 | +SELECT CAST(100.0 * SUM(signal_wait_time_ms) / SUM (wait_time_ms) AS NUMERIC(20,2)) AS [%signal (cpu) waits], |
| 169 | +CAST(100.0 * SUM(wait_time_ms - signal_wait_time_ms) / SUM (wait_time_ms) AS NUMERIC(20,2)) AS [%resource waits] |
| 170 | +FROM sys.dm_os_wait_stats WITH (NOLOCK) OPTION (RECOMPILE); |
| 171 | + |
| 172 | + |
| 173 | +/************************************************************************************/ |
| 174 | +/* */ |
| 175 | +/* Purpose: Show SQL Server database info. */ |
| 176 | +/* Notes: 1. Check compatibility level */ |
| 177 | +/* 2. is_read_committed_snapshot_on (1 is good for concurrency) */ |
| 178 | +/* 3. recovery_model (want simple on non-prod boxes. Bulk_logged for prod) */ |
| 179 | +/* 4. page_verify - want CHECKSUM */ |
| 180 | +/* */ |
| 181 | +/************************************************************************************/ |
| 182 | +SET @StepCounter = @StepCounter + 1 |
| 183 | +SELECT 'Step ' + CAST(@StepCounter AS VARCHAR(10)) + ': ' + 'sys.databases' |
| 184 | + |
| 185 | +SELECT name, compatibility_level, recovery_model_desc, page_verify_option_desc, is_read_committed_snapshot_on |
| 186 | +FROM sys.databases ORDER BY name |
| 187 | + |
| 188 | + |
| 189 | +/************************************************************************************/ |
| 190 | +/* */ |
| 191 | +/* Purpose: CPU utilization usage per object database. */ |
| 192 | +/* Notes: 1. Is a single DB hogging CPU? Maybe needs a separate server */ |
| 193 | +/* */ |
| 194 | +/************************************************************************************/ |
| 195 | +SET @StepCounter = @StepCounter + 1 |
| 196 | +SELECT 'Step ' + CAST(@StepCounter AS VARCHAR(10)) + ': ' + 'CPU usage by database' |
| 197 | + |
| 198 | +-- Get CPU utilization by database |
| 199 | +;WITH DB_CPU_Stats |
| 200 | +AS |
| 201 | +(SELECT DatabaseID, DB_Name(DatabaseID) AS [DatabaseName], |
| 202 | + SUM(total_worker_time) AS [CPU_Time_Ms] |
| 203 | + FROM sys.dm_exec_query_stats AS qs |
| 204 | + CROSS APPLY (SELECT CONVERT(int, value) AS [DatabaseID] |
| 205 | + FROM sys.dm_exec_plan_attributes(qs.plan_handle) |
| 206 | + WHERE attribute = N'dbid') AS F_DB |
| 207 | + GROUP BY DatabaseID) |
| 208 | +SELECT ROW_NUMBER() OVER(ORDER BY [CPU_Time_Ms] DESC) AS [row_num], |
| 209 | + DatabaseName, [CPU_Time_Ms], |
| 210 | + CAST([CPU_Time_Ms] * 1.0 / SUM([CPU_Time_Ms]) |
| 211 | + OVER() * 100.0 AS DECIMAL(5, 2)) AS [CPUPercent] |
| 212 | +FROM DB_CPU_Stats |
| 213 | +WHERE DatabaseID > 4 -- system databases |
| 214 | +AND DatabaseID <> 32767 -- ResourceDB |
| 215 | +ORDER BY [CPUPercent] DESC OPTION (RECOMPILE); |
| 216 | + |
| 217 | + |
| 218 | +/************************************************************************************/ |
| 219 | +/* */ |
| 220 | +/* Purpose: Memory usage per database. */ |
| 221 | +/* Notes: 1. Is a single DB hogging memory? Maybe needs a separate server */ |
| 222 | +/* */ |
| 223 | +/************************************************************************************/ |
| 224 | +SET @StepCounter = @StepCounter + 1 |
| 225 | +SELECT 'Step ' + CAST(@StepCounter AS VARCHAR(10)) + ': ' + 'Memory usage by database' |
| 226 | + |
| 227 | +SELECT |
| 228 | + ISNULL(DB_NAME(database_id), 'ResourceDb') AS DatabaseName |
| 229 | + , CAST(COUNT(row_count) * 8.0 / (1024.0) AS DECIMAL(28,2)) AS [Size (MB)] |
| 230 | + , CAST(COUNT(row_count) * 8.0 / (1024.0) / 1024.0 AS DECIMAL(28,2)) AS [Size (GB)] |
| 231 | +FROM sys.dm_os_buffer_descriptors |
| 232 | +GROUP BY database_id |
| 233 | +ORDER BY [Size (MB)] DESC |
0 commit comments