Created
September 22, 2014 17:45
-
-
Save ghotz/847d64b267f6f0ebf6fe to your computer and use it in GitHub Desktop.
Audit applications that connects to a specified database using Windows Integrated Authentication storing the applications names and the number of connections.
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
-- | |
-- Audit applications that connects to a specified database using | |
-- Windows Integrated Authentication storing the applications names | |
-- and the number of connections. | |
-- | |
-- Requires SQL Server versione >= 2012 | |
-- Activate SQLCMD mode before running | |
-- | |
:setvar DatabaseName TestDatabase | |
-- Create event session | |
CREATE EVENT SESSION [AuditDBNTAuthApps_$(DatabaseName)] ON SERVER | |
ADD EVENT sqlserver.login( | |
SET collect_database_name=(1) | |
ACTION(sqlserver.client_app_name, sqlserver.nt_username) | |
WHERE ( | |
sqlserver.not_equal_i_sql_unicode_string(sqlserver.nt_user, N'') | |
AND sqlserver.equal_i_sql_unicode_string(database_name, N'$(DatabaseName)') | |
) | |
) | |
ADD TARGET package0.histogram(SET filtering_event_name=N'sqlserver.login', SOURCE=N'sqlserver.client_app_name') | |
WITH (MAX_MEMORY=4096KB, 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=ON) | |
GO | |
-- Start sesson | |
ALTER EVENT SESSION [AuditDBNTAuthApps_$(DatabaseName)] ON SERVER STATE = START; | |
GO | |
:setvar DatabaseName TestDatabase | |
-- Query Example (substitute $(DatabaseName) to run it | |
SELECT | |
slot_node.value('(value)[1]', 'nvarchar(128)') AS histogram_value | |
, slot_node.value('@count[1]', 'int') AS histogram_count | |
FROM ( | |
SELECT CAST(XT.target_data AS xml) AS target_data | |
FROM sys.dm_xe_sessions AS XS | |
JOIN sys.dm_xe_session_targets AS XT | |
ON XS.[address] = XT.event_session_address | |
WHERE XS.name = N'AuditDBNTAuthApps_$(DatabaseName)' | |
AND XT.target_name = N'histogram' | |
) AS ED | |
CROSS | |
APPLY target_data.nodes('HistogramTarget/Slot') as XQ(slot_node); | |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment