Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 

Basit's SQL Server Tips

Basit Farooq is a Lead Database Administrator, Trainer and Technical Author. He has more than a decade of IT experience in development, technical training and database administration on Microsoft SQL Server platforms. Basit has authored numerous SQL Server technical articles, and developed and implemented many successful database infrastructure, data warehouse and business intelligence projects. He holds a master's degree in computer science from London Metropolitan University, and industry standard certifications from Microsoft, Sun, Cisco, Brainbench, Prosoft and APM, including MCITP Database Administrator 2008, MCITP Database Administrator 2005, MCDBA SQL Server 2000 and MCTS .NET Framework 2.0 Web Applications.

Using sys.dm_db_index_operational_stats to analyse how indexes are utilised

This dynamic management function (DMF) returns the detailed information about low level activities on indexes such as input/output (I/O) operations, locking and latching contention, and access methods.

You can also use sys.dm_db_index_operational_stats function to find information such as how long the users must wait to read or write to a table, index, or partition, and identify the tables or indexes that are encountering significant I/O activity.

The following is the general syntax of this dynamic management function (DMF):

sys.dm_db_index_operational_stats (
     { database_id | NULL | 0 | DEFAULT }
   , { object_id | NULL | 0 | DEFAULT }
   , { index_id | 0 | NULL | -1 | DEFAULT }
   , { partition_number | NULL | 0 | DEFAULT })

Example:

Query 1: Execute to find out blocking per database object:

SELECT DB_NAME([database_id]) AS [Database]
    ,iops.[object_id] AS [ObjectID]
    ,QUOTENAME(OBJECT_SCHEMA_NAME(iops.[object_id], [database_id])) 
        + N'.' + QUOTENAME(OBJECT_NAME(iops.[object_id], [database_id])) AS [ObjectName]
    ,i.[index_id] AS [IndexID]
    ,i.[name] AS [IndexName]
    ,i.[fill_factor] AS [IndexFillFactor]
    ,iops.[partition_number] AS [PartitionNumber]
    ,CASE 
        WHEN i.[is_unique] = 1
            THEN 'UNIQUE '
        ELSE ''
        END + i.[type_desc] AS [IndexType]
    ,iops.[row_lock_count] AS [RowLockCount]
    ,iops.[row_lock_wait_count] AS [RowLockWaitCount]
    ,CAST(100.0 * iops.[row_lock_wait_count] / (iops.[row_lock_count] + 1) AS NUMERIC(15, 2)) AS [BlockedPercent]
    ,iops.[row_lock_wait_in_ms] AS [RowLockWaitInMilliseconds]
    ,CAST(1.0 * iops.[row_lock_wait_in_ms] / (1 + iops.[row_lock_wait_count]) AS NUMERIC(15, 2)) AS [AverageRowLockWaitInMilliseconds]
FROM [sys].[dm_db_index_operational_stats](DB_ID(), NULL, NULL, NULL) iops
INNER JOIN [sys].[indexes] i 
    ON i.[object_id] = iops.[object_id]
        AND i.[index_id] = iops.[index_id]
        AND iops.[row_lock_wait_count] > 0
WHERE OBJECTPROPERTY(iops.[object_id], 'IsUserTable') = 1
ORDER BY iops.[row_lock_wait_count] DESC;

Query 2 – Execute to analyse statistics of physical I/Os on an index or heap partition:

SELECT DB_NAME([database_id]) AS [Database]
    ,iops.[object_id] AS [ObjectID]
    ,QUOTENAME(OBJECT_SCHEMA_NAME(iops.[object_id], [database_id])) 
        + N'.' + QUOTENAME(OBJECT_NAME(iops.[object_id], [database_id])) AS [ObjectName]
    ,i.[name] AS [IndexName]
    ,CASE 
        WHEN i.[is_unique] = 1
            THEN 'UNIQUE '
        ELSE ''
        END + i.[type_desc] AS [IndexType]
    ,iops.[page_latch_wait_count] AS [PageLatchWaitCount]
    ,iops.[page_io_latch_wait_count] AS [PageIOLatchWaitCount]
    ,iops.[page_io_latch_wait_in_ms] AS [PageIOLatchWaitInMilliseconds]
FROM [sys].[dm_db_index_operational_stats](DB_ID(), NULL, NULL, NULL) iops
INNER JOIN [sys].[indexes] i ON i.[object_id] = iops.[object_id]
    AND i.[index_id] = iops.[index_id]
ORDER BY iops.[page_latch_wait_count] + iops.[page_io_latch_wait_count] DESC

Query 3 – Execute to find how many times Database Engine row or page lock:

SELECT DB_NAME([database_id]) AS [Database]
    ,iops.[object_id] AS [ObjectID]
    ,QUOTENAME(OBJECT_SCHEMA_NAME(iops.[object_id], [database_id])) 
        + N'.' + QUOTENAME(OBJECT_NAME(iops.[object_id], [database_id])) AS [ObjectName]
    ,iops.[row_lock_count] AS [RowLockCount]
    ,iops.[page_lock_count] AS [PageLockCount]
FROM [sys].[dm_db_index_operational_stats](DB_ID(), NULL, NULL, NULL) iops
INNER JOIN [sys].[indexes] i ON i.[object_id] = iops.[object_id]
    AND i.[index_id] = iops.[index_id]
ORDER BY iops.[page_latch_wait_count] + iops.[page_io_latch_wait_count] DESC

Query 4 – Execute to determine number of update, insert, and delete operations against each index of the database:

SELECT DB_NAME([database_id]) AS [Database]
    ,iops.[object_id] AS [ObjectID]
    ,QUOTENAME(OBJECT_SCHEMA_NAME(iops.[object_id], [database_id])) 
        + N'.' + QUOTENAME(OBJECT_NAME(iops.[object_id], [database_id])) AS [ObjectName]
    ,i.[index_id] AS [IndexID]
    ,i.[name] AS [IndexName]
    ,i.[fill_factor] AS [IndexFillFactor]
    ,iops.[partition_number] AS [PartitionNumber]
    ,CASE 
        WHEN i.[is_unique] = 1
            THEN 'UNIQUE '
        ELSE ''
        END + i.[type_desc] AS [IndexType]
    ,iops.[leaf_insert_count] AS [LeafInsertCount]
    ,iops.[leaf_delete_count] AS [LeafDeleteCount]
    ,iops.[leaf_update_count] AS [LeafUpdateCount]
FROM [sys].[dm_db_index_operational_stats](DB_ID(), NULL, NULL, NULL) iops
INNER JOIN [sys].[indexes] i ON i.[object_id] = iops.[object_id]
    AND i.[index_id] = iops.[index_id]
ORDER BY iops.[page_latch_wait_count] + iops.[page_io_latch_wait_count] DESC

As we have seen from above queries that sys.dm_db_index_operational_stats dynamic management function provides us the current low-level I/O, locking, latching, and access method for each partition of the table. This information is really useful to troubleshoot SQL Server performance issues.

For more information about this dynamic management function (DMF), see sys.dm_db_index_operational_stats (Transact-SQL).


Comments

Leave a comment on the original post [basitaalishan.com, opens in a new window]

Loading comments...