|
| 1 | +/* |
| 2 | +https://blog.pythian.com/extended-events-fetching-api-cursors/ |
| 3 | +by Shawn Melton January 3, 2017 |
| 4 | +*/ |
| 5 | + |
| 6 | +DROP EVENT SESSION TrackApiCursor ON SERVER; |
| 7 | +GO |
| 8 | + |
| 9 | +CREATE EVENT SESSION TrackApiCursor ON SERVER |
| 10 | +ADD EVENT sqlserver.cursor_close( |
| 11 | + ACTION( |
| 12 | + sqlserver.client_app_name, |
| 13 | + sqlserver.database_name, |
| 14 | + sqlserver.is_system, |
| 15 | + sqlserver.session_id, |
| 16 | + sqlserver.sql_text) |
| 17 | + WHERE ( |
| 18 | + [sqlserver].[is_system]<>(0) |
| 19 | + -- AND [sqlserver].[client_app_name]=N'Steely-Eyed-Missle-Man' |
| 20 | + ) |
| 21 | +), |
| 22 | +ADD EVENT sqlserver.cursor_open( |
| 23 | + ACTION( |
| 24 | + sqlserver.client_app_name, |
| 25 | + sqlserver.database_name, |
| 26 | + sqlserver.is_system, |
| 27 | + sqlserver.query_hash, |
| 28 | + sqlserver.session_id, |
| 29 | + sqlserver.sql_text) |
| 30 | + WHERE ( |
| 31 | + [sqlserver].[is_system]<>(0) |
| 32 | + -- AND [sqlserver].[client_app_name]=N'Steely-Eyed-Missle-Man' |
| 33 | + ) |
| 34 | +), |
| 35 | +ADD EVENT sqlserver.rpc_completed( |
| 36 | + ACTION( |
| 37 | + sqlserver.client_app_name, |
| 38 | + sqlserver.database_name, |
| 39 | + sqlserver.is_system, |
| 40 | + sqlserver.query_hash, |
| 41 | + sqlserver.session_id, |
| 42 | + sqlserver.sql_text) |
| 43 | + WHERE ( |
| 44 | + [sqlserver].[is_system]<>(0) |
| 45 | + -- AND [sqlserver].[client_app_name]=N'Steely-Eyed-Missle-Man' |
| 46 | + ) |
| 47 | +) |
| 48 | +ADD TARGET package0.event_file(SET filename=N'Track_api_cursor.xel') |
| 49 | +WITH ( |
| 50 | + MAX_DISPATCH_LATENCY=12 SECONDS, |
| 51 | + TRACK_CAUSALITY=ON |
| 52 | +); |
| 53 | +GO |
| 54 | + |
| 55 | +ALTER EVENT SESSION TrackApiCursor ON SERVER STATE = START; |
| 56 | +GO |
| 57 | + |
| 58 | +/* Read the data */ |
| 59 | +IF OBJECT_ID('tempdb..#XEResults') IS NOT NULL |
| 60 | + DROP TABLE #XEResults ; |
| 61 | +GO |
| 62 | +IF OBJECT_ID('tempdb..#XEResultsParsed') IS NOT NULL |
| 63 | + DROP TABLE #XEResultsParsed ; |
| 64 | +GO |
| 65 | + |
| 66 | +-- Create results table to load data from XE files |
| 67 | +CREATE TABLE #XEResults |
| 68 | +( |
| 69 | + [RowID] INT IDENTITY |
| 70 | + PRIMARY KEY, |
| 71 | + [event_data] XML |
| 72 | +); |
| 73 | + |
| 74 | +-- Load the event data from the file target |
| 75 | +INSERT INTO #XEResults |
| 76 | + ([event_data]) |
| 77 | +SELECT CAST([event_data] AS XML) AS event_data |
| 78 | +FROM [sys].[fn_xe_file_target_read_file](N'Track_api_cursor*xel',NULL,NULL,NULL) ; |
| 79 | + |
| 80 | +--SELECT * FROM #XEResults |
| 81 | + |
| 82 | +-- Query the Event data from the Target. |
| 83 | +SELECT [event].[value]('(@name)[1]', 'varchar(50)') AS event_name |
| 84 | +-- , DATEADD(hh, DATEDIFF(hh, GETUTCDATE(), CURRENT_TIMESTAMP), [event].[value]('(@timestamp)[1]', 'datetime2')) AS [timestamp] |
| 85 | + ,[event].[value]('(action[@name="session_id"]/value)[1]', 'int') AS [session_id] |
| 86 | + ,[event].[value]('(action[@name="database_name"]/value)[1]','varchar(128)') AS [database_name] |
| 87 | + ,[event].[value]('(action[@name="client_app_name"]/value)[1]','varchar(500)') AS [client_app_name] |
| 88 | + ,[event].[value]('(data[@name="object_name"]/value)[1]', 'varchar(50)') AS [object_name] |
| 89 | + ,[event].[value]('(action[@name="sql_text"]/value)[1]','varchar(max)') AS [sql_text] |
| 90 | + ,[event].[value]('(data[@name="statement"]/value)[1]', 'varchar(1000)') AS [statement] |
| 91 | + ,[event].[value]('(action[@name="attach_activity_id_xfer"]/value)[1]', 'varchar(200)') AS [attach_activity_id_xfer] |
| 92 | + ,[event].[value]('(action[@name="attach_activity_id"]/value)[1]', 'varchar(200)') AS [attach_activity_id] |
| 93 | +FROM #XEResults |
| 94 | +CROSS APPLY [event_data].[nodes]('event') AS [q] ([event]) |
| 95 | +ORDER BY DATEADD(hh, DATEDIFF(hh, GETUTCDATE(), CURRENT_TIMESTAMP),[event].[value]('(@timestamp)[1]', 'datetime2')) |
| 96 | + ,[event].[value]('(action[@name="attach_activity_id"]/value)[1]', 'varchar(200)'); |
| 97 | + |
0 commit comments