├── README.md └── T-SQL Scripts ├── Blocking Monitoring.sql ├── CPU Monitoring.sql ├── Disk Space Monitoring.sql ├── IO Monitoring.sql ├── Memory Monitoring.sql ├── Session Monitoring.sql ├── Wait stat Monitoring.sql └── sp_whoisactive.sql /README.md: -------------------------------------------------------------------------------- 1 | # AwesomeSQLServer 2 | 3 | A big collection of SQL Server Queries and documeantations to fix your SQL Server's bottle neck 4 | 5 | ## Monitoring 6 | * [Monitor CPU Usgae](https://github.com/SqlAdmin/AwesomeSQLServer/blob/master/T-SQL%20Scripts/CPU%20Monitoring.sql) 7 | * [Monitor Memory Usage](https://github.com/SqlAdmin/AwesomeSQLServer/blob/master/T-SQL%20Scripts/Memory%20Monitoring.sql) 8 | * [Monitor Disk Usgae](https://github.com/SqlAdmin/AwesomeSQLServer/blob/master/T-SQL%20Scripts/Disk%20Space%20Monitoring.sql) 9 | * [Session Monitoring](https://github.com/SqlAdmin/AwesomeSQLServer/blob/master/T-SQL%20Scripts/Session%20Monitoring.sql) 10 | * [Blocking, Deadlock Monitoring](https://github.com/SqlAdmin/AwesomeSQLServer/blob/master/T-SQL%20Scripts/Blocking%20Monitoring.sql) 11 | * [IO Monitoring](https://github.com/SqlAdmin/AwesomeSQLServer/blob/master/T-SQL%20Scripts/IO%20Monitoring.sql) 12 | * [Wait stat Monitoring](https://github.com/SqlAdmin/AwesomeSQLServer/blob/master/T-SQL%20Scripts/Wait%20stat%20Monitoring.sql) 13 | -------------------------------------------------------------------------------- /T-SQL Scripts/Blocking Monitoring.sql: -------------------------------------------------------------------------------- 1 | /******************************************************************************************** 2 | 3 | *** Blocking and deadlock monitor *** 4 | ------------------------------------------------ 5 | 6 | I have prepared this script to monitor blocking sessions with sp_whoisactive, 7 | So first you need tocreate sp_whoisactive stored procedure, 8 | please downad it from the link, 9 | 10 | https://github.com/SqlAdmin/AwesomeSQLServer/blob/master/T-SQL%20Scripts/sp_whoisactive.sql 11 | 12 | *******************************************************************************************/ 13 | 14 | 15 | -- To get overall info about current sessions 16 | 17 | EXEC sp_whoisactive 18 | --------------------------------------- 19 | /*** 1. Monitor blocking session ***/ 20 | --------------------------------------- 21 | 22 | EXEC sp_WhoIsActive @find_block_leaders = 1, 23 | @output_column_list = '[dd%][session_id][database_name][login_name] [sql_text][wait_info][blocking_session_id][blocked_session_count]', 24 | @sort_order = '[start_time] ASC'; 25 | 26 | 27 | --------------------------------------- 28 | /*** 2. Monitor deadlocking session ***/ 29 | --------------------------------------- 30 | 31 | WITH [Blocking] 32 | AS (SELECT 33 | w.[session_id], 34 | s.[original_login_name], 35 | s.[login_name], 36 | w.[wait_duration_ms], 37 | w.[wait_type], 38 | r.[status], 39 | r.[wait_resource], 40 | w.[resource_description], 41 | s.[program_name], 42 | w.[blocking_session_id], 43 | s.[host_name], 44 | r.[command], 45 | r.[percent_complete], 46 | r.[cpu_time], 47 | r.[total_elapsed_time], 48 | r.[reads], 49 | r.[writes], 50 | r.[logical_reads], 51 | r.[row_count], 52 | q.[text], 53 | q.[dbid], 54 | p.[query_plan], 55 | r.[plan_handle] 56 | FROM [sys].[dm_os_waiting_tasks] w 57 | INNER JOIN [sys].[dm_exec_sessions] s 58 | ON w.[session_id] = s.[session_id] 59 | INNER JOIN [sys].[dm_exec_requests] r 60 | ON s.[session_id] = r.[session_id] 61 | CROSS APPLY [sys].[dm_exec_sql_text](r.[plan_handle]) q 62 | CROSS APPLY [sys].[dm_exec_query_plan](r.[plan_handle]) p 63 | WHERE w.[session_id] > 50 64 | AND w.[wait_type] NOT IN ('DBMIRROR_DBM_EVENT' 65 | , 'ASYNC_NETWORK_IO')) 66 | SELECT 67 | b.[session_id] AS [WaitingSessionID], 68 | b.[blocking_session_id] AS [BlockingSessionID], 69 | b.[login_name] AS [WaitingUserSessionLogin], 70 | s1.[login_name] AS [BlockingUserSessionLogin], 71 | b.[original_login_name] AS [WaitingUserConnectionLogin], 72 | s1.[original_login_name] AS [BlockingSessionConnectionLogin], 73 | b.[wait_duration_ms] AS [WaitDuration], 74 | b.[wait_type] AS [WaitType], 75 | t.[request_mode] AS [WaitRequestMode], 76 | UPPER(b.[status]) AS [WaitingProcessStatus], 77 | UPPER(s1.[status]) AS [BlockingSessionStatus], 78 | b.[wait_resource] AS [WaitResource], 79 | t.[resource_type] AS [WaitResourceType], 80 | t.[resource_database_id] AS [WaitResourceDatabaseID], 81 | DB_NAME(t.[resource_database_id]) AS [WaitResourceDatabaseName], 82 | b.[resource_description] AS [WaitResourceDescription], 83 | b.[program_name] AS [WaitingSessionProgramName], 84 | s1.[program_name] AS [BlockingSessionProgramName], 85 | b.[host_name] AS [WaitingHost], 86 | s1.[host_name] AS [BlockingHost], 87 | b.[command] AS [WaitingCommandType], 88 | b.[text] AS [WaitingCommandText], 89 | b.[row_count] AS [WaitingCommandRowCount], 90 | b.[percent_complete] AS [WaitingCommandPercentComplete], 91 | b.[cpu_time] AS [WaitingCommandCPUTime], 92 | b.[total_elapsed_time] AS [WaitingCommandTotalElapsedTime], 93 | b.[reads] AS [WaitingCommandReads], 94 | b.[writes] AS [WaitingCommandWrites], 95 | b.[logical_reads] AS [WaitingCommandLogicalReads], 96 | b.[query_plan] AS [WaitingCommandQueryPlan], 97 | b.[plan_handle] AS [WaitingCommandPlanHandle] 98 | FROM [Blocking] b 99 | INNER JOIN [sys].[dm_exec_sessions] s1 100 | ON b.[blocking_session_id] = s1.[session_id] 101 | INNER JOIN [sys].[dm_tran_locks] t 102 | ON t.[request_session_id] = b.[session_id] 103 | WHERE t.[request_status] = 'WAIT' 104 | GO -------------------------------------------------------------------------------- /T-SQL Scripts/CPU Monitoring.sql: -------------------------------------------------------------------------------- 1 | --=========================================-- 2 | /*** SQL SERVER CPU MONITORING QUERIES ***/ 3 | --=========================================------ 4 | -- Supported Versions SQL server 2008 and higher 5 | ------------------------------------------------- 6 | 7 | ------------------------------------- 8 | /*** 1. Current CPU Utilization ***/ 9 | ------------------------------------- 10 | 11 | DECLARE @ts BIGINT; 12 | DECLARE @lastNmin TINYINT; 13 | 14 | SELECT @ts = (SELECT cpu_ticks / ( cpu_ticks / ms_ticks ) 15 | FROM sys.dm_os_sys_info); 16 | 17 | SELECT TOP(1) Dateadd(ms, -1 * ( @ts - [timestamp] ), Getdate())AS [EventTime], 18 | sqlprocessutilization AS 19 | [SQL Server Utilization], 20 | 100 - systemidle - sqlprocessutilization AS 21 | [Other Process CPU_Utilization], 22 | systemidle AS [System Idle] 23 | FROM (SELECT 24 | record.value('(./Record/@id)[1]', 'int') AS record_id, 25 | record.value('(./Record/SchedulerMonitorEvent/SystemHealth/SystemIdle)[1]', 'int') AS [SystemIdle], 26 | record.value('(./Record/SchedulerMonitorEvent/SystemHealth/ProcessUtilization)[1]', 'int')AS [SQLProcessUtilization], 27 | [timestamp] 28 | FROM (SELECT[timestamp], 29 | CONVERT(XML, record) AS [record] 30 | FROM sys.dm_os_ring_buffers 31 | WHERE ring_buffer_type = N'RING_BUFFER_SCHEDULER_MONITOR' 32 | AND record LIKE'%%')AS x)AS y 33 | ORDER BY record_id DESC; 34 | 35 | 36 | --------------------------------------------- 37 | /*** 2.CPU Utilization for last N minutes***/ 38 | --------------------------------------------- 39 | -- Mention the minutes in @lastNmin Parameter 40 | 41 | DECLARE @ts BIGINT; 42 | DECLARE @lastNmin TINYINT; 43 | 44 | SET @lastNmin = 15; --Mention the Minutes Here 45 | 46 | SELECT @ts = (SELECT cpu_ticks / ( cpu_ticks / ms_ticks ) 47 | FROM sys.dm_os_sys_info); 48 | 49 | SELECT TOP(@lastNmin) Dateadd(ms, -1 * ( @ts - [timestamp] ), Getdate())AS 50 | [EventTime], 51 | sqlprocessutilization AS 52 | [SQL Server Utilization], 53 | 100 - systemidle - sqlprocessutilization AS 54 | [Other Process CPU_Utilization], 55 | systemidle AS 56 | [System Idle] 57 | FROM (SELECT 58 | record.value('(./Record/@id)[1]', 'int') AS record_id, 59 | record.value('(./Record/SchedulerMonitorEvent/SystemHealth/SystemIdle)[1]', 'int') AS [SystemIdle], 60 | record.value('(./Record/SchedulerMonitorEvent/SystemHealth/ProcessUtilization)[1]', 'int')AS [SQLProcessUtilization], 61 | [timestamp] 62 | FROM (SELECT[timestamp], 63 | CONVERT(XML, record) AS [record] 64 | FROM sys.dm_os_ring_buffers 65 | WHERE ring_buffer_type = N'RING_BUFFER_SCHEDULER_MONITOR' 66 | AND record LIKE'%%')AS x)AS y 67 | ORDER BY record_id DESC; 68 | 69 | 70 | ------------------------------------------ 71 | /*** 3.Database wise CPU Utilization ***/ 72 | ------------------------------------------ 73 | 74 | WITH db_cpu 75 | AS (SELECT databaseid, 76 | Db_name(databaseid) AS [DatabaseName], 77 | Sum(total_worker_time)AS [CPU_Time(Ms)] 78 | FROM sys.dm_exec_query_stats AS qs 79 | CROSS apply(SELECT CONVERT(INT, value)AS [DatabaseID] 80 | FROM sys.Dm_exec_plan_attributes(qs.plan_handle) 81 | WHERE attribute = N'dbid')AS epa 82 | GROUP BY databaseid) 83 | SELECT Row_number() 84 | OVER( 85 | ORDER BY [cpu_time(ms)] DESC) AS [SNO], 86 | databasename AS [DBName] 87 | , 88 | [cpu_time(ms)], 89 | Cast([cpu_time(ms)] * 1.0 / Sum([cpu_time(ms)]) 90 | OVER() * 100.0 AS DECIMAL(5, 2))AS 91 | [CPUPercent] 92 | FROM db_cpu 93 | WHERE databaseid > 4 -- system databases 94 | AND databaseid <> 32767 -- ResourceDB 95 | ORDER BY sno 96 | OPTION(recompile); 97 | 98 | 99 | --------------------------------------- 100 | /*** 4.Query Wise CPU Utilization ***/ 101 | --------------------------------------- 102 | -- This Query will show the queries and its CPU time if the avg CPU usgae is > 50 103 | -- You can modify this in IF @AvgCPUUtilization >= 50 104 | 105 | SET nocount ON 106 | 107 | DECLARE @ts_now BIGINT 108 | DECLARE @AvgCPUUtilization DECIMAL(10, 2) 109 | 110 | SELECT @ts_now = cpu_ticks / ( cpu_ticks / ms_ticks ) 111 | FROM sys.dm_os_sys_info 112 | 113 | -- load the CPU utilization in the past 10 minutes into the temp table, you can load them into a permanent table 114 | SELECT TOP(10) sqlprocessutilization AS 115 | [SQLServerProcessCPUUtilization], 116 | systemidle AS 117 | [SystemIdleProcess], 118 | 100 - systemidle - sqlprocessutilization AS 119 | [OtherProcessCPU Utilization], 120 | Dateadd(ms, -1 * ( @ts_now - [timestamp] ), Getdate()) AS 121 | [EventTime] 122 | INTO #cpuutilization 123 | FROM (SELECT record.value('(./Record/@id)[1]', 'int') 124 | AS record_id, 125 | record.value('(./Record/SchedulerMonitorEvent/SystemHealth/SystemIdle)[1]', 126 | 'int') 127 | AS [SystemIdle], 128 | record.value('(./Record/SchedulerMonitorEvent/SystemHealth/ProcessUtilization)[1]', 'int') AS [SQLProcessUtilization], 129 | [timestamp] 130 | FROM (SELECT [timestamp], 131 | CONVERT(XML, record) AS [record] 132 | FROM sys.dm_os_ring_buffers 133 | WHERE ring_buffer_type = N'RING_BUFFER_SCHEDULER_MONITOR' 134 | AND record LIKE '%%') AS x) AS y 135 | ORDER BY record_id DESC 136 | 137 | -- check if the average CPU utilization was over 50% in the past 10 minutes 138 | 139 | SELECT @AvgCPUUtilization = Avg([sqlserverprocesscpuutilization] 140 | + [otherprocesscpu utilization]) 141 | FROM #cpuutilization 142 | WHERE eventtime > Dateadd(mm, -10, Getdate()) 143 | 144 | IF @AvgCPUUtilization >= 50 145 | BEGIN 146 | SELECT TOP(10) CONVERT(VARCHAR(25), @AvgCPUUtilization) 147 | + '%' AS 148 | [AvgCPUUtilization], 149 | Getdate() 150 | [Date and Time] 151 | , 152 | r.cpu_time, 153 | r.total_elapsed_time, 154 | s.session_id, 155 | s.login_name, 156 | s.host_name, 157 | Db_name(r.database_id) AS 158 | DatabaseName 159 | , 160 | Substring (t.text, ( r.statement_start_offset / 2 ) + 1, ( 161 | ( CASE 162 | WHEN r.statement_end_offset = -1 THEN 163 | Len(CONVERT(NVARCHAR(max), t.text)) * 164 | 2 165 | ELSE r.statement_end_offset 166 | END - r.statement_start_offset ) / 2 ) + 1) AS 167 | [IndividualQuery], 168 | Substring(text, 1, 200) AS [ParentQuery], 169 | r.status, 170 | r.start_time, 171 | r.wait_type, 172 | s.program_name 173 | INTO #possiblecpuutilizationqueries 174 | FROM sys.dm_exec_sessions s 175 | INNER JOIN sys.dm_exec_connections c 176 | ON s.session_id = c.session_id 177 | INNER JOIN sys.dm_exec_requests r 178 | ON c.connection_id = r.connection_id 179 | CROSS apply sys.Dm_exec_sql_text(r.sql_handle) t 180 | WHERE s.session_id > 50 181 | AND r.session_id != @@spid 182 | ORDER BY r.cpu_time DESC 183 | 184 | 185 | SELECT * 186 | FROM #possiblecpuutilizationqueries 187 | END 188 | 189 | -- drop the temp tables 190 | IF Object_id('TEMPDB..#CPUUtilization') IS NOT NULL 191 | DROP TABLE #cpuutilization 192 | 193 | IF Object_id('TEMPDB..#PossibleCPUUtilizationQueries') IS NOT NULL 194 | DROP TABLE #possiblecpuutilizationqueries 195 | 196 | 197 | --------------------------------- 198 | /*** 5.TOP costliest Queries ***/ 199 | --------------------------------- 200 | -- This will give top 20 costliest queries which are executed recently. 201 | 202 | SELECT TOP (20) st.text AS Query, 203 | qs.execution_count, 204 | qs.total_worker_time AS Total_CPU, 205 | total_CPU_inSeconds = --Converted from microseconds 206 | qs.total_worker_time / 1000000, 207 | average_CPU_inSeconds = --Converted from microseconds 208 | ( qs.total_worker_time / 1000000 ) / qs.execution_count, 209 | qs.total_elapsed_time, 210 | total_elapsed_time_inSeconds = --Converted from microseconds 211 | qs.total_elapsed_time / 1000000, 212 | qp.query_plan 213 | FROM sys.dm_exec_query_stats AS qs 214 | CROSS apply sys.Dm_exec_sql_text(qs.sql_handle) AS st 215 | CROSS apply sys.Dm_exec_query_plan (qs.plan_handle) AS qp 216 | ORDER BY qs.total_worker_time DESC 217 | OPTION (recompile); 218 | 219 | 220 | ------------------------------------------------------------- 221 | /*** 5.TOP costliest Queries with batch and more details ***/ 222 | ------------------------------------------------------------- 223 | 224 | SELECT TOP 50 225 | [Avg. MultiCore/CPU time(sec)] = qs.total_worker_time / 1000000 / qs.execution_count, 226 | [Total MultiCore/CPU time(sec)] = qs.total_worker_time / 1000000, 227 | [Avg. Elapsed Time(sec)] = qs.total_elapsed_time / 1000000 / qs.execution_count, 228 | [Total Elapsed Time(sec)] = qs.total_elapsed_time / 1000000, 229 | qs.execution_count, 230 | [Avg. I/O] = (total_logical_reads + total_logical_writes) / qs.execution_count, 231 | [Total I/O] = total_logical_reads + total_logical_writes, 232 | Query = SUBSTRING(qt.[text], (qs.statement_start_offset / 2) + 1, 233 | ( 234 | ( 235 | CASE qs.statement_end_offset 236 | WHEN -1 THEN DATALENGTH(qt.[text]) 237 | ELSE qs.statement_end_offset 238 | END - qs.statement_start_offset 239 | ) / 2 240 | ) + 1 241 | ), 242 | Batch = qt.[text], 243 | [DB] = DB_NAME(qt.[dbid]), 244 | qs.last_execution_time, 245 | qp.query_plan 246 | FROM sys.dm_exec_query_stats AS qs 247 | CROSS APPLY sys.dm_exec_sql_text(qs.[sql_handle]) AS qt 248 | CROSS APPLY sys.dm_exec_query_plan(qs.plan_handle) AS qp 249 | 250 | ORDER BY [Total MultiCore/CPU time(sec)] DESC; 251 | -------------------------------------------------------------------------------- /T-SQL Scripts/Disk Space Monitoring.sql: -------------------------------------------------------------------------------- 1 | --==============================================-- 2 | /*** SQL SERVER Disk Space Monitoring QUERIES ***/ 3 | --==============================================-- 4 | 5 | -- Supported Versions SQL server 2008 and higher 6 | ------------------------------------------------- 7 | 8 | ---------------------------------------------- 9 | /*** 1. Get all Disks Total and Free Size ***/ 10 | ---------------------------------------------- 11 | 12 | 13 | DECLARE @MOUNTVOL TABLE 14 | ( MOUNTVOLResult nVARCHAR(500) 15 | ,ExecCommand nVARCHAR(500)) 16 | 17 | INSERT INTO @MOUNTVOL (MOUNTVOLResult) 18 | EXEC XP_CMDSHELL 'MOUNTVOL' 19 | 20 | DELETE @MOUNTVOL WHERE MOUNTVOLResult LIKE '%VOLUME%' 21 | DELETE @MOUNTVOL WHERE MOUNTVOLResult IS NULL 22 | DELETE @MOUNTVOL WHERE MOUNTVOLResult NOT LIKE '%:%' 23 | DELETE @MOUNTVOL WHERE MOUNTVOLResult LIKE '%MOUNTVOL%' 24 | DELETE @MOUNTVOL WHERE MOUNTVOLResult LIKE '%RECYCLE%' 25 | 26 | UPDATE @MOUNTVOL SET ExecCommand = 'EXEC XP_CMDSHELL ''FSUTIL VOLUME DISKFREE ' + LTRIM(RTRIM(MOUNTVOLResult)) +'''' 27 | 28 | DECLARE @DRIVESpace TABLE 29 | ( DriveLetter VARCHAR(10) 30 | ,DriveInfo VARCHAR(100)) 31 | 32 | WHILE (SELECT COUNT(*) FROM @MOUNTVOL) <>0 33 | BEGIN 34 | DECLARE @Command nVARCHAR(500), @DriveLetter nVARCHAR(10) 35 | Select @Command = ExecCommand, @DriveLetter= MOUNTVOLResult from @MOUNTVOL 36 | INSERT INTO @DRIVESpace (DriveInfo) Exec sp_executeSQL @Command 37 | UPDATE @DRIVESpace SET DriveLetter=@DriveLetter WHERE DriveLetter IS NULL 38 | DELETE FROM @MOUNTVOL WHERE ExecCommand=@Command 39 | END 40 | 41 | DECLARE @FinalResults TABLE 42 | ( DriveLetter nVARCHAR(10) 43 | ,[TotalDriveSpace(MB)] DECIMAL(18,2) 44 | ,[UsedSpaceOnDrive(MB)] AS ([TotalDriveSpace(MB)] - [FreeSpaceOnDrive(MB)]) 45 | ,[FreeSpaceOnDrive(MB)] DECIMAL(18,2) 46 | ,[TotalDriveSpace(GB)] AS CAST(([TotalDriveSpace(MB)]/1024) AS DECIMAL(18,2)) 47 | ,[UsedSpaceOnDrive(GB)] AS CAST((([TotalDriveSpace(MB)] - [FreeSpaceOnDrive(MB)])/1024) AS DECIMAL(18,2)) 48 | ,[FreeSpaceOnDrive(GB)] AS CAST(([FreeSpaceOnDrive(MB)]/1024) AS DECIMAL(18,2)) 49 | ,[%FreeSpace] AS CAST((([FreeSpaceOnDrive(MB)]/[TotalDriveSpace(MB)])*100) AS DECIMAL(18,2))) 50 | 51 | INSERT INTO @FinalResults (DriveLetter, [TotalDriveSpace(MB)],[FreeSpaceOnDrive(MB)]) 52 | SELECT RTRIM(LTRIM(DriveLetter)) 53 | ,[TotalDriveSpace(MB)] = SUM(CASE WHEN DriveInfo LIKE 'TOTAL # OF BYTES%' THEN CAST(SUBSTRING(DriveInfo, 32, 48) AS FLOAT) ELSE CAST(0 AS FLOAT) END)/1024/1024 54 | ,[FreeSpaceOnDrive(MB)] = SUM(CASE WHEN DriveInfo LIKE 'TOTAL # OF FREE BYTES%' THEN CAST(SUBSTRING(DriveInfo, 32, 48) AS FLOAT) ELSE CAST(0 AS FLOAT) END)/1024/1024 55 | FROM @DRIVESpace 56 | WHERE DriveInfo LIKE 'TOTAL # OF %' 57 | GROUP BY DriveLetter 58 | ORDER BY DriveLetter 59 | 60 | SELECT DriveLetter, [TotalDriveSpace(GB)], [TotalDriveSpace(GB)], [%FreeSpace] FROM @FinalResults 61 | 62 | 63 | ------------------------------------------------- 64 | /*** 2. Get databases physical file location ***/ 65 | ------------------------------------------------- 66 | 67 | SELECT DISTINCT Db_name(dovs.database_id) 68 | [Database Name], 69 | mf.physical_name 70 | [Physical File Location], 71 | dovs.logical_volume_name AS 72 | [Logical Name], 73 | dovs.volume_mount_point AS Drive, 74 | CONVERT(INT, dovs.available_bytes / 1048576.0 / 1024) AS 75 | [Free Space (GB)] 76 | FROM sys.master_files mf 77 | CROSS apply sys.Dm_os_volume_stats(mf.database_id, mf.file_id) dovs 78 | ORDER BY [free space (gb)] ASC 79 | 80 | 81 | ---------------------------------------------- 82 | /*** 3. List all Databases and its file size ***/ 83 | ---------------------------------------------- 84 | 85 | --Data file size 86 | DECLARE @dbsize TABLE ( 87 | Dbname sysname, 88 | dbstatus varchar(50), 89 | Recovery_Model varchar(40) DEFAULT ('NA'), 90 | file_Size_MB decimal(30, 2) DEFAULT (0), 91 | Space_Used_MB decimal(30, 2) DEFAULT (0), 92 | Free_Space_MB decimal(30, 2) DEFAULT (0) 93 | ) 94 | 95 | INSERT INTO @dbsize (Dbname, dbstatus, Recovery_Model, file_Size_MB, Space_Used_MB, Free_Space_MB) 96 | EXEC sp_msforeachdb 'use [?]; 97 | select DB_NAME() AS DbName, 98 | CONVERT(varchar(20),DatabasePropertyEx(''?'',''Status'')) , 99 | CONVERT(varchar(20),DatabasePropertyEx(''?'',''Recovery'')), 100 | sum(size)/128.0 AS File_Size_MB, 101 | sum(CAST(FILEPROPERTY(name, ''SpaceUsed'') AS INT))/128.0 as Space_Used_MB, 102 | SUM( size)/128.0 - sum(CAST(FILEPROPERTY(name,''SpaceUsed'') AS INT))/128.0 AS Free_Space_MB 103 | from sys.database_files where type=0 group by type' 104 | 105 | 106 | -- log file size 107 | DECLARE @logsize TABLE ( 108 | Dbname sysname, 109 | Log_File_Size_MB decimal(38, 2) DEFAULT (0), 110 | log_Space_Used_MB decimal(30, 2) DEFAULT (0), 111 | log_Free_Space_MB decimal(30, 2) DEFAULT (0) 112 | ) 113 | 114 | INSERT INTO @logsize (Dbname, Log_File_Size_MB, log_Space_Used_MB, log_Free_Space_MB) 115 | EXEC sp_msforeachdb 'use [?]; 116 | select DB_NAME() AS DbName, 117 | sum(size)/128.0 AS Log_File_Size_MB, 118 | sum(CAST(FILEPROPERTY(name, ''SpaceUsed'') AS INT))/128.0 as log_Space_Used_MB, 119 | SUM( size)/128.0 - sum(CAST(FILEPROPERTY(name,''SpaceUsed'') AS INT))/128.0 AS log_Free_Space_MB 120 | from sys.database_files where type=1 group by type' 121 | 122 | -- database free size 123 | DECLARE @dbfreesize TABLE ( 124 | name sysname, 125 | database_size varchar(50), 126 | Freespace varchar(50) DEFAULT (0.00) 127 | ) 128 | INSERT INTO @dbfreesize (name, database_size, Freespace) 129 | EXEC sp_msforeachdb 'use [?];SELECT database_name = db_name() 130 | ,database_size = ltrim(str((convert(DECIMAL(15, 2), dbsize) + convert(DECIMAL(15, 2), logsize)) * 8192 / 1048576, 15, 2) + ''MB'') 131 | ,''unallocated space'' = ltrim(str(( 132 | CASE 133 | WHEN dbsize >= reservedpages 134 | THEN (convert(DECIMAL(15, 2), dbsize) - convert(DECIMAL(15, 2), reservedpages)) * 8192 / 1048576 135 | ELSE 0 136 | END 137 | ), 15, 2) + '' MB'') 138 | FROM ( 139 | SELECT dbsize = sum(convert(BIGINT, CASE 140 | WHEN type = 0 141 | THEN size 142 | ELSE 0 143 | END)) 144 | ,logsize = sum(convert(BIGINT, CASE 145 | WHEN type <> 0 146 | THEN size 147 | ELSE 0 148 | END)) 149 | FROM sys.database_files 150 | ) AS files 151 | ,( 152 | SELECT reservedpages = sum(a.total_pages) 153 | ,usedpages = sum(a.used_pages) 154 | ,pages = sum(CASE 155 | WHEN it.internal_type IN ( 156 | 202 157 | ,204 158 | ,211 159 | ,212 160 | ,213 161 | ,214 162 | ,215 163 | ,216 164 | ) 165 | THEN 0 166 | WHEN a.type <> 1 167 | THEN a.used_pages 168 | WHEN p.index_id < 2 169 | THEN a.data_pages 170 | ELSE 0 171 | END) 172 | FROM sys.partitions p 173 | INNER JOIN sys.allocation_units a 174 | ON p.partition_id = a.container_id 175 | LEFT JOIN sys.internal_tables it 176 | ON p.object_id = it.object_id 177 | ) AS partitions' 178 | 179 | 180 | DECLARE @alldbstate TABLE ( 181 | 182 | dbname sysname, 183 | DBstatus varchar(55), 184 | R_model varchar(30) 185 | ) 186 | 187 | --select * from sys.master_files 188 | 189 | INSERT INTO @alldbstate (dbname, DBstatus, R_model) 190 | SELECT 191 | name, 192 | CONVERT(varchar(20), DATABASEPROPERTYEX(name, 'status')), 193 | recovery_model_desc 194 | FROM sys.databases 195 | --select * from @dbsize 196 | 197 | INSERT INTO @dbsize (Dbname, dbstatus, Recovery_Model) 198 | SELECT 199 | dbname, 200 | dbstatus, 201 | R_model 202 | FROM @alldbstate 203 | WHERE DBstatus <> 'online' 204 | 205 | INSERT INTO @logsize (Dbname) 206 | SELECT 207 | dbname 208 | FROM @alldbstate 209 | WHERE DBstatus <> 'online' 210 | 211 | INSERT INTO @dbfreesize (name) 212 | SELECT 213 | dbname 214 | FROM @alldbstate 215 | WHERE DBstatus <> 'online' 216 | 217 | SELECT 218 | 219 | d.Dbname AS [Database Name], 220 | d.dbstatus AS [Status], 221 | d.Recovery_Model AS [Recovery Mode], 222 | (file_size_mb + log_file_size_mb) AS [Total DB Size], 223 | fs.Freespace AS [DB Free Space], 224 | d.file_Size_MB AS [MDF Size(MB)], 225 | d.Space_Used_MB AS [MDF Used(MB)], 226 | d.Free_Space_MB AS [MDF Free(MB)], 227 | l.Log_File_Size_MB AS [LDF Size (MB)], 228 | log_Space_Used_MB AS [LDF Used (MB)], 229 | l.log_Free_Space_MB AS [LDF Free (MB)] 230 | FROM @dbsize d 231 | JOIN @logsize l 232 | ON d.Dbname = l.Dbname 233 | JOIN @dbfreesize fs 234 | ON d.Dbname = fs.name 235 | ORDER BY [Database Name] ASC 236 | -------------------------------------------------------------------------------- /T-SQL Scripts/IO Monitoring.sql: -------------------------------------------------------------------------------- 1 | /************************************************* 2 | I got this scripts from SQLskills.com 3 | writtern by Paul Randal. 4 | *************************************************/ 5 | 6 | --==========================================-- 7 | /*** 1. Monitor IO on databases files from 8 | the server starting or Database Online ***/ 9 | --==========================================-- 10 | 11 | SELECT 12 | [ReadLatency] = 13 | CASE 14 | WHEN [num_of_reads] = 0 THEN 0 15 | ELSE ([io_stall_read_ms] / [num_of_reads]) 16 | END, 17 | [WriteLatency] = 18 | CASE 19 | WHEN [num_of_writes] = 0 THEN 0 20 | ELSE ([io_stall_write_ms] / [num_of_writes]) 21 | END, 22 | [Latency] = 23 | CASE 24 | WHEN ([num_of_reads] = 0 AND 25 | [num_of_writes] = 0) THEN 0 26 | ELSE ([io_stall] / ([num_of_reads] + [num_of_writes])) 27 | END, 28 | [AvgBPerRead] = 29 | CASE 30 | WHEN [num_of_reads] = 0 THEN 0 31 | ELSE ([num_of_bytes_read] / [num_of_reads]) 32 | END, 33 | [AvgBPerWrite] = 34 | CASE 35 | WHEN [num_of_writes] = 0 THEN 0 36 | ELSE ([num_of_bytes_written] / [num_of_writes]) 37 | END, 38 | [AvgBPerTransfer] = 39 | CASE 40 | WHEN ([num_of_reads] = 0 AND 41 | [num_of_writes] = 0) THEN 0 42 | ELSE (([num_of_bytes_read] + [num_of_bytes_written]) / 43 | ([num_of_reads] + [num_of_writes])) 44 | END, 45 | LEFT([mf].[physical_name], 2) AS [Drive], 46 | DB_NAME([vfs].[database_id]) AS [DB], 47 | [mf].[physical_name] 48 | FROM sys.dm_io_virtual_file_stats(NULL, NULL) AS [vfs] 49 | JOIN sys.master_files AS [mf] 50 | ON [vfs].[database_id] = [mf].[database_id] 51 | AND [vfs].[file_id] = [mf].[file_id] 52 | -- WHERE [vfs].[file_id] = 2 -- log files 53 | -- ORDER BY [Latency] DESC 54 | -- ORDER BY [ReadLatency] DESC 55 | ORDER BY [WriteLatency] DESC; 56 | GO 57 | 58 | 59 | 60 | --==========================================-- 61 | /*** 2. Monitor IO For particular period ***/ 62 | --==========================================-- 63 | -- In line 41 you can mention the time period 64 | -- ie; WAITFOR DELAY '00:30:00'; 65 | 66 | 67 | IF EXISTS (SELECT 68 | * 69 | FROM [tempdb].[sys].[objects] 70 | WHERE [name] = N'##Stats1') 71 | DROP TABLE [##Stats1]; 72 | 73 | IF EXISTS (SELECT 74 | * 75 | FROM [tempdb].[sys].[objects] 76 | WHERE [name] = N'##Stats2') 77 | DROP TABLE [##Stats2]; 78 | GO 79 | 80 | SELECT 81 | [database_id], 82 | [file_id], 83 | [num_of_reads], 84 | [io_stall_read_ms], 85 | [num_of_writes], 86 | [io_stall_write_ms], 87 | [io_stall], 88 | [num_of_bytes_read], 89 | [num_of_bytes_written], 90 | [file_handle] INTO ##Stats1 91 | FROM sys.dm_io_virtual_file_stats(NULL, NULL); 92 | GO 93 | 94 | WAITFOR DELAY '00:00:30'; 95 | GO 96 | 97 | SELECT 98 | [database_id], 99 | [file_id], 100 | [num_of_reads], 101 | [io_stall_read_ms], 102 | [num_of_writes], 103 | [io_stall_write_ms], 104 | [io_stall], 105 | [num_of_bytes_read], 106 | [num_of_bytes_written], 107 | [file_handle] INTO ##Stats2 108 | FROM sys.dm_io_virtual_file_stats(NULL, NULL); 109 | GO 110 | 111 | WITH [DiffLatencies] 112 | AS (SELECT 113 | -- Files that weren't in the first snapshot 114 | [ts2].[database_id], 115 | [ts2].[file_id], 116 | [ts2].[num_of_reads], 117 | [ts2].[io_stall_read_ms], 118 | [ts2].[num_of_writes], 119 | [ts2].[io_stall_write_ms], 120 | [ts2].[io_stall], 121 | [ts2].[num_of_bytes_read], 122 | [ts2].[num_of_bytes_written] 123 | FROM [##Stats2] AS [ts2] 124 | LEFT OUTER JOIN [##Stats1] AS [ts1] 125 | ON [ts2].[file_handle] = [ts1].[file_handle] 126 | WHERE [ts1].[file_handle] IS NULL 127 | UNION 128 | SELECT 129 | -- Diff of latencies in both snapshots 130 | [ts2].[database_id], 131 | [ts2].[file_id], 132 | [ts2].[num_of_reads] - [ts1].[num_of_reads] AS [num_of_reads], 133 | [ts2].[io_stall_read_ms] - [ts1].[io_stall_read_ms] AS [io_stall_read_ms], 134 | [ts2].[num_of_writes] - [ts1].[num_of_writes] AS [num_of_writes], 135 | [ts2].[io_stall_write_ms] - [ts1].[io_stall_write_ms] AS [io_stall_write_ms], 136 | [ts2].[io_stall] - [ts1].[io_stall] AS [io_stall], 137 | [ts2].[num_of_bytes_read] - [ts1].[num_of_bytes_read] AS [num_of_bytes_read], 138 | [ts2].[num_of_bytes_written] - [ts1].[num_of_bytes_written] AS [num_of_bytes_written] 139 | FROM [##Stats2] AS [ts2] 140 | LEFT OUTER JOIN [##Stats1] AS [ts1] 141 | ON [ts2].[file_handle] = [ts1].[file_handle] 142 | WHERE [ts1].[file_handle] IS NOT NULL) 143 | SELECT 144 | DB_NAME([vfs].[database_id]) AS [DB], 145 | LEFT([mf].[physical_name], 2) AS [Drive], 146 | [mf].[type_desc], 147 | [num_of_reads] AS [Reads], 148 | [num_of_writes] AS [Writes], 149 | [ReadLatency(ms)] = 150 | CASE 151 | WHEN [num_of_reads] = 0 THEN 0 152 | ELSE ([io_stall_read_ms] / [num_of_reads]) 153 | END, 154 | [WriteLatency(ms)] = 155 | CASE 156 | WHEN [num_of_writes] = 0 THEN 0 157 | ELSE ([io_stall_write_ms] / [num_of_writes]) 158 | END, 159 | /*[Latency] = 160 | CASE WHEN ([num_of_reads] = 0 AND [num_of_writes] = 0) 161 | THEN 0 ELSE ([io_stall] / ([num_of_reads] + [num_of_writes])) END,*/ 162 | [AvgBPerRead] = 163 | CASE 164 | WHEN [num_of_reads] = 0 THEN 0 165 | ELSE ([num_of_bytes_read] / [num_of_reads]) 166 | END, 167 | [AvgBPerWrite] = 168 | CASE 169 | WHEN [num_of_writes] = 0 THEN 0 170 | ELSE ([num_of_bytes_written] / [num_of_writes]) 171 | END, 172 | /*[AvgBPerTransfer] = 173 | CASE WHEN ([num_of_reads] = 0 AND [num_of_writes] = 0) 174 | THEN 0 ELSE 175 | (([num_of_bytes_read] + [num_of_bytes_written]) / 176 | ([num_of_reads] + [num_of_writes])) END,*/ 177 | [mf].[physical_name] 178 | FROM [DiffLatencies] AS [vfs] 179 | JOIN sys.master_files AS [mf] 180 | ON [vfs].[database_id] = [mf].[database_id] 181 | AND [vfs].[file_id] = [mf].[file_id] 182 | -- ORDER BY [ReadLatency(ms)] DESC 183 | ORDER BY [WriteLatency(ms)] DESC; 184 | GO 185 | 186 | -- Cleanup 187 | IF EXISTS (SELECT 188 | * 189 | FROM [tempdb].[sys].[objects] 190 | WHERE [name] = N'##Stats1') 191 | DROP TABLE [##Stats1]; 192 | 193 | IF EXISTS (SELECT 194 | * 195 | FROM [tempdb].[sys].[objects] 196 | WHERE [name] = N'##Stats2') 197 | DROP TABLE [##Stats2]; 198 | GO 199 | -------------------------------------------------------------------------------- /T-SQL Scripts/Memory Monitoring.sql: -------------------------------------------------------------------------------- 1 | --=========================================-- 2 | /*** SQL SERVER MEMORY MONITORING QUERIES ***/ 3 | --=========================================-- 4 | -- Supported Versions SQL server 2008 and higher 5 | ------------------------------------------------- 6 | 7 | ---------------------------------- 8 | /*** 1. System Memory Status ***/ 9 | ---------------------------------- 10 | 11 | SELECT total_physical_memory_kb / 1024 AS 12 | [Total Physical Memory], 13 | available_physical_memory_kb / 1024 AS 14 | [Available Physical Memory], 15 | total_page_file_kb / 1024 AS 16 | [Total Page File (MB)], 17 | available_page_file_kb / 1024 AS 18 | [Available Page File (MB)], 19 | 100 - ( 100 * Cast(available_physical_memory_kb AS DECIMAL(18, 3)) / Cast 20 | ( 21 | total_physical_memory_kb AS DECIMAL(18, 3)) ) AS 22 | 'Percentage Used', 23 | system_memory_state_desc AS 24 | [Memory State] 25 | FROM sys.dm_os_sys_memory; 26 | 27 | 28 | --------------------------------------- 29 | /*** 2. SQL Server's memory Status ***/ 30 | --------------------------------------- 31 | -- this will show how much memory allocated to SQL Server , Buffer pool commit. 32 | 33 | -- SQL server 2008 and earlier 34 | 35 | SELECT 36 | (bpool_committed*8)/1024.0 as [Buffer Pool Committed (MB)], 37 | (bpool_commit_target*8)/1024.0 as [Buffer Pool Committed Targer (MB)] 38 | FROM sys.dm_os_sys_info; 39 | 40 | -- SQL Server 2012 and later 41 | 42 | SELECT 43 | (committed_kb)/1024.0 as [Buffer Pool Committed (MB)], 44 | (committed_target_kb)/1024.0 as [Buffer Pool Committed Targer (MB)] 45 | FROM sys.dm_os_sys_info; 46 | 47 | 48 | ---------------------------------------------- 49 | /*** 3. Physical Memory Used By SQL Sever***/ 50 | ---------------------------------------------- 51 | -- Find the actual Memory used by SQL Server 52 | 53 | select 54 | convert(decimal (5,2),physical_memory_in_use_kb/1048576.0) AS 'Physical Memory Used By SQL (GB)', 55 | convert(decimal (5,2),locked_page_allocations_kb/1048576.0) As 'Locked Page Allocation', 56 | convert(decimal (5,2),available_commit_limit_kb/1048576.0) AS 'Available Commit Limit (GB)', 57 | page_fault_count as 'Page Fault Count' 58 | from sys.dm_os_process_memory; 59 | 60 | ------------------------------------------ 61 | /*** 4. Buffer Pool Usage By Databases ***/ 62 | ------------------------------------------ 63 | 64 | DECLARE @total_buffer INT; 65 | SELECT @total_buffer = cntr_value 66 | FROM sys.dm_os_performance_counters 67 | WHERE RTRIM([object_name]) LIKE '%Buffer Manager' 68 | AND counter_name = 'Database Pages'; 69 | 70 | ;WITH DBBuffer AS 71 | ( 72 | SELECT database_id, 73 | COUNT_BIG(*) AS db_buffer_pages, 74 | SUM (CAST ([free_space_in_bytes] AS BIGINT)) / (1024 * 1024) AS [MBEmpty] 75 | FROM sys.dm_os_buffer_descriptors 76 | GROUP BY database_id 77 | ) 78 | SELECT 79 | CASE [database_id] WHEN 32767 THEN 'Resource DB' ELSE DB_NAME([database_id]) END AS 'DataBase Name', 80 | db_buffer_pages AS 'DB Buffer Pages', 81 | db_buffer_pages / 128 AS 'DB Buffer Pages Used (MB)', 82 | [mbempty] AS 'DB Buffer Pages Free (MB)', 83 | CONVERT(DECIMAL(6,3), db_buffer_pages * 100.0 / @total_buffer) AS 'DB Buffer Percentage' 84 | FROM DBBuffer 85 | ORDER BY [DB Buffer Pages Used (MB)] DESC; 86 | 87 | 88 | -------------------------------------------- 89 | /*** 5. Memory Used By Database Objects ***/ 90 | -------------------------------------------- 91 | 92 | ;WITH obj_buffer 93 | AS (SELECT [Object] = o.NAME, 94 | [Type] = o.type_desc, 95 | [Index] = COALESCE(i.NAME, ''), 96 | [Index_Type] = i.type_desc, 97 | p.[object_id], 98 | p.index_id, 99 | au.allocation_unit_id 100 | FROM sys.partitions AS p 101 | INNER JOIN sys.allocation_units AS au 102 | ON p.hobt_id = au.container_id 103 | INNER JOIN sys.objects AS o 104 | ON p.[object_id] = o.[object_id] 105 | INNER JOIN sys.indexes AS i 106 | ON o.[object_id] = i.[object_id] 107 | AND p.index_id = i.index_id 108 | WHERE au.[type] IN ( 1, 2, 3 ) 109 | AND o.is_ms_shipped = 0) 110 | SELECT obj.[object], 111 | obj.[type], 112 | obj.[index], 113 | obj.index_type, 114 | Count_big(b.page_id) AS 'Buffer Pages', 115 | Count_big(b.page_id) / 128 AS 'Buffer MB' 116 | FROM obj_buffer obj 117 | INNER JOIN sys.dm_os_buffer_descriptors AS b 118 | ON obj.allocation_unit_id = b.allocation_unit_id 119 | WHERE b.database_id = Db_id() 120 | GROUP BY obj.[object], 121 | obj.[type], 122 | obj.[index], 123 | obj.index_type 124 | ORDER BY [buffer pages] DESC; 125 | 126 | 127 | ---------------------------------------- 128 | /*** 6. Costliest Stored Procedures ***/ 129 | ---------------------------------------- 130 | -- Based on Logical reads 131 | 132 | SELECT TOP(25) p.NAME AS [SP Name], 133 | qs.total_logical_reads AS 134 | [TotalLogicalReads], 135 | qs.total_logical_reads / qs.execution_count AS [AvgLogicalReads], 136 | qs.execution_count AS 'execution_count', 137 | qs.total_elapsed_time AS 138 | 'total_elapsed_time', 139 | qs.total_elapsed_time / qs.execution_count AS 'avg_elapsed_time' 140 | , 141 | qs.cached_time AS 142 | 'cached_time' 143 | FROM sys.procedures AS p 144 | INNER JOIN sys.dm_exec_procedure_stats AS qs 145 | ON p.[object_id] = qs.[object_id] 146 | WHERE qs.database_id = Db_id() 147 | ORDER BY qs.total_logical_reads DESC; 148 | 149 | 150 | ---------------------------------------------- 151 | /*** 7. Top Performance Counters – Memory ***/ 152 | ---------------------------------------------- 153 | 154 | -- Get size of SQL Server Page in bytes 155 | DECLARE @pg_size INT, 156 | @Instancename VARCHAR(50) 157 | 158 | SELECT @pg_size = low 159 | FROM master..spt_values 160 | WHERE number = 1 161 | AND type = 'E' 162 | 163 | -- Extract perfmon counters to a temporary table 164 | IF Object_id('tempdb..#perfmon_counters') IS NOT NULL 165 | DROP TABLE #perfmon_counters 166 | 167 | SELECT * 168 | INTO #perfmon_counters 169 | FROM sys.dm_os_performance_counters; 170 | 171 | -- Get SQL Server instance name as it require for capturing Buffer Cache hit Ratio 172 | SELECT @Instancename = LEFT([object_name], ( Charindex(':', [object_name]) )) 173 | FROM #perfmon_counters 174 | WHERE counter_name = 'Buffer cache hit ratio'; 175 | 176 | SELECT * 177 | FROM (SELECT 'Total Server Memory (GB)' AS Counter, 178 | ( cntr_value / 1048576.0 ) AS Value 179 | FROM #perfmon_counters 180 | WHERE counter_name = 'Total Server Memory (KB)' 181 | UNION ALL 182 | SELECT 'Target Server Memory (GB)', 183 | ( cntr_value / 1048576.0 ) 184 | FROM #perfmon_counters 185 | WHERE counter_name = 'Target Server Memory (KB)' 186 | UNION ALL 187 | SELECT 'Connection Memory (MB)', 188 | ( cntr_value / 1024.0 ) 189 | FROM #perfmon_counters 190 | WHERE counter_name = 'Connection Memory (KB)' 191 | UNION ALL 192 | SELECT 'Lock Memory (MB)', 193 | ( cntr_value / 1024.0 ) 194 | FROM #perfmon_counters 195 | WHERE counter_name = 'Lock Memory (KB)' 196 | UNION ALL 197 | SELECT 'SQL Cache Memory (MB)', 198 | ( cntr_value / 1024.0 ) 199 | FROM #perfmon_counters 200 | WHERE counter_name = 'SQL Cache Memory (KB)' 201 | UNION ALL 202 | SELECT 'Optimizer Memory (MB)', 203 | ( cntr_value / 1024.0 ) 204 | FROM #perfmon_counters 205 | WHERE counter_name = 'Optimizer Memory (KB) ' 206 | UNION ALL 207 | SELECT 'Granted Workspace Memory (MB)', 208 | ( cntr_value / 1024.0 ) 209 | FROM #perfmon_counters 210 | WHERE counter_name = 'Granted Workspace Memory (KB) ' 211 | UNION ALL 212 | SELECT 'Cursor memory usage (MB)', 213 | ( cntr_value / 1024.0 ) 214 | FROM #perfmon_counters 215 | WHERE counter_name = 'Cursor memory usage' 216 | AND instance_name = '_Total' 217 | UNION ALL 218 | SELECT 'Total pages Size (MB)', 219 | ( cntr_value * @pg_size ) / 1048576.0 220 | FROM #perfmon_counters 221 | WHERE object_name = @Instancename + 'Buffer Manager' 222 | AND counter_name = 'Total pages' 223 | UNION ALL 224 | SELECT 'Database pages (MB)', 225 | ( cntr_value * @pg_size ) / 1048576.0 226 | FROM #perfmon_counters 227 | WHERE object_name = @Instancename + 'Buffer Manager' 228 | AND counter_name = 'Database pages' 229 | UNION ALL 230 | SELECT 'Free pages (MB)', 231 | ( cntr_value * @pg_size ) / 1048576.0 232 | FROM #perfmon_counters 233 | WHERE object_name = @Instancename + 'Buffer Manager' 234 | AND counter_name = 'Free pages' 235 | UNION ALL 236 | SELECT 'Reserved pages (MB)', 237 | ( cntr_value * @pg_size ) / 1048576.0 238 | FROM #perfmon_counters 239 | WHERE object_name = @Instancename + 'Buffer Manager' 240 | AND counter_name = 'Reserved pages' 241 | UNION ALL 242 | SELECT 'Stolen pages (MB)', 243 | ( cntr_value * @pg_size ) / 1048576.0 244 | FROM #perfmon_counters 245 | WHERE object_name = @Instancename + 'Buffer Manager' 246 | AND counter_name = 'Stolen pages' 247 | UNION ALL 248 | SELECT 'Cache Pages (MB)', 249 | ( cntr_value * @pg_size ) / 1048576.0 250 | FROM #perfmon_counters 251 | WHERE object_name = @Instancename + 'Plan Cache' 252 | AND counter_name = 'Cache Pages' 253 | AND instance_name = '_Total' 254 | UNION ALL 255 | SELECT 'Page Life Expectency in seconds', 256 | cntr_value 257 | FROM #perfmon_counters 258 | WHERE object_name = @Instancename + 'Buffer Manager' 259 | AND counter_name = 'Page life expectancy' 260 | UNION ALL 261 | SELECT 'Free list stalls/sec', 262 | cntr_value 263 | FROM #perfmon_counters 264 | WHERE object_name = @Instancename + 'Buffer Manager' 265 | AND counter_name = 'Free list stalls/sec' 266 | UNION ALL 267 | SELECT 'Checkpoint pages/sec', 268 | cntr_value 269 | FROM #perfmon_counters 270 | WHERE object_name = @Instancename + 'Buffer Manager' 271 | AND counter_name = 'Checkpoint pages/sec' 272 | UNION ALL 273 | SELECT 'Lazy writes/sec', 274 | cntr_value 275 | FROM #perfmon_counters 276 | WHERE object_name = @Instancename + 'Buffer Manager' 277 | AND counter_name = 'Lazy writes/sec' 278 | UNION ALL 279 | SELECT 'Memory Grants Pending', 280 | cntr_value 281 | FROM #perfmon_counters 282 | WHERE object_name = @Instancename + 'Memory Manager' 283 | AND counter_name = 'Memory Grants Pending' 284 | UNION ALL 285 | SELECT 'Memory Grants Outstanding', 286 | cntr_value 287 | FROM #perfmon_counters 288 | WHERE object_name = @Instancename + 'Memory Manager' 289 | AND counter_name = 'Memory Grants Outstanding' 290 | UNION ALL 291 | SELECT 'process_physical_memory_low', 292 | process_physical_memory_low 293 | FROM sys.dm_os_process_memory WITH (nolock) 294 | UNION ALL 295 | SELECT 'process_virtual_memory_low', 296 | process_virtual_memory_low 297 | FROM sys.dm_os_process_memory WITH (nolock) 298 | UNION ALL 299 | SELECT 'Max_Server_Memory (MB)', 300 | [value_in_use] 301 | FROM sys.configurations 302 | WHERE [name] = 'max server memory (MB)' 303 | UNION ALL 304 | SELECT 'Min_Server_Memory (MB)', 305 | [value_in_use] 306 | FROM sys.configurations 307 | WHERE [name] = 'min server memory (MB)' 308 | UNION ALL 309 | SELECT 'BufferCacheHitRatio', 310 | ( a.cntr_value * 1.0 / b.cntr_value ) * 100.0 311 | FROM sys.dm_os_performance_counters a 312 | JOIN (SELECT cntr_value, 313 | object_name 314 | FROM sys.dm_os_performance_counters 315 | WHERE counter_name = 'Buffer cache hit ratio base' 316 | AND object_name = @Instancename + 'Buffer Manager') 317 | b 318 | ON a.object_name = b.object_name 319 | WHERE a.counter_name = 'Buffer cache hit ratio' 320 | AND a.object_name = @Instancename + 'Buffer Manager') AS D; 321 | 322 | -------------------------------------------------------------------------------- /T-SQL Scripts/Session Monitoring.sql: -------------------------------------------------------------------------------- 1 | /******************************************************************************************** 2 | 3 | *** Session Momitoring using sp_whoisactive *** 4 | ------------------------------------------------ 5 | 6 | I have prepared this script to monitor currently running sessions 7 | in different scenarios like CPU, Blocking, So first you need to 8 | create sp_whoisactive stored procedure, please downad it from the link, 9 | 10 | https://github.com/SqlAdmin/AwesomeSQLServer/blob/master/T-SQL%20Scripts/sp_whoisactive.sql 11 | 12 | *******************************************************************************************/ 13 | 14 | 15 | -- To get overall info about current sessions 16 | 17 | EXEC sp_whoisactive 18 | 19 | 20 | ------------------------------------------------ 21 | /*** 1. Currently running sessions CPU time ***/ 22 | ------------------------------------------------ 23 | 24 | EXEC sp_WhoIsActive @get_plans = 1, 25 | @get_avg_time = 1, 26 | @output_column_list = '[dd%][session_id][database_name][cpu%][sql_text]', 27 | @sort_order = '[start_time] ASC' 28 | 29 | 30 | ----------------------------------------------------------- 31 | /*** 2. Currently running sessions memory pages usage ***/ 32 | ----------------------------------------------------------- 33 | 34 | EXEC sp_WhoIsActive @output_column_list = '[dd%][session_id][database_name][sql_text][used_memory][tempdb_allocations][tempdb_current]', 35 | @sort_order = '[start_time] ASC'; 36 | 37 | 38 | -------------------------------------------------------------- 39 | /*** 3. Currently running query, batch and execution plan ***/ 40 | -------------------------------------------------------------- 41 | 42 | EXEC sp_WhoIsActive @get_full_inner_text = 1, 43 | @get_plans = 1, 44 | @get_outer_command = 1, 45 | @output_column_list = '[dd%][session_id][database_name][sql_text][sql_command][query_plan]', 46 | @sort_order = '[start_time] ASC'; 47 | 48 | 49 | ----------------------------------------------------------------- 50 | /*** 4. Monitor Transaction log writing process of a session ***/ 51 | ----------------------------------------------------------------- 52 | 53 | EXEC sp_WhoIsActive @get_transaction_info = 1, 54 | @output_column_list = '[dd%][session_id][database_name][tran_log_writes]', 55 | @sort_order = '[start_time] ASC'; 56 | 57 | -------------------------------------------------------------------------------- /T-SQL Scripts/Wait stat Monitoring.sql: -------------------------------------------------------------------------------- 1 | /********************************************** 2 | Monitoring Wait stats 3 | ***********************************************/ 4 | 5 | --========================================-- 6 | /*** 1. Monitor Current sessions wait ***/ 7 | --========================================-- 8 | 9 | 10 | SELECT 11 | dm_ws.wait_duration_ms, 12 | dm_ws.wait_type, 13 | dm_es.status, 14 | dm_t.TEXT, 15 | dm_qp.query_plan, 16 | dm_ws.session_ID, 17 | dm_es.cpu_time, 18 | dm_es.memory_usage, 19 | dm_es.logical_reads, 20 | dm_es.total_elapsed_time, 21 | dm_es.program_name, 22 | DB_NAME(dm_r.database_id) DatabaseName, 23 | -- Optional columns 24 | dm_ws.blocking_session_id, 25 | dm_r.wait_resource, 26 | dm_es.login_name, 27 | dm_r.command, 28 | dm_r.last_wait_type 29 | FROM sys.dm_os_waiting_tasks dm_ws 30 | INNER JOIN sys.dm_exec_requests dm_r 31 | ON dm_ws.session_id = dm_r.session_id 32 | INNER JOIN sys.dm_exec_sessions dm_es 33 | ON dm_es.session_id = dm_r.session_id 34 | CROSS APPLY sys.dm_exec_sql_text(dm_r.sql_handle) dm_t 35 | CROSS APPLY sys.dm_exec_query_plan(dm_r.plan_handle) dm_qp 36 | WHERE dm_es.is_user_process = 1 37 | GO 38 | 39 | --===========================================-- 40 | /*** 2. Monior waits for a specific period ***/ 41 | --===========================================-- 42 | 43 | -- Got this from SQLskills.com 44 | -- You can set the time limit in > WAITFOR DELAY '00:30:00'; 45 | 46 | IF EXISTS (SELECT 47 | * 48 | FROM [tempdb].[sys].[objects] 49 | WHERE [name] = N'##SQLskillsStats1') 50 | DROP TABLE [##SQLskillsStats1]; 51 | 52 | IF EXISTS (SELECT 53 | * 54 | FROM [tempdb].[sys].[objects] 55 | WHERE [name] = N'##SQLskillsStats2') 56 | DROP TABLE [##SQLskillsStats2]; 57 | GO 58 | 59 | SELECT 60 | [wait_type], 61 | [waiting_tasks_count], 62 | [wait_time_ms], 63 | [max_wait_time_ms], 64 | [signal_wait_time_ms] INTO ##SQLskillsStats1 65 | FROM sys.dm_os_wait_stats; 66 | GO 67 | 68 | WAITFOR DELAY '00:30:00'; 69 | GO 70 | 71 | SELECT 72 | [wait_type], 73 | [waiting_tasks_count], 74 | [wait_time_ms], 75 | [max_wait_time_ms], 76 | [signal_wait_time_ms] INTO ##SQLskillsStats2 77 | FROM sys.dm_os_wait_stats; 78 | GO 79 | 80 | WITH [DiffWaits] 81 | AS (SELECT 82 | -- Waits that weren't in the first snapshot 83 | [ts2].[wait_type], 84 | [ts2].[wait_time_ms], 85 | [ts2].[signal_wait_time_ms], 86 | [ts2].[waiting_tasks_count] 87 | FROM [##SQLskillsStats2] AS [ts2] 88 | LEFT OUTER JOIN [##SQLskillsStats1] AS [ts1] 89 | ON [ts2].[wait_type] = [ts1].[wait_type] 90 | WHERE [ts1].[wait_type] IS NULL 91 | AND [ts2].[wait_time_ms] > 0 92 | UNION 93 | SELECT 94 | -- Diff of waits in both snapshots 95 | [ts2].[wait_type], 96 | [ts2].[wait_time_ms] - [ts1].[wait_time_ms] AS [wait_time_ms], 97 | [ts2].[signal_wait_time_ms] - [ts1].[signal_wait_time_ms] AS [signal_wait_time_ms], 98 | [ts2].[waiting_tasks_count] - [ts1].[waiting_tasks_count] AS [waiting_tasks_count] 99 | FROM [##SQLskillsStats2] AS [ts2] 100 | LEFT OUTER JOIN [##SQLskillsStats1] AS [ts1] 101 | ON [ts2].[wait_type] = [ts1].[wait_type] 102 | WHERE [ts1].[wait_type] IS NOT NULL 103 | AND [ts2].[waiting_tasks_count] - [ts1].[waiting_tasks_count] > 0 104 | AND [ts2].[wait_time_ms] - [ts1].[wait_time_ms] > 0), 105 | [Waits] 106 | AS (SELECT 107 | [wait_type], 108 | [wait_time_ms] / 1000.0 AS [WaitS], 109 | ([wait_time_ms] - [signal_wait_time_ms]) / 1000.0 AS [ResourceS], 110 | [signal_wait_time_ms] / 1000.0 AS [SignalS], 111 | [waiting_tasks_count] AS [WaitCount], 112 | 100.0 * [wait_time_ms] / SUM([wait_time_ms]) OVER () AS [Percentage], 113 | ROW_NUMBER() OVER (ORDER BY [wait_time_ms] DESC) AS [RowNum] 114 | FROM [DiffWaits] 115 | WHERE [wait_type] NOT IN ( 116 | N'BROKER_EVENTHANDLER', N'BROKER_RECEIVE_WAITFOR', 117 | N'BROKER_TASK_STOP', N'BROKER_TO_FLUSH', 118 | N'BROKER_TRANSMITTER', N'CHECKPOINT_QUEUE', 119 | N'CHKPT', N'CLR_AUTO_EVENT', 120 | N'CLR_MANUAL_EVENT', N'CLR_SEMAPHORE', 121 | N'DBMIRROR_DBM_EVENT', N'DBMIRROR_EVENTS_QUEUE', 122 | N'DBMIRROR_WORKER_QUEUE', N'DBMIRRORING_CMD', 123 | N'DIRTY_PAGE_POLL', N'DISPATCHER_QUEUE_SEMAPHORE', 124 | N'EXECSYNC', N'FSAGENT', 125 | N'FT_IFTS_SCHEDULER_IDLE_WAIT', N'FT_IFTSHC_MUTEX', 126 | N'HADR_CLUSAPI_CALL', N'HADR_FILESTREAM_IOMGR_IOCOMPLETION', 127 | N'HADR_LOGCAPTURE_WAIT', N'HADR_NOTIFICATION_DEQUEUE', 128 | N'HADR_TIMER_TASK', N'HADR_WORK_QUEUE', 129 | N'KSOURCE_WAKEUP', N'LAZYWRITER_SLEEP', 130 | N'LOGMGR_QUEUE', N'ONDEMAND_TASK_QUEUE', 131 | N'PWAIT_ALL_COMPONENTS_INITIALIZED', 132 | N'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP', 133 | N'QDS_SHUTDOWN_QUEUE', 134 | N'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP', 135 | N'REQUEST_FOR_DEADLOCK_SEARCH', N'RESOURCE_QUEUE', 136 | N'SERVER_IDLE_CHECK', N'SLEEP_BPOOL_FLUSH', 137 | N'SLEEP_DBSTARTUP', N'SLEEP_DCOMSTARTUP', 138 | N'SLEEP_MASTERDBREADY', N'SLEEP_MASTERMDREADY', 139 | N'SLEEP_MASTERUPGRADED', N'SLEEP_MSDBSTARTUP', 140 | N'SLEEP_SYSTEMTASK', N'SLEEP_TASK', 141 | N'SLEEP_TEMPDBSTARTUP', N'SNI_HTTP_ACCEPT', 142 | N'SP_SERVER_DIAGNOSTICS_SLEEP', N'SQLTRACE_BUFFER_FLUSH', 143 | N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', 144 | N'SQLTRACE_WAIT_ENTRIES', N'WAIT_FOR_RESULTS', 145 | N'WAITFOR', N'WAITFOR_TASKSHUTDOWN', 146 | N'WAIT_XTP_HOST_WAIT', N'WAIT_XTP_OFFLINE_CKPT_NEW_LOG', 147 | N'WAIT_XTP_CKPT_CLOSE', N'XE_DISPATCHER_JOIN', 148 | N'XE_DISPATCHER_WAIT', N'XE_TIMER_EVENT')) 149 | SELECT 150 | [W1].[wait_type] AS [WaitType], 151 | CAST([W1].[WaitS] AS decimal(16, 2)) AS [Wait_S], 152 | CAST([W1].[ResourceS] AS decimal(16, 2)) AS [Resource_S], 153 | CAST([W1].[SignalS] AS decimal(16, 2)) AS [Signal_S], 154 | [W1].[WaitCount] AS [WaitCount], 155 | CAST([W1].[Percentage] AS decimal(5, 2)) AS [Percentage], 156 | CAST(([W1].[WaitS] / [W1].[WaitCount]) AS decimal(16, 4)) AS [AvgWait_S], 157 | CAST(([W1].[ResourceS] / [W1].[WaitCount]) AS decimal(16, 4)) AS [AvgRes_S], 158 | CAST(([W1].[SignalS] / [W1].[WaitCount]) AS decimal(16, 4)) AS [AvgSig_S] 159 | FROM [Waits] AS [W1] 160 | INNER JOIN [Waits] AS [W2] 161 | ON [W2].[RowNum] <= [W1].[RowNum] 162 | GROUP BY [W1].[RowNum], 163 | [W1].[wait_type], 164 | [W1].[WaitS], 165 | [W1].[ResourceS], 166 | [W1].[SignalS], 167 | [W1].[WaitCount], 168 | [W1].[Percentage] 169 | HAVING SUM([W2].[Percentage]) - [W1].[Percentage] < 95; -- percentage threshold 170 | GO 171 | 172 | -- Cleanup 173 | IF EXISTS (SELECT 174 | * 175 | FROM [tempdb].[sys].[objects] 176 | WHERE [name] = N'##SQLskillsStats1') 177 | DROP TABLE [##SQLskillsStats1]; 178 | 179 | IF EXISTS (SELECT 180 | * 181 | FROM [tempdb].[sys].[objects] 182 | WHERE [name] = N'##SQLskillsStats2') 183 | DROP TABLE [##SQLskillsStats2]; 184 | GO 185 | 186 | --------------------------------------------------------------------------------