Detecting CPU Pressure

There are a few different ways to detect CPU pressure, for example, Performance Monitor or SQL Profiler, but in this tip we’ll discuss the wait type SOS_SCHEDULER_YIELD and the DMV sys.dm_os_schedulers.

Some of you might have seen the wait type SOS_SCHEDULER_YIELD and wondered what in the world is this? Books Online (BOL) describes this wait type as:

Occurs when a task voluntarily yields the scheduler for other tasks to execute. During this wait the task is waiting for its quantum to be renewed.

SOS_SCHEDULER_YIELD is a fairly common wait type and occurs when there is CPU pressure. SQL Server runs multiple threads and tries to allow all threads to run without problems. However, if all the threads are busy on each scheduler and can’t let other threads run, it will yield itself for another thread, which in turn creates the SOS_SCHEDULER_YIELD wait type.

You can see the top wait stats and the percentage of waits at the current point in time by running the following query by Tim Ford and Glenn Berry.

WITH Waits AS 
( 
SELECT 
wait_type, 
wait_time_ms / 1000. AS wait_time_s, 
100. * wait_time_ms / SUM(wait_time_ms) OVER() AS pct, 
ROW_NUMBER() OVER(ORDER BY wait_time_ms DESC) AS rn 
FROM sys.dm_os_wait_stats 
WHERE wait_type 
NOT IN 
('CLR_SEMAPHORE', 'LAZYWRITER_SLEEP', 'RESOURCE_QUEUE', 
'SLEEP_TASK', 'SLEEP_SYSTEMTASK', 'SQLTRACE_BUFFER_FLUSH', 'WAITFOR', 
'CLR_AUTO_EVENT', 'CLR_MANUAL_EVENT') 
) -- filter out additional irrelevant waits 
SELECT W1.wait_type, 
CAST(W1.wait_time_s AS DECIMAL(12, 2)) AS wait_time_s, 
CAST(W1.pct AS DECIMAL(12, 2)) AS pct, 
CAST(SUM(W2.pct) AS DECIMAL(12, 2)) AS running_pct 
FROM Waits AS W1 
INNER JOIN Waits AS W2 ON W2.rn <= W1.rn 
GROUP BY W1.rn, 
W1.wait_type, 
W1.wait_time_s, 
W1.pct 
HAVING SUM(W2.pct) - W1.pct < 95; -- percentage threshold;

After running this query on one of my servers I can see that only 2.22% of my waits are due to CPU pressure so I can rule that out as a cause for poor performance. (This is only current since the last SQL Service restart):

SQL Freelancer SQL Server CPU Pressure DMV

If you see a high percentage of this wait type then one way of troubleshooting this is to use the DMV sys.dm_os_schedulers. BOL describes sys.dm_os_schedulers as:

Returns one row per scheduler in SQL Server where each scheduler is mapped to an individual processor. Use this view to monitor the condition of a scheduler or to identify runaway tasks.

This DMV has several columns including number or workers, active tasks, and the status of each scheduler, etc., which can help troubleshoot certain problems, but the most important column is the one used for measuring queued tasks, the runnable_tasks_count column. This column displays the count of tasks yielding to other tasks resulting in a SOS_SCHEDULER_YIELD wait type. If this column is frequently greater than 0 then CPU pressure may be present and blocking may occur.

To see an average of current tasks and current waiting tasks you can use the following query:

SELECT AVG(current_tasks_count) AS [Avg Current Task], 
AVG(runnable_tasks_count) AS [Avg Wait Task]
FROM sys.dm_os_schedulers
WHERE scheduler_id < 255
AND status = 'VISIBLE ONLINE'

SQL Freelancer SQL Server CPU Pressure DMV
Click here to view the rest of this post.

Report to Capture Table Growth Statistics for SQL Server

There are a few tools that monitor table size growth, but with the use of sp_spaceused and SQL Server Reporting Services (SSRS) you can make custom reports.

Using sp_spaceused

The system stored procedure sp_spaceused displays the number of rows, disk space reserved, and disk space used by a table, indexed view, or Service Broker queue in the current database in an object is provided or it displays the disk space reserved and used by the whole database.

