ReadChangeTrackingXEData.sql 1.9 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748
  1. -- Sample script to read data Change Tracking Automatic Cleanup Data using XE "change_tracking_cleanup"
  2. -- Create an XE session to read the
  3. CREATE EVENT SESSION [ChangeTracking] ON SERVER
  4. ADD EVENT sqlserver.change_tracking_cleanup
  5. ADD TARGET package0.ring_buffer
  6. WITH (MAX_MEMORY=4096 KB,EVENT_RETENTION_MODE=ALLOW_SINGLE_EVENT_LOSS,MAX_DISPATCH_LATENCY=30 SECONDS,MAX_EVENT_SIZE=0 KB,MEMORY_PARTITION_MODE=NONE,TRACK_CAUSALITY=OFF,STARTUP_STATE=OFF)
  7. GO
  8. -- Start the session
  9. ALTER EVENT SESSION ChangeTracking
  10. ON SERVER
  11. STATE = start
  12. -- Store the XML data in a temporary table
  13. SELECT CAST(xet.target_data as xml) as XMLDATA
  14. INTO #CTCleanupData
  15. FROM sys.dm_xe_session_targets xet
  16. JOIN sys.dm_xe_sessions xe
  17. ON (xe.address = xet.event_session_address)
  18. WHERE xe.name = 'changetracking' -- ### UPDATE with appropriate change tracking session name ###
  19. and target_name = 'ring_buffer'
  20. -- Get information about the steps executed by the automatic cleanup
  21. ;WITH CT_CleanupSession (EventXML) AS
  22. (
  23. SELECT C.query('.') EventXML
  24. FROM #CTCleanupData a
  25. CROSS APPLY a.XMLDATA.nodes('/RingBufferTarget/event') as T(C)
  26. )
  27. SELECT
  28. EventXML.value('(/event/@timestamp)[1]', 'datetime') as [Time (UTC)],
  29. DB_NAME(EventXML.value('(/event/data[@name = "database_id"]/value)[1]', 'int')) as [Database Name],
  30. OBJECT_NAME(EventXML.value('(/event/data[@name = "object_id"]/value)[1]', 'int')) as [Object Name],
  31. EventXML.value('(/event/data[@name = "cleanup_id"]/text)[1]', 'varchar(255)') as [Step],
  32. EventXML.value('(/event/data[@name = "value"]/value)[1]', 'varchar(255)') as [Value],
  33. CASE EventXML.value('(/event/data[@name = "status"]/value)[1]', 'int')
  34. WHEN 1 THEN 'Not Initialized'
  35. WHEN 2 THEN 'Initialized'
  36. WHEN 8 THEN 'In Progress'
  37. WHEN 16 THEN 'Finished'
  38. WHEN 32 THEN 'Error'
  39. END as [Status]
  40. FROM CT_CleanupSession
  41. WHERE EventXML.value('(/event/@name)[1]', 'varchar(255)') = 'change_tracking_cleanup'
  42. -- Drop the temporary table
  43. DROP TABLE #CTCleanupData