Skip to content

Commit 7470d08

Browse files
committed
Add new useful extended events
1 parent 2f77bfd commit 7470d08

File tree

3 files changed

+55
-0
lines changed

3 files changed

+55
-0
lines changed

Extended_Events/DarkQueries.sql

Lines changed: 26 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,26 @@
1+
CREATE EVENT SESSION [DarkQueries] ON SERVER
2+
ADD EVENT sqlserver.sql_statement_recompile(
3+
ACTION(sqlserver.database_id,sqlserver.sql_text)
4+
WHERE ([recompile_cause]=(11))) -- Option (RECOMPILE) Requested
5+
ADD TARGET package0.event_file(SET filename=N'DarkQueries');
6+
7+
ALTER EVENT SESSION [DarkQueries] ON SERVER STATE = START;
8+
9+
10+
SELECT DarkQueryData.eventDate,
11+
DB_NAME(DarkQueryData.database_id) as DatabaseName,
12+
DarkQueryData.object_type,
13+
COALESCE(DarkQueryData.sql_text,
14+
OBJECT_NAME(DarkQueryData.object_id, DarkQueryData.database_id)) command,
15+
DarkQueryData.recompile_cause
16+
FROM sys.fn_xe_file_target_read_file ( 'DarkQueries*xel', null, null, null) event_file_value
17+
CROSS APPLY ( SELECT CAST(event_file_value.[event_data] as xml) ) event_file_value_xml ([xml])
18+
CROSS APPLY (
19+
SELECT event_file_value_xml.[xml].value('(event/@timestamp)[1]', 'datetime') as eventDate,
20+
event_file_value_xml.[xml].value('(event/action[@name="sql_text"]/value)[1]', 'nvarchar(max)') as sql_text,
21+
event_file_value_xml.[xml].value('(event/data[@name="object_type"]/text)[1]', 'nvarchar(100)') as object_type,
22+
event_file_value_xml.[xml].value('(event/data[@name="object_id"]/value)[1]', 'bigint') as object_id,
23+
event_file_value_xml.[xml].value('(event/data[@name="source_database_id"]/value)[1]', 'bigint') as database_id,
24+
event_file_value_xml.[xml].value('(event/data[@name="recompile_cause"]/text)[1]', 'nvarchar(100)') as recompile_cause
25+
) as DarkQueryData
26+
ORDER BY eventDate DESC;

Extended_Events/README.md

Lines changed: 5 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2,3 +2,8 @@
22

33
Source links:
44
- [Extended Events Microsoft Docs](https://docs.microsoft.com/en-us/sql/relational-databases/extended-events/extended-events)
5+
- [Find Your Dark Queries](http://michaeljswart.com/2017/04/finding-your-dark-queries/)
6+
- [Finding Blocked Processes and Deadlocks using SQL Server Extended Events](https://www.brentozar.com/archive/2014/03/extended-events-doesnt-hard/)
7+
- [What event information can I get by default from SQL Server?](http://dba.stackexchange.com/questions/48052/what-event-information-can-i-get-by-default-from-sql-server)
8+
- [Understanding the sql_text Action in Extended Events](https://www.sqlskills.com/blogs/jonathan/understanding-the-sql_text-action-in-extended-events/)
9+
- [Extended Events Series (1 of 31) – An Overview of Extended Events](https://www.sqlskills.com/blogs/jonathan/extended-events-overview/)
Lines changed: 24 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,24 @@
1+
CREATE EVENT SESSION Recompile_Histogram ON SERVER
2+
ADD EVENT sqlserver.sql_statement_recompile
3+
ADD TARGET package0.histogram (
4+
SET filtering_event_name=N'sqlserver.sql_statement_recompile',
5+
source=N'recompile_cause',
6+
source_type=(0) );
7+
8+
ALTER EVENT SESSION Recompile_Histogram ON SERVER STATE = START;
9+
10+
SELECT sv.subclass_name as recompile_cause,
11+
shredded.recompile_count
12+
FROM sys.dm_xe_session_targets AS xet
13+
JOIN sys.dm_xe_sessions AS xe
14+
ON (xe.address = xet.event_session_address)
15+
CROSS APPLY ( SELECT CAST(xet.target_data as xml) ) as target_data_xml ([xml])
16+
CROSS APPLY target_data_xml.[xml].nodes('/HistogramTarget/Slot') AS nodes (slot_data)
17+
CROSS APPLY (
18+
SELECT nodes.slot_data.value('(value)[1]', 'int') AS recompile_cause,
19+
nodes.slot_data.value('(@count)[1]', 'int') AS recompile_count
20+
) as shredded
21+
JOIN sys.trace_subclass_values AS sv
22+
ON shredded.recompile_cause = sv.subclass_value
23+
WHERE xe.name = 'Recompile_Histogram'
24+
AND sv.trace_event_id = 37 -- SP:Recompile;

0 commit comments

Comments
 (0)