Intro
There were many new DMVs added in SQL Server 2012, and some that have changed since SQL Server 2008 R2. This is a brief overview of the biggest changes and what they mean to you.
Introduction
Dynamic management views (DMVs) are immensely useful tools that are provided with all editions of SQL Server since 2005. Using them, you can quickly find out information about many aspects of SQL Server, everything from index usage, query cache contents, server process data, wait stats, and much, much more.
With each new version of SQL Server comes many new DMVs as well as changes to existing ones. What follows are the highlights of DMV changes in SQL Server 2012. In addition, I have provided a spreadsheet with a list of all changes that I could identify between SQL Server 2008 R2 and SQL Server 2012. If you are upgrading, this list could be very useful to ensure that data collectors, debugging stored procedures, or other TSQL that you have written are modified as necessary to keep working, and that new views can be utilized to fill any existing gaps in monitoring.
The Details
A list of DMVs can be generated in any version of SQL Server using the following query:
SELECT * FROM sys.system_objects WHERE name LIKE 'dm_%' AND type = 'V' ORDER BY name
With no further delay, here are some of the more significant DMV changes in SQL Server 2012:
sys.dm_server_services
This contains details on each service that is running on your SQL Server, including the startup type, status, process ID, service account, startup command, and some cluster details. Being able to quickly return this data using T-SQL can be a big time saver, and could allow you to do some rudimentary monitoring on the service, or verify that all of its settings are what they should be. Here is a quick select of the contents of this DMV on my local test server.
Note that this DMV was available in SQL Server 2008R2 starting in service pack 1.
sys.dm_os_windows_info
This straightforward one-line DMV contains some basic version info on the OS that is running your SQL Server:
Note that this DMV was also available in SQL Server 2008R2 starting in service pack 1.
sys.dm_db_log_space_usage
This is another super-simple view that provides the size of your transaction log and the space used:
sys.dm_server_registry
Quick access to registry settings for your SQL server can be found right here! This DMV can be invaluable for troubleshooting a settings issue or confirming that SQL Server is configured correctly:
Note that this DMV was also available in SQL Server 2008R2 starting in service pack 1.
sys.dm_db_uncontained_entities
If an entity in a database references anything outside of the current database, it is considered an uncontained entity and will be reported in this DMV. This can be especially handy if you are renaming, moving, or otherwise making changes to an object that could be referenced by another database. This view can be used to check for these unenforced dependencies and prepare changes as needed. The example below creates an entity such as this as an example:
CREATE DATABASE uncontained_entity_test GO USE uncontained_entity_test GO CREATE PROCEDURE uncontained_entity_test_proc AS SELECT * FROM master.sys.dm_os_wait_stats; GO SELECT SYS_SCHEMAS.name AS schemaname, SYS_OBJECTS.name AS objectname, SYS_OBJECTS.type_desc, SYS_OBJECTS.create_date, SYS_OBJECTS.modify_date, ENTITIES.class_desc, ENTITIES.statement_line_number, ENTITIES.statement_type, ENTITIES.feature_name, ENTITIES.feature_type_name FROM sys.dm_db_uncontained_entities ENTITIES INNER JOIN sys.objects SYS_OBJECTS ON SYS_OBJECTS.object_id = ENTITIES.major_id INNER JOIN sys.schemas SYS_SCHEMAS ON SYS_SCHEMAS.schema_id = SYS_OBJECTS.schema_id
In this SQL we create a simple stored procedure that selects data from the master database, which is outside of the scope of our current database. The query returns basic info on the stored proc, its schema, and the referenced object:
In this example, we can see our proc (dbo.uncontained_entity_test_proc) under objectname and the external resource (dm_os_wait_stats) we are referencing under feature_name. As an added bonus, statement_line_number tells you on what line of the proc our reference occurs, which could be very handy when dealing with a large proc.
sys.dm_tcp_listener_states
This new DMV provides data on which TCP ports are being used by the TCP Listener, and does so for T-SQL, the Service Broker, and for mirroring. This can be very handy for troubleshooting connectivity problems or verifying that a server is set up with the correct port & IP address. A look at my local (and somewhat boring) server:
Note that the “::” is used for an IPv6 wildcard. A separate row is returned if a listener has both an IPv4 and an IPv6 address.
sys.dm_server_memory_dumps
Another simple view with troubleshooting in mind. It will return basic file data for any dump files that have been generated by SQL Server:
The file can be a minidump, full dump, or an all-thread dump.
sys.dm_os_cluster_properties
This DMV provides one row of data about the SQL Server cluster settings. If your instance is stand-alone and not on a failover cluster, then no rows are returned. This view is focused squarely on troubleshooting, and contains info on dump files, failure conditions, logging and the health check timeout.
sys.dm_os_server_diagnostics_log_configurations
One row is returned by this DMV, which contains the basic configuration info for the SQL Server failover cluster diagnostic log:
If you use AlwaysOn Availability Groups, then there are a dozen new DMVs that provide a plethora of information on the feature. Since these views may not apply to everyone, I will leave out the details, but suffice it to say that troubleshooting AlwaysOn issues will be much easier with these than without:
- sys.dm_hadr_auto_page_repair
- sys.dm_hadr_availability_group_states
- sys.dm_hadr_availability_replica_cluster_nodes
- sys.dm_hadr_availability_replica_cluster_states
- sys.dm_hadr_availability_replica_states
- sys.dm_hadr_cluster
- sys.dm_hadr_cluster_members
- sys.dm_hadr_cluster_networks
- sys.dm_hadr_database_replica_cluster_states
- sys.dm_hadr_database_replica_states
- sys.dm_hadr_instance_node_map
- sys.dm_hadr_name_id_map
Conclusion
The changes above outline only a fraction of the DMVs that have been added or altered in SQL Server 2012. There is quite a bit of new functionality that is addressed in these new views. Many existing views have had columns added, removed, or renamed. In addition, other new views have been added to address new functionality in the Resource Governor, Full-Text Search, and other features in SQL Server.
For details of all major changes and additions, please see the attached document, which contains a list of DMVs in SQL Server 2008 R2 and SQL Server 2012. A row exists for each instance of the DMV, one in 2008R2 and one in 2012, along with brief details on what was changed.