Click here to monitor SSC
  • Av rating:
  • Total votes: 11
  • Total comments: 3
Feodor Georgiev

Collect Your SQL Server Auditing and Troubleshooting Information Automatically

28 January 2014

Database delivery patterns & practices

STAGE 3 CONTINUOUS INTEGRATION

If you have a number of SQL Server instances with versions ranging from 2005 upwards, with a whole host of databases, and you want to be alerted about a number of diverse events that are useful for first-line problem-diagnosis and auditing, then Feodor's homebrew solution, using SSIS and Robocopy is likely to be what you're looking for.

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

  1. monitor the folder in a remote server  that contains the default trace files
  2. 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:

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:

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:

 INSERT INTO [dbo].[ProcessingTrace_Config]

           ([ServerName]

           ,[TracePath]

           ,[IsActive])

     VALUES

           ('remoteServerA'

           ,'C:\Destination\remoteServerA'

           ,1)

The table contains 3 columns:

  1. Server name – the name of the server which is audited
  2.  Trace path – the local folder where the default trace files are stored for the server
  3.  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 head of the article.) The scripts can be viewed here.

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:

#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.

This article is part of our database delivery patterns & practices series on Simple Talk.

Find more articles for version control, automated testing, continuous integration & deployment.

Feodor Georgiev

Author profile:

Feodor has been working with SQL Server since 2002, starting on the 2000 version and mixing it up as newer versions - 2005, 2008 and 2012 - were released. He specializes in database performance tuning, documentation and scalability management. He also works as project leader and mentor on SQL Server and Business Intelligence projects on Microsoft-based solutions. HIs specialties include: Database Architecture, Microsoft SQL Server Data Platform, Data Model Design, Database Design, Integration Solutions, Business Intelligence, Reporting, Performance Optimization, Big Data. When he is not busy with his DBA work, keeping up with the latest SQL Server tricks or sharing tips on forums, he writes articles on SQLConcept.com.

Search for other articles by Feodor Georgiev

Rate this article:   Avg rating: from a total of 11 votes.


Poor

OK

Good

Great

Must read
Have Your Say
Do you have an opinion on this article? Then add your comment below:
You must be logged in to post to this forum

Click here to log in.


Subject: Nice idea but ...
Posted by: Jeff_yao (not signed in)
Posted on: Wednesday, January 29, 2014 at 4:13 PM
Message: With a few hundred instances (lots of named instances), and 10% of instances will be gone by replaced with new ones or consolidated in a year, it will be a nightmare to maintain the RoboCopy script itself.

For trace collection, we actually only need to know one piece information, i.e. sql instance name.

So a better solution is to use PowerShell to do the following:
1. sql instance inventory collection system (can be combined with AD info for physical server name)
2. Execute the local trace collection script on each target sql instance
3. Write back the info collected back to a central repository

Nevertheless, for a small number of sql instances (yet not changing frequently), I think your solution is solid.

Subject: DTS Package is not working
Posted by: Abdul Majeed (not signed in)
Posted on: Tuesday, February 18, 2014 at 1:49 AM
Message: Hi,
Can you send me the DTS package as the attached package is not working

Thanks Majeed

Subject: Availability merge command
Posted by: luismarinaray@gmail.com (not signed in)
Posted on: Wednesday, February 19, 2014 at 8:05 AM
Message: Hi,

Excelent article, but if you are using MS Sql Server version 2005, how could I use the merge command ? , it is not available in 2005.

Thanks

 

Phil Factor
Searching for Strings in SQL Server Databases

Sometimes, you just want to do a search in a SQL Server database as if you were using a search engine like Google.... Read more...

 View the blog

Top Rated

Searching for Strings in SQL Server Databases
 Sometimes, you just want to do a search in a SQL Server database as if you were using a search engine... Read more...

Continuous Delivery and the Database
 Continuous Delivery is fairly generally understood to be an effective way of tackling the problems of... Read more...

The SQL Server Sqlio Utility
 If, before deployment, you need to push the limits of your disk subsystem in order to determine whether... Read more...

The PoSh DBA - Reading and Filtering Errors
 DBAs regularly need to keep an eye on the error logs of all their SQL Servers, and the event logs of... Read more...

MySQL Compare: The Manual That Time Forgot, Part 1
 Although SQL Compare, for SQL Server, is one of Red Gate's best-known products, there are also 'sister'... Read more...

Most Viewed

Beginning SQL Server 2005 Reporting Services Part 1
 Steve Joubert begins an in-depth tour of SQL Server 2005 Reporting Services with a step-by-step guide... Read more...

Ten Common Database Design Mistakes
 If database design is done right, then the development, deployment and subsequent performance in... Read more...

SQL Server Index Basics
 Given the fundamental importance of indexes in databases, it always comes as a surprise how often the... Read more...

Reading and Writing Files in SQL Server using T-SQL
 SQL Server provides several "standard" techniques by which to read and write to files but, just... Read more...

Concatenating Row Values in Transact-SQL
 It is an interesting problem in Transact SQL, for which there are a number of solutions and... Read more...

Why Join

Over 400,000 Microsoft professionals subscribe to the Simple-Talk technical journal. Join today, it's fast, simple, free and secure.