Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Creating a generic audit trigger with SQL 2005 CLR


Creating a generic audit trigger with SQL 2005 CLR

Author
Message
David Ziffer
David Ziffer
SSC-Enthusiastic
SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)

Group: General Forum Members
Points: 147 Visits: 203
Comments posted to this topic are about the content posted at http://www.sqlservercentral.com/columnists/dziffer/creatingagenericaudittriggerwithsql2005clr.asp
Joe Blow-346186
Joe Blow-346186
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 1
I have to say that, as far as database design and good coding practices go, this solution is definitely not something that I would recommend. Your idea of having a single audit table with Row-Id (1) works only for single-column primary keys, and (2) would result in HUGE overhead for inserts, updates, and deletes whenever more than one column is affected. If I insert one row into a table that has 80 columns, your trigger would add the additional overhead of inserting 80 rows, one per column. No way would a well-educated DBA allow or encourage this to occur.

This type of coding/behavior is a more OO approach to database development and I've seen a lot of inexperienced-database-developers-who-are-good-application-developers design such tables. OO to Relational mapping is hard, no question, but a relational database is not object-oriented and, when you try to make it such (as with this generic design), you are causing more headaches than creating an audit table and trigger for each table. IMO, this is an example of the reasons most DBAs will not allow CLR code to be executed on their server. This is just an example of a .NET programmer doing something in .NET that should be done in T-SQL.

Scott Whigham
LearnSqlServer.com - tutorials for SQL Server 2005 and SQL 2000
Ninja's_RGR'us
Ninja's_RGR'us
SSC-Insane
SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)

Group: General Forum Members
Points: 22223 Visits: 9671

Totally agree with Scott on this one.

What happens if you delete 250 000 rows from a table with 80 columns???

How do you recreate the whole history of a single row with a select query??? (All the columns of the row at each version of its life).

BTW I didn't read the whole thing but I seems you are having problems identifying the base table name from within the trigger. Maybe you can use this code somehow to extract the basetable name (from sql 2000).

Select Object_name(Parent_obj) as BaseTableName from dbo.SysObjects where id = @@PROCID

Where @@PROCID is the id of the trigger in sysobjects. This variable is available and set within the trigger and any other procedure for that matter.


Larry Aue
Larry Aue
SSC-Enthusiastic
SSC-Enthusiastic (161 reputation)SSC-Enthusiastic (161 reputation)SSC-Enthusiastic (161 reputation)SSC-Enthusiastic (161 reputation)SSC-Enthusiastic (161 reputation)SSC-Enthusiastic (161 reputation)SSC-Enthusiastic (161 reputation)SSC-Enthusiastic (161 reputation)

Group: General Forum Members
Points: 161 Visits: 668

Agree. Stick to VB.

It does give some good insight into .NET, tho.





eric g
eric g
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 1
I would have gotten more out of the note if the lines didn't extend past the limits of my fully expanded browser. Recommend either not preformatting the text or using a more reasonable line width.
StrateSQL
StrateSQL
Valued Member
Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)

Group: General Forum Members
Points: 55 Visits: 212
My god... I have to agree with the previous posts. This type of trigger is a wholly bad idea. Besides the massive amounts of overhead in splitting each column out from the table for each update, there will also be the contention between tables as evey table in the database attempts to write to a single audit table.

And as RGR mentioned, how do you get this data back out overly complex SQL queries?
Marc Brooks
Marc Brooks
SSC-Enthusiastic
SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)

Group: General Forum Members
Points: 103 Visits: 19
Any of you nay sayers (not that you are wrong) have any better plans? What do YOU suggest?



Ninja's_RGR'us
Ninja's_RGR'us
SSC-Insane
SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)

Group: General Forum Members
Points: 22223 Visits: 9671

A solution to this problem has already been created on this site. Search the script section with the keywords triggers and (generated, concatenated... sorry don't remember the name).

Basically it's a script that creates an audit table for each table in the system. It also creates the trigger that audits the data. I don't remember if it creates only the code or if it generates the objects as well. But it was working great as far as I remember.


StrateSQL
StrateSQL
Valued Member
Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)

Group: General Forum Members
Points: 55 Visits: 212
I have a template that I put together for CodeSmith that I use. It works for a single or multiple tables. Though I should probably update it for SQL Server 2005 to possibly use an audit schema for the audit tables.
George Palacean
George Palacean
SSC-Enthusiastic
SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)

Group: General Forum Members
Points: 134 Visits: 186
I don't think it's a good idea to audit ALL tables in the database.

For the most important tables (which usually are small so the overhead is minimal), I use the following solution (SQL 2005):

The logging table (only one for the entire database):

create table DMLLogs(
DMLLogID int identity primary key,
TableName nvarchar (128),
DateCreated datetime DEFAULT (getdate()),
OldValues xml NULL,
NewValues xml NULL)


The trigger for the table which you want to audit; The only thing that needs to be changed for another table is the table name. You can use the solution presented early in this post:
Select @TableName = Object_name(Parent_obj)
from dbo.SysObjects
where id = @@PROCID;
in this case the trigger will be exactly the same for all audited tables

create trigger MyTable_T_Log on MyTable
for insert, update, delete
as
declare @i xml, @d xml
set @i = (select * from inserted for xml auto)
set @d = (select * from deleted for xml auto)
exec LogDMLEvent
@TableName = 'MyTable',
@Deleted = @D,
@Inserted = @I

The procedure LogDMLEvent is:
create procedure LogDMLEvent
@TableName sysname,
@Deleted xml,
@Inserted xml
as
if @Deleted is not null or @Inserted is not null
insert into DMLLogs (TableName, OldValues, NewValues)
values (@TableName, @Deleted, @Inserted)

you can include in this procedure (and in the DMLLogs table) also the user name, connection info ....

So in the logging table you will have xml representations of inserted and deleted tables. You can very easy put them into a view to mimic the original table structure (one view for each table).
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search