接續上次的主題,上次己經使用了SQL Profiler這個工具來錄製特定登入帳號的活動,
接下來為您介紹使用SQL Trace來監控SQL Server的活動,
SQL Trace有提供一組系統預存程序和函數,
可以建立Database Engine執行個體的"追踨",
可以搭配排程建立每日稽核的記錄檔。
常用的功能如下:
系統預存程序/函數 | 功能 |
---|---|
fn_trace_getinfo | 查詢特定Trace或所有Trace的相關資訊 |
sp_trace_create | 建立新的Trace定義,但注意建立後必須使用sp_trace_setstatus來啓動Trace |
sp_trace_setstatus | 啓動、停止或關閉Trace |
fn_trace_gettable | 以表格的方式回傳Trace File的內容,正在追蹤的Trace File內容也能被查詢 |
另外如果不想自行撰寫Trace Script,可以透過SQL Profiler設定出自己想要Trace的內容再加以匯出Script
--匯出的Script
/****************************************************/
/* Created by: SQL Server 2012 Profiler */
/* Date: 2018/10/20 10:34:58 AM */
/****************************************************/
-- Create a Queue
declare @rc int
declare @TraceID int
declare @maxfilesize bigint
set @maxfilesize = 1
-- Please replace the text InsertFileNameHere, with an appropriate
-- filename prefixed by a path, e.g., c:\MyFolder\MyTrace. The .trc extension
-- will be appended to the filename automatically. If you are writing from
-- remote server to local drive, please use UNC path and make sure server has
-- write access to your network share
exec @rc = sp_trace_create @TraceID output, 0, N'd:\Trace.trc', @maxfilesize, NULL
if (@rc != 0) goto error
-- Client side File and Table cannot be scripted
-- Set the events
declare @on bit
set @on = 1
exec sp_trace_setevent @TraceID, 12, 1, @on
exec sp_trace_setevent @TraceID, 12, 9, @on
exec sp_trace_setevent @TraceID, 12, 11, @on
exec sp_trace_setevent @TraceID, 12, 6, @on
exec sp_trace_setevent @TraceID, 12, 10, @on
exec sp_trace_setevent @TraceID, 12, 12, @on
exec sp_trace_setevent @TraceID, 12, 13, @on
exec sp_trace_setevent @TraceID, 12, 14, @on
exec sp_trace_setevent @TraceID, 12, 15, @on
exec sp_trace_setevent @TraceID, 12, 16, @on
exec sp_trace_setevent @TraceID, 12, 17, @on
exec sp_trace_setevent @TraceID, 12, 18, @on
exec sp_trace_setevent @TraceID, 13, 1, @on
exec sp_trace_setevent @TraceID, 13, 9, @on
exec sp_trace_setevent @TraceID, 13, 11, @on
exec sp_trace_setevent @TraceID, 13, 6, @on
exec sp_trace_setevent @TraceID, 13, 10, @on
exec sp_trace_setevent @TraceID, 13, 12, @on
exec sp_trace_setevent @TraceID, 13, 14, @on
-- Set the Filters
declare @intfilter int
declare @bigintfilter bigint
exec sp_trace_setfilter @TraceID, 10, 0, 7, N'SQL Server Profiler - 4aee4689-8d22-41a3-9c98-aaf657f551d8'
exec sp_trace_setfilter @TraceID, 11, 0, 6, N'%user1%'
-- Set the trace status to start
exec sp_trace_setstatus @TraceID, 1
-- display trace id for future references
select TraceID=@TraceID
goto finish
error:
select ErrorCode=@rc
finish:
go
執行以上Script後,可以透過
SELECT * FROM fn_trace_getinfo(default)
來查詢當下正在追蹤的情況
接著我用user1帳號登入後下了一些SQL指令,也可以透過fn_trace_gettable查出剛才所紀錄到的指令,