Blog Post

SQL Server DMV: sys.dm_exec_requests

Today, I’ve received an email from friend asking that that is there any way to find out the progress of following operation using T- SQL query. As we know, with the release of SQL Server 2005, Microsoft provides set of dynamic management views (DMVs) which helps ease the administration SQL Server Database Engine. These sets of new DMVs include one particular DMV that is sys.dm_exec_requests, which we can use to return information about the requests that are currently executing on SQL Server instance. I used this DMV to write the following query, which helps to find the progress of following operations programmatically:

  • ALTER INDEX REORGANIZE
  • AUTO_SHRINK
  • BACKUP DATABASE
  • DBCC CHECKDB
  • DBCC CHECKFILEGROUP
  • DBCC CHECKTABLE
  • DBCC INDEXDEFRAG
  • DBCC SHRINKDATABASE
  • DBCC SHRINKFILE
  • RECOVERY
  • RESTORE DATABASE
  • ROLLBACK
  • TDE ENCRYPTION
  • RESTORE LOG
  • BACKUP LOG
SELECT dmv1.[session_id] AS [UserSessionID]
      ,dmv2.[login_name] AS [SessionLoginName]
      ,dmv2.[original_login_name] AS [ConnectionLoginName]
      ,dmv1.[command] AS [TSQLCommandType]
      ,est.[text] AS [TSQLCommandText]
      ,dmv2.[status] AS [Status]
      ,dmv2.[cpu_time] AS [CPUTime]
      ,dmv2.[memory_usage] AS [MemoryUsage]
      ,dmv1.[start_time] AS [StartTime]
      ,dmv1.[percent_complete] AS [PercentComplete]
      ,dmv2.[program_name] AS [ProgramName]
      ,CAST(((DATEDIFF(s, dmv1.[start_time], CURRENT_TIMESTAMP)) / 3600) AS [varchar](32)) + ' hour(s), ' 
        + CAST((DATEDIFF(s, dmv1.[start_time], CURRENT_TIMESTAMP) % 3600) / 60 AS [varchar](32)) + 'min, ' 
        + CAST((DATEDIFF(s, dmv1.[start_time], CURRENT_TIMESTAMP) % 60) AS [varchar](32)) + ' sec' AS [RunningTime]
      ,CAST((dmv1.[estimated_completion_time] / 3600000) AS [varchar](32)) + ' hour(s), ' 
        + CAST((dmv1.[estimated_completion_time] % 3600000) / 60000 AS [varchar](32)) + 'min, ' 
        + CAST((dmv1.[estimated_completion_time] % 60000) / 1000 AS [varchar](32)) + ' sec' AS [TimeRequiredToCompleteOperation]
      ,dateadd(second, dmv1.[estimated_completion_time] / 1000, CURRENT_TIMESTAMP) AS [EstimatedCompletionTime]
FROM [sys].[dm_exec_requests] dmv1
CROSS APPLY [sys].[dm_exec_sql_text](dmv1.[sql_handle]) est
INNER JOIN [sys].[dm_exec_sessions] dmv2 
    ON dmv1.[session_id] = dmv2.[session_id]
WHERE dmv1.[command] IN ('ALTER INDEX REORGANIZE'
                        ,'AUTO_SHRINK'
                        ,'BACKUP DATABASE'
                        ,'DBCC CHECKDB'
                        ,'DBCC CHECKFILEGROUP'
                        ,'DBCC CHECKTABLE'
                        ,'DBCC INDEXDEFRAG'
                        ,'DBCC SHRINKDATABASE'
                        ,'DBCC SHRINKFILE'
                        ,'RECOVERY'
                        ,'RESTORE DATABASE'
                        ,'ROLLBACK'
                        ,'TDE ENCRYPTION'
                        ,'RESTORE LOG'
                        ,'BACKUP LOG')

Then following is the resultset this query returned, when I executed against server where I’m performing backup of the database (Note: To fit the resultset on the page, I splitted into two images):

progress_1

progress_2

For more information about this DMV, see sys.dm_exec_requests (Transact-SQL).

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating