Click here to Skip to main content
15,884,298 members
Articles / Database Development / SQL Server

Dynamic Management Views [DMV] – A SQL Server 2005 Feature

Rate me:
Please Sign up or sign in to vote.
4.94/5 (28 votes)
29 Dec 2006CPOL6 min read 212.9K   45   7
The DMVs; newly introduced in SQL Server 2005 gives database administrator information about the current state of the SQL Server machine.

Introduction

The DMVs; newly introduced in SQL Server 2005 gives the database administrator information about the current state of the SQL Server machine. These values will help the administrator to diagnose problems and tune the server for optimal performance. DMVs are designed to be used instead of system tables and various other functions provided in SQL Server 2000. In this article, I will be explaining only about the frequently used DMVs.

Two types of dynamic management views:

  1. Server-scoped DMV: Stored in Master Database
  2. Database-scoped DMV: Specific to each database

Permission to Execute DMV [Security]

To query a server scoped DMV, the database user must have SELECT privilege on VIEW SERVER STATE and for database scoped DMV, the user must have SELECT privilege on VIEW DATABASE STATE.

  • GRANT VIEW SERVER STATE to <Login>
  • GRANT VIEW DATABASE STATE to <User>

If you want to deny a user permission to query certain DMVs, you can use the DENY command to restrict access to a specific DMV.

Getting Started

All the DMVs exits in SYS schema and their names start with DM_. So when you need to query a DMV, you should prefix the view name with SYS. As an example, if you need to see the total physical memory of the SQL Server machine; then execute the below TSQL command:

SQL
SELECT 
(Physical_memory_in_bytes/1024.0)/1024.0 AS Physical_memory_in_Mb 
FROM 
sys.dm_os_sys_info

In this article, I will be explaining some of the DMVs which can be used frequently to understand the current behavior of SQL Server:

  1. SQL Server related [Hardware Resources] DMV
  2. Database related DMV
  3. Index related DMV
  4. Execution related DMV

1. SQL Server Related DMV

This section details the DMVs associated with SQL Server system. SQL DMV is responsible to manage server level resources specific to a SQL Server instance.

This section covers DMVs related to OS, Disk and Memory.

a. sys.dm_os_sys_info

This view returns the information about the SQL Server machine, available resources and the resource consumption.

This view returns information like the following:

  1. CPU Count: Number of logical CPUs in the server
  2. Hyperthread-ratio: Ratio of logical and physical CPUs
  3. Physical_memory_in_bytes: Amount of physical memory available
  4. Virtual_memory_in_bytes: Amount of virtual memory available
  5. Bpool_commited: Committed physical memory in buffer pool
  6. OS_Priority_class: Priority class for SQL Server process
  7. Max_workers_thread: Maximum number of workers which can be created

b. sys.dm_os_hosts

This view returns all the hosts registered with SQL Server 2005. This view also provides the resources used by each host.

  1. Name: Name of the host registered
  2. Type: Type of hosted component [SQL Native Interface/OLE DB/MSDART]
  3. Active_tasks_count: Number active tasks host placed
  4. Active_ios_count: I/O requests from host waiting

c. sys.dm_os_schedulers

Sys.dm_os_schedulers view will help you identify if there is any CPU bottleneck in the SQL Server machine. The number of runnable tasks is generally a nonzero value; a nonzero value indicates that tasks have to wait for their time slice to run. If the runnable task counts show high values, then there is a symptom of CPU bottleneck.

SQL
SELECT 
scheduler_id,current_tasks_count,runnable_tasks_count 
FROM sys.dm_os_schedulers 
WHERE scheduler_id < 255

The above query will list all the available schedulers in the SQL Server machine and the number of runnable tasks for each scheduler.

d. sys.dm_io_pending_io_requests

This dynamic view will return the I/O requests pending in SQL Server side. It gives you information like:

  1. Io_type: Type of pending I/O request
  2. Io_pending: Indicates whether the I/O request is pending or has been completed by Windows
  3. Scheduler_address: Scheduler on which this I/O request was issued

e. sys.dm_io_virtual_file_stats