This procedure, sp_spaceused can be used at the database or table level. For example, sp_spaceused at the database level returns the following:

SQL Freelancer SQL Server SSRS Table Growth
And sp_spaceused at the table level displays:
SQL Freelancer SQL Server SSRS Table Growth

 

Creating the Report

To create our custom report, first we will need to create a table that will store the data from sp_spaceused. For this example, I’ll create a table named TableSizeGrowth.

CREATE TABLE [dbo].[TableSizeGrowth](
[id] [int] IDENTITY(1,1) NOT NULL,
[table_schema] [nvarchar](256) NULL,
[table_name] [nvarchar](256) NULL,
[table_rows] [int] NULL,
[reserved_space] [int] NULL,
[data_space] [int] NULL,
[index_space] [int] NULL,
[unused_space] [int] NULL,
[date] [datetime] NULL
) ON [PRIMARY]

I’m also going to add a default constraint that will automatically update the date column to the current date for each new row.

ALTER TABLE [dbo].[TableSizeGrowth] ADD CONSTRAINT [DF_TableSizeGrowth_date]  
DEFAULT (dateadd(day,(0),datediff(day,(0),getdate()))) FOR [date]
GO

Next, we need to create a stored procedure that moves the data from sp_spaceused to the table we created above. I have put comments throughout the stored procedure to help you figure out what is going on. Also make sure you change the table names to match your tables. For this example, I want to monitor HumanResources.Employee, Production.Product, and Purchasing.Vendor tables.

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE PROCEDURE [dbo].[sp_TableSizeGrowth] 
AS
BEGIN
 SET NOCOUNT ON

 --DECLARE VARIABLES
 DECLARE
 @max INT,
 @min INT,
 @table_name NVARCHAR(256),
 @table_schema NVARCHAR(256),
 @sql NVARCHAR(4000)

 --DECLARE TABLE VARIABLE
 DECLARE @table TABLE(
 id INT IDENTITY(1,1) PRIMARY KEY,
 table_name NVARCHAR(256),
 table_schema NVARCHAR(256))

 --CREATE TEMP TABLE THAT STORES INFORMATION FROM SP_SPACEUSED
 IF (SELECT OBJECT_ID('tempdb..#results')) IS NOT NULL
 BEGIN
  DROP TABLE #results
 END

 CREATE TABLE #results
 (
  [table_schema] [nvarchar](256) NULL,
  [table_name] [nvarchar](256) NULL,
  [table_rows] [int] NULL,
  [reserved_space] [nvarchar](55) NULL,
  [data_space] [nvarchar](55) NULL,
  [index_space] [nvarchar](55) NULL,
  [unused_space] [nvarchar](55) NULL
 )

 --LOOP THROUGH STATISTICS FOR EACH TABLE
 INSERT @table(table_schema, table_name)
 SELECT  
  table_schema, table_name
 FROM
  information_schema.tables 
 WHERE table_schema + '.' + table_name IN ('HumanResources.Employee','Production.Product', 'Purchasing.Vendor') --INSERT TABLE NAMES TO MONITOR

 SELECT
  @min = 1,
  @max = (SELECT MAX(id) FROM @table)

 WHILE @min = @max
 BEGIN
  SELECT 
   @table_name = table_name,
   @table_schema = table_schema
  FROM
   @table
  WHERE
   id = @min

  --DYNAMIC SQL
  SELECT @sql = 'EXEC sp_spaceused ''[' + @table_schema + '].[' + @table_name + ']'''

  --INSERT RESULTS FROM SP_SPACEUSED TO TEMP TABLE
  INSERT #results(table_name, table_rows, reserved_space, data_space, index_space, unused_space)
  EXEC (@sql)

  --UPDATE SCHEMA NAME
  UPDATE #results
  SET table_schema = @table_schema
  WHERE table_name = @table_name
  SELECT @min = @min + 1
 END

 --REMOVE "KB" FROM RESULTS FOR REPORTING (GRAPH) PURPOSES
 UPDATE #results SET data_space = SUBSTRING(data_space, 1, (LEN(data_space)-3))
 UPDATE #results SET reserved_space = SUBSTRING(reserved_space, 1, (LEN(reserved_space)-3))
 UPDATE #results SET index_space = SUBSTRING(index_space, 1, (LEN(index_space)-3))
 UPDATE #results SET unused_space = SUBSTRING(unused_space, 1, (LEN(unused_space)-3))

 --INSERT RESULTS INTO TABLESIZEGROWTH
 INSERT INTO TableSizeGrowth (table_schema, table_name, table_rows, reserved_space, data_space, index_space, unused_space)
 SELECT * FROM #results

 DROP TABLE #results
