In a word; YES! In a lot more words, not always in the way that we want it to, but there are plenty of cases where it actually works and changes are made to the product as a result.
Now with that said, it doesn’t work all the time, and it helps to realize that what is important to us as an individual user might not be important to the product as a whole. Before you post comments, I am sure that there are plenty of cases out there where people can say that Microsoft Connect for SQL Server is broken. I have personally been irritated to the point of posting negative comments on Twitter about the whole Connect process. I feel that it is about time that I show the other side of the story as well and talk about some Connect successes that have occurred in the past year, and of course what better topic to do this with than Extended Events. Over the next few weeks, I’ll post a couple of different examples of Connect actually working and bringing about changes to the product that are beneficial to the community, starting with this post.
Extended Events does not track insert statements
This Connect item is actually incorrectly titled and is based on some confusion about what the sqlserver.plan_handle action actually returns when executed in the engine. I blogged about this with much more detail last year in my blog post; What plan_handle is Extended Events sqlserver.plan_handle action returning?
If we revisit the Connect item there is a note that the sql_statement_completed event in SQL Server 2012 now includes a parameterized_plan_handle customizable column that can be used to retrieve the parameterized plan handle for statements that are auto-parameterized by SQL Server during their execution. Taking the same original demo code from my previous blog post, we can now see how this Connect item has improved the ability to find information about plan caching in SQL Server 2012:
-- Create the Event Session IF EXISTS(SELECT * FROM sys.server_event_sessions WHERE name='SQLStmtEvents') DROP EVENT SESSION SQLStmtEvents ON SERVER; GO CREATE EVENT SESSION SQLStmtEvents ON SERVER ADD EVENT sqlserver.sql_statement_completed( SET collect_parameterized_plan_handle = 1 ACTION (sqlserver.client_app_name, sqlserver.plan_handle, sqlserver.sql_text, sqlserver.tsql_stack, package0.callstack, sqlserver.request_id) --Change this to match the AdventureWorks, --AdventureWorks2008 or AdventureWorks2008 SELECT DB_ID('AdventureWorks2008R2') WHERE sqlserver.database_id=9 ) ADD TARGET package0.ring_buffer WITH (MAX_DISPATCH_LATENCY=5SECONDS, TRACK_CAUSALITY=ON) GO -- Start the Event Session ALTER EVENT SESSION SQLStmtEvents ON SERVER STATE = START; GO -- Change database contexts and insert one row USE AdventureWorks2008R2; GO INSERT INTO [dbo].[ErrorLog]([ErrorTime],[UserName],[ErrorNumber],[ErrorSeverity],[ErrorState],[ErrorProcedure],[ErrorLine],[ErrorMessage]) VALUES(getdate(),SYSTEM_USER,-1,-1,-1,'ErrorProcedure',-1,'An error occurred') GO 10 -- Drop the Event ALTER EVENT SESSION SQLStmtEvents ON SERVER DROP EVENT sqlserver.sql_statement_completed; GO -- Retrieve the Event Data from the Event Session Target SELECT event_data.value('(event/@name)[1]', 'varchar(50)') AS event_name, event_data.value('xs:hexBinary((event/data[@name="parameterized_plan_handle"]/value)[1])', 'varbinary(64)') as parameterized_plan_handle, event_data.value('xs:hexBinary((event/action[@name="plan_handle"]/value)[1])', 'varbinary(64)') as plan_handle, event_data.value('(event/action[@name="sql_text"]/value)[1]', 'varchar(max)') AS sql_text FROM( SELECT evnt.query('.') AS event_data FROM ( SELECT CAST(target_data AS xml) AS TargetData FROM sys.dm_xe_sessions AS s JOIN sys.dm_xe_session_targets AS t ON s.address = t.event_session_address WHERE s.name = 'SQLStmtEvents' AND t.target_name = 'ring_buffer' ) AS tab CROSS APPLY TargetData.nodes ('RingBufferTarget/event') AS split(evnt) ) AS evts(event_data)
If we look at the output of this, we will get the parameterized plan handle for each subsequent call of the statement after the initial call caches the parameterized plan into the cache.
If we plug one of the original plan_handle values from the sqlserver.plan_handle action into a query of sys.dm_exec_cached_plans() it will return nothing, but using the new parameterized_plan_handle value from the customizable column will give us the appropriate cached plan for the statement from cache:
-- Use the plan_handle from one of the Events action to get the query plan DECLARE @plan_handle varbinary(64) = 0x06000900DFC9DD12608B18EE0100000001000000000000000000000000000000000000000000000000000000 SELECT * FROM sys.dm_exec_query_plan(@plan_handle) GO -- Use the parameterized_plan_handle from the same Events to get the query plan DECLARE @plan_handle varbinary(64) = 0x06000900DD8D6D08601E70EE01000000010000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000 SELECT * FROM sys.dm_exec_query_plan(@plan_handle) GO
Now, you might point out the different lengths of the plan handles in the above two queries. If you look back at the source, the same code is being used to perform the xhexBinary conversion in the XML so the values are exactly the same as what was originally provided by the event and the action. The non-parameterized plan is not cached because it is not likely to be reused, which is why we have the auto-parameterized plan in cache.