This view returns I/O statistics for data and log files [MDF and LDF file]. This view is one of the commonly used views and will help you to identify I/O file level. This will return information like:

  1. Sample_ms: Number of milliseconds since the instance of SQL Server has started
  2. Num_of_reads: Number of reads issued on the file
  3. Num_of_bytes_read: Total number of bytes read on this file
  4. Io_stall_read_ms: Total time, in milliseconds, that the users waited for reads issued on the file
  5. Num_of_writes: Number of writes made on this file
  6. Num_of_bytes_written: Total number of bytes written to the file
  7. Io_stall_write_ms: Total time, in milliseconds, that users waited for writes to be completed on the file
  8. Io_stall: Total time, in milliseconds, that users waited for I/O to be completed
  9. Size_on_disk_bytes: Number of bytes used on the disk for this file

f. sys.dm_os_memory_clerks

This DMV will help how much memory SQL Server has allocated through AWE.

SQL
SELECT 
SUM(awe_allocated_kb) / 1024 as [AWE allocated, Mb] 
FROM sys.dm_os_memory_clerks

The same DMV can be used to get the memory consumption by internal components of SQL Server 2005.

SQL
SELECT TOP 10 type, 
SUM(single_pages_kb) as [SPA Mem, Kb] 
FROM sys.dm_os_memory_clerks 
GROUP BY type 
ORDER BY SUM(single_pages_kb) DESC

g. sys.dm_os_ring_buffers

This DMV uses RING_BUFFER_RESOURCE_MONITOR and gives information from resource monitor notifications to identify memory state changes. Internally, SQL Server has a framework that monitors different memory pressures. When the memory state changes, the resource monitor task generates a notification. This notification is used internally by the components to adjust their memory usage according to the memory state.

SQL
SELECT 
Record FROM sys.dm_os_ring_buffers 
WHERE ring_buffer_type = 'RING_BUFFER_RESOURCE_MONITOR'

The output of the above query will be in XML format. The output will help you in detecting any low memory notification.

RING_BUFFER_OOM: Ring buffer oom contains records indicating server out-of-memory conditions.

SQL
SELECT
record FROM sys.dm_os_ring_buffers 
WHERE ring_buffer_type = 'RING_BUFFER_OOM'

2. Database Related DMV

This section details the DMVs associated with SQL Server Databases. These DMVs will help to identify database space usages, partition usages, session information usages, etc...

a. sys.dm_db_file_space_usage

This DMV provides the space usage information of TEMPDB database.

b. sys.dm_db_session_space_usage

This DMV provides the number of pages allocated and de-allocated by each session for the database

c. sys.dm_db_partition_stats

This DMV provides page and row-count information for every partition in the current database.

The below query shows all counts for all partitions of all indexes and heaps in the MSDB database:

SQL
USE MSDB;
GO
SELECT * FROM sys.dm_db_partition_stats;

The following query shows all counts for all partitions of Backup set table and its indexes

SQL
USE MSDB
GO
SELECT * FROM sys.dm_db_partition_stats 
WHERE object_id = OBJECT_ID('backupset');

d. sys.dm_os_performance_counters

Returns the SQL Server / Database related counters maintained by the server.

The below sample query uses the dm_os_performance_counters DMV to get the Log file usage for all databases in KB.

SQL
SELECT instance_name
,cntr_value 'Log File(s) Used Size (KB)'
FROM sys.dm_os_performance_counters 
WHERE counter_name = 'Log File(s) Used Size (KB)'

3. INDEX Related DMV

This section details the DMVs associated with SQL Server Databases. These DMVs will help to identify database space usages, Partition usages, Session information usages, etc.

a. sys.dm_db_index_usage_stats

This DMV is used to get useful information about the index usage for all objects in all databases. This also shows the amount of seeks and scan for each index.

SQL
SELECT object_id, index_id, user_seeks, user_scans, user_lookups 
FROM sys.dm_db_index_usage_stats 
ORDER BY object_id, index_id

All indexes which have not been used so far in as database can be identified using the below Query:

SQL
SELECT object_name(i.object_id), 
i.name, 
s.user_updates, 
s.user_seeks, 
s.user_scans, 
s.user_lookups
from sys.indexes i 
left join sys.dm_db_index_usage_stats s 
on s.object_id = i.object_id and 
i.index_id = s.index_id and s.database_id = 5
where objectproperty(i.object_id, 'IsIndexable') = 1 and
s.index_id is null or
(s.user_updates > 0 and s.user_seeks = 0 
and s.user_scans = 0 and s.user_lookups = 0)
order by object_name(i.object_id)

