DevOps, Continuous Delivery & Database Lifecycle Management
Continuous Integration
After many years, the Default Trace still remains the simplest way of auditing SQL Server. It gives you so much useful information about significant events, when they happened and, where relevant, the login associated with the event. The Default trace is, however, now deprecated in favor of Extended Events and so has not evolved much over the years. The biggest problem with it is that it consists only of 5 files of 20Mb each, and they get overwritten often, especially in a busy SQL Server environment.
This article shows how you can get around this difficulty in order to maintain an unbroken record of trace events. This is only the start.
We then tackle the problems of maintaining a record of these default trace events for a whole group of servers and their databases, and use this archive for reporting and alerting for potential problems. We will do this by automating the process of extracting the default trace data from several SQL Server instances to a centralized location, persisting the data to a single database and preparing it for further analysis. The information that it can provide you about the way these servers and databases are being used is extremely valuable and difficult to get any other way. We can, for example get a complete record of every change to every database object, when it happened and who did it.
For the purpose, we will be using a Robocopy script which offloads the default trace files from the remote servers, then SSIS package which will import the data into a database and will delete the imported files.
The steps are as follows:
- Configure the Robocopy to access the remote server and to store the default trace files locally
- Configure the SSIS package to look for the default trace files copied by Robocopy
We’ll use Robocopy because the tool can be used to
- monitor the folder in a remote server that contains the default trace files
- detect any changes and copy over any changed file periodically
We choose Robocopy over SSIS to do this because we would have to schedule an SSIS package to run quite often and the copying process is not as lightweight.
Setting up Robocopy
The purpose of the Robocopy script in this case is to use it to maintain a copy of the Default Trace files in a centralized location, since the default trace log files in the SSQL Server instance are overwritten after a certain time.
This is a bit tricky to schedule and it is based on each individual SQL Server instance. For example, on a very busy production server it might be so that, every 10 minutes, all 5 default trace files are overwritten and on another SQL Server instance it may take 5 days for the files to be overwritten. The overwrite of the files depends on the volume of the traced events occurring on the system and also on instance restarts.
This is why it will take some investigation to understand and to schedule the Robocopy script in individual cases.
For the purpose of this article I will use a setting for Robocopy to check for changes in the default trace files every 10 minutes, though, in the assumption that this interval would be geared to the number events being recorded in the trace for the individual server.
The following script will execute Robocopy and will look at the default trace folder for the SQL Server instance and will copy over the changes to a local folder:
1 |
robocopy "\\remoteServerA\Program Files\Microsoft SQL Server\MSSQL10_50.SQL2008\MSSQL\Log" "\\myMachine\c$\Destination\remoteServerA" *.trc /MON:10 |
Note that the script is using the UNC path for the file storage locations. This means that it is up to the user to decide whether the robocopy script will be scheduled to run on the source machine or on the destination machine. (From my personal experience, it is better to have all Robocopy scripts to run from the same destination machine – it is easier to monitor and maintain).
Also note that the Destination folder contains a sub-folder for each monitored server. This is used later on in the configuration of the SSIS package.
Setting up the database
Here is the database script:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 |
CREATE TABLE [dbo].[ProcessingTrace_Config] ( [TraceProcessingID] [smallint] IDENTITY(1, 1) NOT NULL , [ServerName] [varchar](256) NOT NULL , [TracePath] [varchar](550) NOT NULL , [IsActive] [bit] NOT NULL , CONSTRAINT [PK_ProcessingTrace_Config] PRIMARY KEY CLUSTERED ( [TraceProcessingID] ASC ) ) CREATE TABLE [dbo].[temp_trc] ( [TextData] [ntext] NULL , [BinaryData] [image] NULL , [DatabaseID] [int] NULL , [TransactionID] [bigint] NULL , [LineNumber] [int] NULL , [NTUserName] [nvarchar](256) NULL , [NTDomainName] [nvarchar](256) NULL , [HostName] [nvarchar](256) NULL , [ClientProcessID] [int] NULL , [ApplicationName] [nvarchar](256) NULL , [LoginName] [nvarchar](256) NULL , [SPID] [int] NULL , [Duration] [bigint] NULL , [StartTime] [datetime] NULL , [EndTime] [datetime] NULL , [Reads] [bigint] NULL , [Writes] [bigint] NULL , [CPU] [int] NULL , [Permissions] [bigint] NULL , [Severity] [int] NULL , [EventSubClass] [int] NULL , [ObjectID] [int] NULL , [Success] [int] NULL , [IndexID] [int] NULL , [IntegerData] [int] NULL , [ServerName] [nvarchar](256) NULL , [EventClass] [int] NULL , [ObjectType] [int] NULL , [NestLevel] [int] NULL , [State] [int] NULL , [Error] [int] NULL , [Mode] [int] NULL , [Handle] [int] NULL , [ObjectName] [nvarchar](256) NULL , [DatabaseName] [nvarchar](256) NULL , [FileName] [nvarchar](256) NULL , [OwnerName] [nvarchar](256) NULL , [RoleName] [nvarchar](256) NULL , [TargetUserName] [nvarchar](256) NULL , [DBUserName] [nvarchar](256) NULL , [LoginSid] [image] NULL , [TargetLoginName] [nvarchar](256) NULL , [TargetLoginSid] [image] NULL , [ColumnPermissions] [int] NULL , [LinkedServerName] [nvarchar](256) NULL , [ProviderName] [nvarchar](256) NULL , [MethodName] [nvarchar](256) NULL , [RowCounts] [bigint] NULL , [RequestID] [int] NULL , [XactSequence] [bigint] NULL , [EventSequence] [bigint] NULL , [BigintData1] [bigint] NULL , [BigintData2] [bigint] NULL , [GUID] [uniqueidentifier] NULL , [IntegerData2] [int] NULL , [ObjectID2] [bigint] NULL , [Type] [int] NULL , [OwnerID] [int] NULL , [ParentName] [nvarchar](256) NULL , [IsSystem] [int] NULL , [Offset] [int] NULL , [SourceDatabaseID] [int] NULL , [SqlHandle] [image] NULL , [SessionLoginName] [nvarchar](256) NULL , [PlanHandle] [image] NULL , [GroupID] [int] NULL ) CREATE TABLE [dbo].[trc_AlteredObjects] ( [EventName] [nvarchar](128) NULL , [subclass_name] [nvarchar](128) NULL , [DBName] [nvarchar](128) NULL , [NTDomainName] [nvarchar](256) NULL , [NTUserName] [nvarchar](256) NULL , [HostName] [nvarchar](256) NULL , [ApplicationName] [nvarchar](256) NULL , [LoginName] [nvarchar](256) NULL , [Duration] [bigint] NULL , [StartTime] [datetime] NULL , [ServerName] [nvarchar](256) NULL , [ObjectName] [nvarchar](256) NULL , [ObjectType] [varchar](58) NOT NULL ) CREATE TABLE [dbo].[trc_CreatedUsersAndLogins] ( [EventName] [nvarchar](128) NULL , [subclass_name] [nvarchar](128) NULL , [DatabaseName] [nvarchar](256) NULL , [DatabaseID] [int] NULL , [NTDomainName] [nvarchar](256) NULL , [ApplicationName] [nvarchar](256) NULL , [LoginName] [nvarchar](256) NULL , [SPID] [int] NULL , [StartTime] [datetime] NULL , [ServerName] [nvarchar](256) NULL , [RoleName] [nvarchar](256) NULL , [TargetUserName] [nvarchar](256) NULL , [TargetLoginName] [nvarchar](256) NULL , [SessionLoginName] [nvarchar](256) NULL ) CREATE TABLE [dbo].[trc_DroppedUsersAndLogins] ( [EventName] [nvarchar](128) NULL , [subclass_name] [nvarchar](128) NULL , [DatabaseName] [nvarchar](256) NULL , [DatabaseID] [int] NULL , [NTDomainName] [nvarchar](256) NULL , [ApplicationName] [nvarchar](256) NULL , [LoginName] [nvarchar](256) NULL , [SPID] [int] NULL , [StartTime] [datetime] NULL , [ServerName] [nvarchar](256) NULL , [RoleName] [nvarchar](256) NULL , [TargetUserName] [nvarchar](256) NULL , [TargetLoginName] [nvarchar](256) NULL , [SessionLoginName] [nvarchar](256) NULL ) CREATE TABLE [dbo].[trc_ErrorLog] ( [EventName] [nvarchar](128) NULL , [DatabaseName] [nvarchar](256) NULL , [DatabaseID] [int] NULL , [NTDomainName] [nvarchar](256) NULL , [ApplicationName] [nvarchar](256) NULL , [LoginName] [nvarchar](256) NULL , [SPID] [int] NULL , [StartTime] [datetime] NULL , [ServerName] [nvarchar](256) NULL , [TextData] [ntext] NULL , [Severity] [int] NULL , [Error] [int] NULL ) CREATE TABLE [dbo].[trc_FileGrowAndShrink] ( [EventName] [nvarchar](128) NULL , [ServerName] [nvarchar](256) NULL , [DatabaseName] [nvarchar](256) NULL , [DatabaseID] [int] NULL , [NTDomainName] [nvarchar](256) NULL , [ApplicationName] [nvarchar](256) NULL , [LoginName] [nvarchar](256) NULL , [SPID] [int] NULL , [Duration] [bigint] NULL , [StartTime] [datetime] NULL , [EndTime] [datetime] NULL ) CREATE TABLE [dbo].[trc_FTSearch] ( [EventName] [nvarchar](128) NULL , [DatabaseName] [nvarchar](128) NULL , [DatabaseID] [int] NULL , [NTDomainName] [nvarchar](256) NULL , [ApplicationName] [nvarchar](256) NULL , [LoginName] [nvarchar](256) NULL , [SPID] [int] NULL , [StartTime] [datetime] NULL , [ServerName] [nvarchar](256) NULL , [IsSystem] [int] NULL ) CREATE TABLE [dbo].[trc_LogFileAutoGrowAndShrink] ( [EventName] [nvarchar](128) NULL , [DatabaseName] [nvarchar](256) NULL , [DatabaseID] [int] NULL , [NTDomainName] [nvarchar](256) NULL , [ApplicationName] [nvarchar](256) NULL , [LoginName] [nvarchar](256) NULL , [SPID] [int] NULL , [Duration] [bigint] NULL , [StartTime] [datetime] NULL , [ServerName] [nvarchar](256) NULL , [EndTime] [datetime] NULL ) CREATE TABLE [dbo].[trc_LoginFailed] ( [EventName] [nvarchar](128) NULL , [subclass_name] [nvarchar](128) NULL , [DatabaseName] [nvarchar](256) NULL , [DatabaseID] [int] NULL , [NTDomainName] [nvarchar](256) NULL , [ApplicationName] [nvarchar](256) NULL , [LoginName] [nvarchar](256) NULL , [SPID] [int] NULL , [StartTime] [datetime] NULL , [ServerName] [nvarchar](256) NULL , [SessionLoginName] [nvarchar](256) NULL ) CREATE TABLE [dbo].[trc_MemoryChangesEvents] ( [EventName] [nvarchar](128) NULL , [subclass_name] [nvarchar](128) NULL , [IsSystem] [int] NULL , [StartTime] [datetime] NULL , [ServerName] [nvarchar](256) NULL ) CREATE TABLE [dbo].[trc_MissingStatsAndPredicates] ( [EventName] [nvarchar](128) NULL , [DatabaseName] [nvarchar](256) NULL , [DatabaseID] [int] NULL , [NTDomainName] [nvarchar](256) NULL , [ApplicationName] [nvarchar](256) NULL , [LoginName] [nvarchar](256) NULL , [SPID] [int] NULL , [StartTime] [datetime] NULL , [ServerName] [nvarchar](256) NULL ) CREATE TABLE [dbo].[trc_ServerStarts] ( [EventName] [nvarchar](128) NULL , [subclass_name] [nvarchar](128) NULL , [DatabaseName] [nvarchar](256) NULL , [DatabaseID] [int] NULL , [NTDomainName] [nvarchar](256) NULL , [ApplicationName] [nvarchar](256) NULL , [LoginName] [nvarchar](256) NULL , [SPID] [int] NULL , [StartTime] [datetime] NULL , [ServerName] [nvarchar](256) NULL , [SessionLoginName] [nvarchar](256) NULL ) CREATE TABLE [dbo].[trc_SortAndHashWarnings] ( [EventName] [nvarchar](128) NULL , [subclass_name] [nvarchar](128) NULL , [DatabaseName] [nvarchar](256) NULL , [DatabaseID] [int] NULL , [NTDomainName] [nvarchar](256) NULL , [ApplicationName] [nvarchar](256) NULL , [LoginName] [nvarchar](256) NULL , [SPID] [int] NULL , [StartTime] [datetime] NULL , [ServerName] [nvarchar](256) NULL ) GO CREATE CLUSTERED INDEX [idx_EventClass_EventSubClass_ObjectType_DatabaseID] ON [dbo].[temp_trc] ( [EventClass] ASC, [EventSubClass] ASC, [ObjectType] ASC, [DatabaseID] ASC ) GO CREATE STATISTICS [stat_245575913_14_26_27_21_28_3] ON [dbo].[temp_trc]([StartTime], [ServerName], [EventClass], [EventSubClass], [ObjectType], [DatabaseID]) GO CREATE STATISTICS [stat_245575913_21_14_26] ON [dbo].[temp_trc]([EventSubClass], [StartTime], [ServerName]) GO CREATE STATISTICS [stat_245575913_21_27_28_3_14] ON [dbo].[temp_trc]([EventSubClass], [EventClass], [ObjectType], [DatabaseID], [StartTime]) GO CREATE STATISTICS [stat_245575913_27_14] ON [dbo].[temp_trc]([EventClass], [StartTime]) GO CREATE STATISTICS [stat_245575913_27_21_14_26] ON [dbo].[temp_trc]([EventClass], [EventSubClass], [StartTime], [ServerName]) GO CREATE STATISTICS [stat_437576597_10_11] ON [dbo].[trc_AlteredObjects]([StartTime], [ServerName]) GO CREATE STATISTICS [stat_405576483_8_9] ON [dbo].[trc_MissingStatsAndPredicates]([StartTime], [ServerName]) GO |
After creating the objects, we have to populate the config table:
1 2 3 4 5 6 7 8 |
INSERT INTO [dbo].[ProcessingTrace_Config] ([ServerName] ,[TracePath] ,[IsActive]) VALUES ('remoteServerA' ,'C:\Destination\remoteServerA' ,1) |
The table contains 3 columns:
- Server name – the name of the server which is audited
- Trace path – the local folder where the default trace files are stored for the server
- isActive – this flag indicates whether the files should be processed
Importing the default trace files
The SSIS package takes its configurations from the dbo.ProcessingTrace_Config table.
Then the ForEachLoop container executes for every record in the config table and it imports each trace file into a scrubbing table called dbo.temp_trc.
From there the default trace data is queried by event groups and merged into separate tables.
The idea is that since we do not know how often the default trace files are changing for each server, and since the files have a maximum size of 20Mb each (but they may be much smaller), it is actually more efficient to import them and merge them than to write custom logic to check which file was imported and which has not. (The performance overhead of importing 20Mb trace files and using the MERGE script is minimal. I performed a test by populating 1 million rows in each table by using Redgate’s Data Generator and even in such case the import was fast. )
Technically, the Robocopy script makes sure that the files are stored and updated on our local storage and later on we can schedule the SSIS package to import them at any time we would like.
The events are split in the following categories, and each category is represented by a database table:
- FileGrowAndShrink
- LogFileAutoGrowAndShrink
- ErrorLog
- SortAndHashWarnings
- MissingStatsAndPredicates
- FTSearch
- AlteredObjects
- CreatedUsersAndLogins
- DroppedUsersAndLogins
- LoginFailed
- ServerStarts
- MemoryChangesEvents
A typical merge operation is this, for sort and hash warnings. (the rest are in the SSIS package that you can download from the link at the bottom of the article.) The scripts can be viewed here.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 |
MERGE trc_SortAndHashWarnings AS target USING ( SELECT TE.name AS [EventName] , v.subclass_name , T.DatabaseName , t.DatabaseID , t.NTDomainName , t.ApplicationName , t.LoginName , t.SPID , t.StartTime , T.ServerName FROM [dbo].[temp_trc] T JOIN sys.trace_events TE ON T.EventClass = TE.trace_event_id JOIN sys.trace_subclass_values v ON v.trace_event_id = TE.trace_event_id AND v.subclass_value = t.EventSubClass WHERE te.name = 'Hash Warning' OR te.name = 'Sort Warnings' ) AS source ON target.StartTime = source.StartTime AND target.ServerName = source.ServerName WHEN NOT MATCHED BY TARGET THEN INSERT ( EventName , subclass_name , DatabaseName , DatabaseID , NTDomainName , ApplicationName , LoginName , SPID , StartTime , ServerName ) VALUES ( EventName , subclass_name , DatabaseName , DatabaseID , NTDomainName , ApplicationName , LoginName , SPID , StartTime , ServerName ); |
After extracting and merging the data, the last step is to delete all the files from the filesystem that are older than 1 day.
Note that the scheduling of the Robocopy and the SSIS package is individual and it depends on the systems which are audited. If the default trace files are overwritten often by the source system then we might want to run the Robocopy task and the SSIS package more often.
For the purpose of this article I have set up the SSIS Script Component to delete files older than 1 day.
Here is the C# script for the component:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 |
#region Namespaces using System; using System.Data; using Microsoft.SqlServer.Dts.Runtime; using System.Windows.Forms; using System.IO; // add this #endregion public void Main() { string directoryPath = Dts.Variables["User::TracePath"].Value.ToString(); string[] oldFiles = System.IO.Directory.GetFiles(directoryPath, "*.trc"); foreach (string currFile in oldFiles) { FileInfo currFileInfo = new FileInfo(currFile); if (currFileInfo.CreationTime < DateTime.Now.AddDays(-1)) { currFileInfo.Delete(); } } // TODO: Add your code here Dts.TaskResult = (int)ScriptResults.Success; } |
Conclusions
This article shows how the default trace logs of a number of SQL Servers can be aggregated and preserved on a centralized auditing server , and then imported into a central auditing database via an SSIS task that filters and merges the results into a number of tables that give a central record of a number of diverse events that are useful for first-line problem-diagnosis, such as database and log File growth and shrinkage, Error Log information, a variety of warnings, notice of created or altered or deleted database objects, users or logins, failed logins, server starts and memory change events.
Now we have all this information in one place for all our servers, we have the opportunity for first-line alerting for a number of signs that things are going wrong, and that we need to reach for our monitoring system to find out more about what is going on within that server, and maybe also database.
With this database in place we can then have a number of data mining possibilities for this data. We’ll do into more detail about this in a subsequent article.
The SSIS package is downloadable from the link at the head of the article, as is the SQL source of the scripts. You can view all the SQL merge scripts via the browser by clicking here.
DevOps, Continuous Delivery & Database Lifecycle Management
Go to the Simple Talk library to find more articles, or visit www.red-gate.com/solutions for more information on the benefits of extending DevOps practices to SQL Server databases.
Load comments