END

Now that the stored procedure has been created, let’s go ahead and execute it.

Once the stored procedure finishes we can view the table:

SQL Freelancer SQL Server SSRS Table Growth
Click here to view the rest of this post.

Finding what port SQL Server is listening on

SQL Server communicates over TCP/IP and listens for incoming connections over what is called a port. The default TCP/IP port for SQL Server is 1433. The port doesn’t have to be 1433, but 1433 is the official Internet Assigned Number Authority (IANA) socket number for SQL Server. (http://support.microsoft.com/kb/287932)

Named instances are configured for dynamic ports. This means when the SQL Server service is started it selects a random port. Best practice is to configure named instances to listen on a specific port.

You need to know what port your SQL Server is using so you can allow the ports through the firewall otherwise you can run into connection problems between the client and the server.

There are a few different ways to find the port number that SQL Server is listening on. Below you will find T-SQL statements that will allow you to find the port number for default and named instances.


--SQL Server 2000 Default Instance 
DECLARE @tcp_port nvarchar(5)

EXEC xp_regread
 @rootkey    =    'HKEY_LOCAL_MACHINE',
 @key        =    'SOFTWARE\Microsoft\MSSQLServer\MSSQLServer\SuperSocketNetLib\TCP',
 @value_name    =    'TcpPort',
 @value        =    @tcp_port OUTPUT

select @tcp_port

--SQL Server 2000 Named Instance
DECLARE @tcp_port nvarchar(5)

EXEC xp_regread
 @rootkey    =    'HKEY_LOCAL_MACHINE',
 @key        =     'SOFTWARE\Microsoft\Microsoft SQL Server(InstanceName)\MSSQLServer\SuperSocketNetLib\TCP',
 @value_name    =    'TcpPort',
 @value        =    @tcp_port OUTPUT

select @tcp_port

--SQL Server 2005 Default Instance
DECLARE @tcp_port nvarchar(5)

EXEC xp_regread
 @rootkey    =    'HKEY_LOCAL_MACHINE',
 @key        =    'SOFTWARE\Microsoft\Microsoft SQL Server\MSSQL.1\MSSQLServer\SuperSocketNetLib\TCP\IPAll',
 @value_name    =    'TcpPort',
 @value        =    @tcp_port OUTPUT

select @tcp_port

--SQL Server 2005 Named Instance
DECLARE @tcp_port nvarchar(5)

EXEC xp_regread
 @rootkey    =    'HKEY_LOCAL_MACHINE',
 @key        =    'SOFTWARE\Microsoft\Microsoft SQL Server\MSSQL.(#)\MSSQLServer\SuperSocketNetLib\TCP\IPAll',
 @value_name    =    'TcpPort',
 @value        =    @tcp_port OUTPUT

select @tcp_port

--SQL Server 2008 R2 Default Instance
DECLARE @tcp_port nvarchar(5)

EXEC xp_regread
 @rootkey    =    'HKEY_LOCAL_MACHINE',
 @key        =    'SOFTWARE\Microsoft\Microsoft SQL Server\MSSQL10_50.MSSQLSERVER\MSSQLServer\SuperSocketNetLib\TCP\IPAll',
 @value_name    =    'TcpPort',
 @value        =    @tcp_port OUTPUT

select @tcp_port

--SQL Server 2008 R2 Named Instance
DECLARE @tcp_port nvarchar(5)

EXEC xp_regread
 @rootkey    =    'HKEY_LOCAL_MACHINE',
 @key        =    'SOFTWARE\Microsoft\Microsoft SQL Server\MSSQL10_50.(InstanceName)\MSSQLServer\SuperSocketNetLib\TCP\IPAll',
 @value_name    =    'TcpPort',
 @value        =    @tcp_port OUTPUT

select @tcp_port

 --SQL Server 2012 Default Instance
DECLARE @tcp_port nvarchar(5)

EXEC xp_regread
 @rootkey    =    'HKEY_LOCAL_MACHINE',
 @key        =    'SOFTWARE\Microsoft\Microsoft SQL Server\MSSQL11.MSSQLSERVER\MSSQLServer\SuperSocketNetLib\TCP\IPAll',
 @value_name    =    'TcpPort',
 @value        =    @tcp_port OUTPUT

select @tcp_port

--SQL Server 2012 Named Instance
DECLARE @tcp_port nvarchar(5)

EXEC xp_regread
 @rootkey    =    'HKEY_LOCAL_MACHINE',
 @key        =    'SOFTWARE\Microsoft\Microsoft SQL Server\MSSQL11.(InstanceName)\MSSQLServer\SuperSocketNetLib\TCP\IPAll',
 @value_name    =    'TcpPort',
 @value        =    @tcp_port OUTPUT

select @tcp_port

Managing SQL Server Extended Events in Management Studio

SQL Server 2012 introduces a GUI in SQL Server Management Studio to create and manage extended events. Prior to the SQL Server 2012 integration, Extended Events could only be created using T-SQL. In this tip, I’ll show you step by step process on how to create a simple Extended Event in SQL Server 2012 using the new GUI in SQL Server Management Studio.

Creating an Extended Event has never been easier with SQL Server 2012. Open SSMS, and drilldown to Management, Extended Events, Sessions as shown in the image below.  By default, you should see an AlwaysOn_health and a system_health session already created. You will notice the AlwaysOn_health session is disabled and the system_health session is running. The system_health session collects system data that you can use to help troubleshoot performance issues. For the most part, SQL Server Extended Events use very little resources.

SQL Freelancer SQL Server Extended Events Management Studio SSMS
There are two ways to create a session. Right click on the Sessions folder and you can choose New Session or New Session Wizard. In this tip, we’ll step through using the wizard.

SQL Freelancer SQL Server Extended Events Management Studio SSMS

After clicking New Session Wizard, an Introduction window will appear that will give you a brief introduction. Click the “Next” button to continue.

The next window, Set Session Properties, is where you can specify the session name and whether or not you want the session to start on server start-up. In this tip, I’ll name the session DB Monitor and choose to start the event session at server start-up. Click the “Next” button to continue.

SQL Freelancer SQL Server Extended Events Management Studio SSMS
The next screen will allow us to choose a preconfigured template or create our own. If you’ve ever used SQL Server Profiler’s built in template, these function the same way. In this tip, we’ll create our own. Choose the “Do not use a template” option and click the “Next” button to continue.

SQL Freelancer SQL Server Extended Events Management Studio SSMS
The “Select Events To Capture” window is an important one. This is where we select the events we want to capture. For this example, I want to monitor when my DB goes offline and when it becomes available, so I’ll choose the events that relate to this: database_attached, database_created, database_detached, database_started, and database_stopped. Once you select the events from the “Event library” (on the left), click the right arrow to move them to the “Selected events” (on the right). Click the “Next” button to continue.

SQL Freelancer SQL Server Extended Events Management Studio SSMS

Click here to view the rest of this post.

sp_who

There are numerous ways you can view blocking information but I’ll share the most popular in sp_who and sp_who2.

Like their name implies sp_who and sp_who2 give information about “who” is in your SQL Server as well as other useful information including processes and blocking info.

Below is an example of sp_who running against a SQL Server:

SQL Freelancer SQL Server sp_who

As you can see, sp_who will return SPID, status, loginname, blk, dbname, etc.

spid – The system process ID.
ecid – The execution context ID of a given thread associated with a specific SPID.
status – The process status.
loginame – The login name associated with the particular process.
hostname – The host or computer name for each process.
blk – The system process ID for the blocking process, if one exists. Otherwise, this column is zero.

When a transaction associated with a given SPID is blocked by an orphan distributed transaction, this column will return a ‘-2′ for the blocking orphan transaction.
dbname – The database used by the process.
cmd – The SQL Server command (Transact-SQL statement, SQL Server internal engine process, and so on) executing for the process.