sqlskills-logo-2015-white.png

SQL Server Diagnostic Information Queries Detailed, Day 23

For Day 23 of this series, we start out with Query #52, which is SP Logical Writes. This query retrieves information from the sys.procedures object catalog view and the sys.dm_exec_procedure_stats dynamic management view about the cached stored procedures that have the highest cumulative total logical writes in the current database. Query #52 is shown in Figure 1.

   1: -- Top Cached SPs By Total Logical Writes (Query 52) (SP Logical Writes)

   2: -- Logical writes relate to both memory and disk I/O pressure 

   3: SELECT TOP(25) p.name AS [SP Name], qs.total_logical_writes AS [TotalLogicalWrites], 

   4: qs.total_logical_writes/qs.execution_count AS [AvgLogicalWrites], qs.execution_count,

   5: ISNULL(qs.execution_count/DATEDIFF(Minute, qs.cached_time, GETDATE()), 0) AS [Calls/Minute],

   6: qs.total_elapsed_time, qs.total_elapsed_time/qs.execution_count AS [avg_elapsed_time], 

   7: qs.cached_time

   8: FROM sys.procedures AS p WITH (NOLOCK)

   9: INNER JOIN sys.dm_exec_procedure_stats AS qs WITH (NOLOCK)

  10: ON p.[object_id] = qs.[object_id]

  11: WHERE qs.database_id = DB_ID()

  12: AND qs.total_logical_writes > 0

  13: ORDER BY qs.total_logical_writes DESC OPTION (RECOMPILE);

  14:  

  15: -- This helps you find the most expensive cached stored procedures from a write I/O perspective

  16: -- You should look at this if you see signs of I/O pressure or of memory pressure

Figure 1: Query #52 SP Logical Writes

This query lets you see which cached stored procedures have the highest number cumulative logical writes in this database. This helps you see which stored procedures are causing the most write I/O pressure for this database. If you are seeing any signs of high write I/O latency on your instance of SQL Server (and if this database is causing a lot of I/O activity, as shown in Query #31), then the results of this query can help you figure out which stored procedures are the biggest offenders.

 

Query #53 is Top IO Statements. This query retrieves information from the sys.dm_exec_query_stats dynamic management and the sys.dm_exec_sql_text dynamic management function about the cached query statements that have the highest average I/O activity in the current database. Query #53 is shown in Figure 2.

   1: -- Lists the top statements by average input/output usage for the current database  (Query 53) (Top IO Statements)

   2: SELECT TOP(50) OBJECT_NAME(qt.objectid, dbid) AS [SP Name],

   3: (qs.total_logical_reads + qs.total_logical_writes) /qs.execution_count AS [Avg IO], qs.execution_count AS [Execution Count],

   4: SUBSTRING(qt.[text][/text],qs.statement_start_offset/2, 

   5:     (CASE 

   6:         WHEN qs.statement_end_offset = -1 

   7:      THEN LEN(CONVERT(nvarchar(max), qt.[text][/text])) * 2 

   8:         ELSE qs.statement_end_offset 

   9:      END - qs.statement_start_offset)/2) AS [Query Text]    

  10: FROM sys.dm_exec_query_stats AS qs WITH (NOLOCK)

  11: CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) AS qt

  12: WHERE qt.[dbid] = DB_ID()

  13: ORDER BY [Avg IO] DESC OPTION (RECOMPILE);

  14:  

  15: -- Helps you find the most expensive statements for I/O by SP

Figure 2: Query #53 Top IO Statements

This query shows you which query statements (which are often inside of stored procedures are causing the highest average I/O activity in the current database. Again, if you are under internal memory pressure, or if you are seeing high I/O latency for reads or for writes, the results of this query can point you in the right direction for further investigation.

Perhaps you have a query that is doing a clustered index scan because it is missing a useful non-clustered index. Perhaps a query is pulling back more rows or columns of data than it really needs (although can be hard for you to confirm this as a DBA). Perhaps the table(s) that are involved in this query might have indexes that would be good candidates for SQL Server Data Compression. There are many, many possible issues and actions that you can investigate in this area!

Leave a Reply

Your email address will not be published. Required fields are marked *

Other articles

Imagine feeling confident enough to handle whatever your database throws at you.

With training and consulting from SQLskills, you’ll be able to solve big problems, elevate your team’s capacity, and take control of your data career.