Replace the Database_id with the database you are looking at.

4. Execution Related DMV

Execution related DMVs will provide information regarding sessions, connections, and various requests which are coming into the SQL Server.

a. sys.dm_exec_sessions

This DMV will give information on each session connected to SQL Server. This DMV is similar to running sp_who2 or querying Master..sysprocesses table.

SQL
SELECT
session_id,login_name,
last_request_end_time,cpu_time
FROM sys.dm_exec_sessions
WHERE session_id >= 51All user Sessions

b. sys.dm_exec_connections

This DMV shows all the connection to SQL Server. The below query uses sys.dm_exec_connections DMV to get connection information. This view returns one row for each user connection (Sessionid > =51).

SQL
SELECT
connection_id,
session_id,client_net_address,
auth_scheme
FROM sys.dm_exec_connections

c. sys.dm_exec_requests

This DMV will give details on what each connection is actually performing in SQL Server.

SQL
SELECT
session_id,status,
command,sql_handle,database_id
FROM sys.dm_exec_requests
WHERE session_id >= 51

d. sys.dm_exec_sql_text

This dynamic management function returns the text of a SQL statement given a SQL handle.

SQL
SELECT 
st.text
FROM
sys.dm_exec_requests r 
CROSS APPLY 
sys.dm_exec_sql_text(sql_handle) AS st
WHERE r.session_id = 51

Conclusion

Dynamic Management views (DMV) and Dynamic Management Functions (DMF) in SQL Server 2005 give a transparent view of what is going on inside various areas of SQL Server. By using them, we will be able to query the system for information about its current state in a much more effective manner and provide solutions much faster. DMVs can be used to performance tune and for troubleshooting server and queries. This article has shown an overview of what they are and how we can use them.

License

This article, along with any associated source code and files, is licensed under The Code Project Open License (CPOL)


Written By
Web Developer
United States United States
SUMMARY

 Working as a Database Architect in US Technology [CMMI/PCMMI Level 5 Company] - WWW.USTRI.COM
 MVP in SQL Server (2 years continuously) with MCDBA Certificationin SQL 2000
 9 years of experience in MSSQL Server
 Extensive experience in SQL Server from version 6.0 to SQL 2000
 Active participation in Microsoft Public SQL Server groups and Trivandrum user group
 Contributing articles on SQL Server for MSDN India.
 Experience in Database design, Installation, Crash / Recovery, Replication, Logshipping, 24 X 7 production support, Migration, Upgrades, Performance Tuning, DTS

Comments and Discussions

 
GeneralMy vote of 5 Pin
Sunil K Singh4-Sep-12 19:32
professionalSunil K Singh4-Sep-12 19:32 
GeneralMy vote of 5 Pin
Tim Corey7-Jun-12 7:49
professionalTim Corey7-Jun-12 7:49 
GeneralMy vote of 4 Pin
Pravin Patil, Mumbai12-Jan-11 22:18
Pravin Patil, Mumbai12-Jan-11 22:18 
GeneralDMV List Pin
BeckyWalker2-Jan-07 17:16
BeckyWalker2-Jan-07 17:16 
Is there any system table which stores the DMV listing?

Thanks
Becky

Thanks
Becky

GeneralRe: DMV List Pin
Hari Prasad K3-Jan-07 2:26
Hari Prasad K3-Jan-07 2:26 
QuestionTable, Stored Procedure, and User Function info? Pin
robrich22-Dec-06 12:45
robrich22-Dec-06 12:45 
AnswerRe: Table, Stored Procedure, and User Function info? Pin
Hari Prasad K22-Dec-06 18:41
Hari Prasad K22-Dec-06 18:41 

General General    News News    Suggestion Suggestion    Question Question    Bug Bug    Answer Answer    Joke Joke    Praise Praise    Rant Rant    Admin Admin   

Use Ctrl+Left/Right to switch messages, Ctrl+Up/Down to switch threads, Ctrl+Shift+Left/Right to switch pages.