A Microsoft SQL Server DMV/DMF Cheat-Sheet

I am asked this question by Microsoft SQL Server customers again and again: “What dynamic management views (DMV) or dynamic management functions (DMF) should I use?” The short answer is, it depends. There are so many DMV/DMFs spread across various categories and are expanding since the initial introduction SQL Server 2005. It can be a daunting challenge trying to remember which DMV to leverage. I don’t think I have used all in my years of experience with SQL Server. I don’t think I ever will. The use of these really stems from what issues you are trying to deal with or what information you need from SQL Server. Since the use for most DMVs is scenarios based, I am listing here DMV/DMFs that I think every DBA should get familiar with. Now I am not saying this is an exhaustive list, but I find it a good starting point.

  1. DMV/DMFs that Every DBA Should Know
    1. Execution Related DMV/DMFs
    2. Index Related DMV/DMFs
    3. SQL Server Operating System DMV/DMFs
    4. I/O Related DMV/DMFs
  2. Using DMV/DMFs
    1. Statement #1: Get a List of Connections
    2. Statement #2: Get a List of Sessions
    3. Statement #3: Get a List of all the User Connections
    4. Statement #4: Get a List of the User Connections with the Current Request

DMV/DMFs that Every DBA Should Know

These DMVs skim the surface, but will let you know what is happening. There are a lot solutions available by community experts. If you don’t feel comfortable learning or remembering the DMV, they come in handy. For example, Adam Machanic’s, sp_whoisactive.

  • sys.dm_exec_connections
  • sys.dm_exec_sessions
  • sys.dm_exec_requests
  • sys.dm_exec_cached_plans
  • sys.dm_exec_query_plans
  • sys.dm_exec_sql_text
  • sys.dm_exec_query_stats
  • sys.dm_db_index_physical_stats
  • sys.dm_db_index_usage_stats

SQL Server Operating System DMV/DMFs

  • sys.dm_os_performance_counters
  • sys.dm_os_schedulers
  • sys.dm_os_nodes
  • sys.dm_os_waiting_tasks
  • sys.dm_os_wait_stats
  • sys.dm_io_virtual_file_stats

Using DMV/DMFs

Instead of just giving you random SQL statements against the DMV/DMFs listed above, I am going to walk through the DMV and build the corresponding SQL statement based on information I want to collect. For starters we will look to answer the following question: who is connected to SQL Server? We have in particular two DMVs to give us that information; sys.dm_exec_connections and sys.dm_exec_sessions. The sys.dm_exec_connections returns information for only user connections, whereas sys.dm_exec_sessions returns information for both user connections and system sessions. There is one-to-one relationship between the two DMVs. When looking at just the sys.dm_exec_sessions we can identify the system sessions by looking at is_user_process column.

Statement #1: Get a List of Connections

SELECT *
  FROM sys.dm_exec_connections

Statement #2: Get a List of Sessions

SELECT *
  FROM sys.dm_exec_sessions

Both statements return everything from the DMV, sample output is below.

The DMV returns too much information, so lets re-write both statements to return the information we are most interested in.

Statement #3: Get a List of all the User Connections

    SELECT   c.session_id
           , c.auth_scheme
           , c.node_affinity
           , s.login_name
           , db_name(s.database_id) AS database_name
           , CASE s.transaction_isolation_level
             WHEN 0 THEN 'Unspecified'
             WHEN 1 THEN 'Read Uncomitted'
             WHEN 2 THEN 'Read Committed'
             WHEN 3 THEN 'Repeatable'
             WHEN 4 THEN 'Serializable'
             WHEN 5 THEN 'Snapshot'
             END AS transaction_isolation_level
           , s.status
           , c.most_recent_sql_handle
      FROM sys.dm_exec_connections c
INNER JOIN sys.dm_exec_sessions s
        ON c.session_id = s.session_id
Field NameReason For Selection
auth_schemeLet us know what protocol they are coming in on: NTML, KERBEROS, or SQL.
node_affinityThis is important to find out who is using the DAC connection (I’ll explain below).
transaction_isolation_levelI want to know this, especially if I am dealing with a Blocking Issue and it is because users are using Serializable isolation level.
most_recent_sql_handleNow yes we still have DBCC INPUTBUFFER (); however I like this a lot better because I can join into other DMVs; will show you examples later.

Note we are only getting user connection information; in case we needed details for system sessions we will have to change INNER JOIN to RIGHT OUTER JOIN instead. Now we know who is connected, but we also want to know what are they doing? The STATUS field in the sys.dm_exec_sessions can tell us if the session is actively running something or is sleeping. Sleeping means the last task on the session has completed and is waiting for next batch of work (aka Idle Connection). And if it’s running we can find out what is the being run by the session, by diving into sys.dm_exec_requests; again I am going to expand Stmt3 to include new DMV now.

Statement #4: Get a List of the User Connections with the Current Request

    SELECT   c.session_id
           , c.auth_scheme
           , c.node_affinity
           , r.scheduler_id
           , s.login_name
           , db_name(s.database_id) AS database_name
           , CASE s.transaction_isolation_level
             WHEN 0 THEN 'Unspecified'
             WHEN 1 THEN 'Read Uncomitted'
             WHEN 2 THEN 'Read Committed'
             WHEN 3 THEN 'Repeatable'
             WHEN 4 THEN 'Serializable'
             WHEN 5 THEN 'Snapshot'
             END AS transaction_isolation_level
           , s.status AS SessionStatus
           , r.status AS RequestStatus
	   , CASE WHEN r.sql_handle IS NULL THEN
	        c.most_recent_sql_handle
             ELSE
	        r.sql_handle
	     END AS sql_handle
           , r.cpu_time
	   , r.reads
	   , r.writes
	   , r.logical_reads
	   , r.total_elapsed_time
      FROM sys.dm_exec_connections c
INNER JOIN sys.dm_exec_sessions s
        ON c.session_id = s.session_id
 LEFT JOIN sys.dm_exec_requests r
        ON c.session_id = r.session_id

I think this SQL statement gives us enough information to see what is going on in SQL Server. If we needed to dig in further we can use other DMVs or this one. So one question I often get asked is why use all these DMV? Why not sys.sysprocessesor sp_who or sp_who2?

  • Sysprocesses will be phased on in a future version, so it’s better to get use to the DMV before it is completely gone.
  • Sp_who and sp_who2 do not provide as much information as the DMV/DMF. I have taken out a lot of the information from each DMV/DMF, but after you know what you are looking for you can always dig further into the DMV/DMFs.

In this article we looked at getting information on who is connected and what request they are running. In my next post I’ll talk about how to get the T-SQL Code they are running and even the execution plans for those statements.

One comment

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out /  Change )

Facebook photo

You are commenting using your Facebook account. Log Out /  Change )

Connecting to %s

This site uses Akismet to reduce spam. Learn how your comment data is processed.