SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Triggers for Auditing


Triggers for Auditing

Author
Message
cravi_kumar
cravi_kumar
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
Points: 1 Visits: 10
the solution has one more problem. the original update statement may update only one column. by forcing an update of all the columns, we will be taxing the servers. in case of the database implementation where the after trigger is used for auditing, this can be expensive. same in the case of implementations with replication



Richard Moldwin
Richard Moldwin
SSC-Enthusiastic
SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)

Group: General Forum Members
Points: 184 Visits: 15

I am concerned about the incorrect and unsubstantiated statements made both in the article and by some of the posters. By now, most of the mistakes have been corrected, but I really wish people would triple-check their sources and code before posting.

There have been many articles written about triggers for auditing, and IMO, none can be used as a generic solution. The issue of auditing the entire record vs. just the changed fields (MUCH more difficult) is not usually addressed properly. The issue of trigger (or SP) overhead for auditing is almost never analyzed with real data. Rarely is the use of transaction log auditing discussed in any depth. The issue of auditing "meaningless" foreign keys (and not the "readable" value fom the related tables) is a serious concern in these solutions. The issue of "single table for all audits" vs. "one audit table per table" is another area that is usually ignored.

Like many others, I have created very complicated trigger-based and client app-based auditing solutions. I have had to design my database tables and app from the ground up with my own style of auditing solution in mind. In my case, that means I must have a single autoinc-integer primary key and timestamp for every table in the database. For my purposes, the client app must be able to instantly pull up a list of all the changes to any record in a database of hundreds of tables. The client app must also be able to generate a sequential list of all changes made to the database over an arbitrary time period, or made by an arbitrary user. Obviously, most multi-table trigger solutions would fail in this scenario. Transaction log-based solutions are one possible way to go here, but unfortunately I had to roll my own.

My point is this: it's unlikely that an unmodified generic solution will work for any particular database. OTOH, it's always nice to see how other people approach these problems - there's usually something to learn - even from the mistakes.


G.R.Prithiviraj Kulasingham
G.R.Prithiviraj Kulasingham
Mr or Mrs. 500
Mr or Mrs. 500 (565 reputation)Mr or Mrs. 500 (565 reputation)Mr or Mrs. 500 (565 reputation)Mr or Mrs. 500 (565 reputation)Mr or Mrs. 500 (565 reputation)Mr or Mrs. 500 (565 reputation)Mr or Mrs. 500 (565 reputation)Mr or Mrs. 500 (565 reputation)

Group: General Forum Members
Points: 565 Visits: 367

SprocKing says: "I implemented audit triggers on tables with both text and image columns in them. The problem is that you can't refer to binary columns in the inserted and deleted tables."

here is an additional issue with the article.

1. Instead of triggers overright your update statement and you can't refer blob columns. That means you have no mechanism of updating the blob column through instead of triggers.

2. let em clarify on what I mentioned. If you update the blob fields using UPADTETEXT or WRITETEXT, triggers will not fire. Triggers will fire only if you update them through Update statement. (If you disagree check the example give here.) That means Audit trigger is not a reliable solution if you have ad-hoc queries and blob columns.

Here is the example.

I am using SQL Server 2000 Sp4 with all the latest hotfixes.

IF Object_ID('TriggerTest') is NOT NULL
Drop table TriggerTest
GO
Create table TriggerTest
(
IntID int identity(1,1) primary key clustered,
Field1 varchar(20) not NULL,
Field2 text NOT NULL Default(''),
Last_Modified datetime NOT NULL default(GetDate())
)

GO

Create Trigger trg_TriggerTest_Ins_Upd On TriggerTest INSTEAD of Update
As
Update TriggerTest Set
Field1 = IsNULL(I.Field1, TriggerTest.Field1),
Last_Modified =CURRENT_TIMESTAMP
From Inserted I
Where I.IntID = TriggerTest.IntID
GO

Set IDENTITY_INSERT TriggerTest ON
Insert TriggerTest (IntID, Field1) Values(1, 'Record 1')
Set IDENTITY_INSERT TriggerTest OFF

Select * from TriggerTest

WAITFOR DELAY '00:00:00.500'
Update TriggerTest Set Field2 ='Row 1' Where IntID =1
Select * from TriggerTest

WAITFOR DELAY '00:00:00.500'
DECLARE @ptrval binary(16)
SELECT @ptrval = TEXTPTR(Field2)
FROM TriggerTest
WHERE IntID =1
WRITETEXT TriggerTest.Field2 @ptrval 'The text column for row 1 is added through WRITETEXT.'
Select * from TriggerTest

WAITFOR DELAY '00:00:00.500'
Declare @LEN int

SELECT @ptrval = TEXTPTR(Field2), @Len= DataLength(Field2)
FROM TriggerTest
WHERE IntID =1
UPDATETEXT TriggerTest.Field2 @ptrval @LEN 0 ' The text column for row 1 is updated through UPDATETEXT'
Select * from TriggerTest

WAITFOR DELAY '00:00:00.500'
Update TriggerTest Set Field1 ='record1' Where IntID =1
Select * from TriggerTest



Cheers,
Prithiviraj Kulasingham

http://preethiviraj.blogspot.com/
Richard Moldwin
Richard Moldwin
SSC-Enthusiastic
SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)

Group: General Forum Members
Points: 184 Visits: 15

Preethiviraj Kulasingham

1. "Instead of triggers overright your update statement and you can't refer blob columns. That means you have no mechanism of updating the blob column through instead of triggers."

This is a bit misleading. The subject of the article is auditing via triggers, not updating the same table's blobs via triggers. Blob fields are accessible for "INSTEAD OF" auditing in the Inserted and Deleted tables.

See BOL:

"SQL Server 2000 does not allow text, ntext, or image column references in the inserted and deleted tables for AFTER triggers; however, these column references are allowed for INSTEAD OF triggers."

2. This is interesting. Although it is true that UPDATETEXT/WRITETEXT (and potentially bulk copies) are not logged and do not fire triggers, these functions are not commonly used. Most blob updates are performed through regular Update statements that are logged and fire triggers. However, when UPDATETEXT/WRITETEXT statements are used, it is simple enough to manually update the audit table, e.g. in the same SP. I don't think this is a reason to reject the technique. It's just an unusual application-specific quirk that we may need to take into account when writing audit procedures.


Sergiy
Sergiy
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10212 Visits: 11958

Another issue nobody noticed ( ):

IT'S NESTED TRIGGER

INSTEAD OF UPDATE trigger makes UPDATE to the same table and fires itself.

I don't see in trigger any mean to stop this endless loop.

But in general view:

wouldn't it be easier to have separate table to log changes:

ObjectId, PK_Id, DateRecorded, UserId.

Triggers on monitored tables will just add records to this table.
Easy and reliable.
And you don't need to care about freaky datatypes (did anybody think about user defined ones?) in monitored tables.


G.R.Prithiviraj Kulasingham
G.R.Prithiviraj Kulasingham
Mr or Mrs. 500
Mr or Mrs. 500 (565 reputation)Mr or Mrs. 500 (565 reputation)Mr or Mrs. 500 (565 reputation)Mr or Mrs. 500 (565 reputation)Mr or Mrs. 500 (565 reputation)Mr or Mrs. 500 (565 reputation)Mr or Mrs. 500 (565 reputation)Mr or Mrs. 500 (565 reputation)

Group: General Forum Members
Points: 565 Visits: 367

Hi Richard,

I Agree that INSERTED and DELETED tables have blob fields within INSTEAD OF triggers. Thank you for correcting the mistake. However, I disagree with what you say with UPDATETEXT/WRITETEXT. If you are using stored procedures to update the tables, you can always refer the additional column (with less cost) and update last_modified field. Why do you want triggers on the first place. Triggers is one of the mechanism where we can control ad-hoc queries. What about adhoc queries using UPDATETEXT/WRITETEXT? It shows that, triggers is not the best solutions.

On the other hand, triggers could be used against tables which do not have blob fields. I use it. it is one of the best methods to add audit component against, existing table.



Cheers,
Prithiviraj Kulasingham

http://preethiviraj.blogspot.com/
Richard Moldwin
Richard Moldwin
SSC-Enthusiastic
SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)

Group: General Forum Members
Points: 184 Visits: 15

"What about adhoc queries using UPDATETEXT/WRITETEXT?"

I would never allow such a thing, unless it was in a custom SP that updated the audit table in later statement. The same is true if you update a field in the original table: I would never allow it outside a custom SP. Therefore, I would not worry about the trigger-firing issue. But it is good that you pointed out this undocumented (in BOL, AFAIK) problem.

I would guess that your need to write/update text blobs line by line is very unusual. I guess that >90% of databases will not encounter this issue. But if you need it, you need it!

Good luck,

Rich


Richard Moldwin
Richard Moldwin
SSC-Enthusiastic
SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)SSC-Enthusiastic (184 reputation)

Group: General Forum Members
Points: 184 Visits: 15

"On the other hand, triggers could be used against tables which do not have blob fields. I use it. it is one of the best methods to add audit component against, existing table."

I just re-read your post, and I think I understand you point a bit better. I think it is reasonable to write audits into a text/ntext field, although I have not seen anyone else doing that. You could write into the same record or into a blob in another audit table (This may be easier and more flexible). However, in either case, you should be able to write to the blob field inside an "Instead Of" trigger.

In response to the previous post by Serqiy, this does NOT fire reentrant/recursive triggers by default. I don't know what will happen if you turn on the recursive_triggers option - but I would not want to try it.)


Hugo Kornelis
Hugo Kornelis
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10809 Visits: 11967

Hi Sergiy,

There's no need to. An INSTEAD OF UPDATE trigger will enver fire on an UPDATE statement that is executed in the context of the trigger. Cut and pastte the code below in Query Analyzer for a quick proof.

CREATE TABLE Test (A int NOT NULL PRIMARY KEY,
B int)
go
INSERT INTO Test (A, B)
VALUES (1, 1)
go
CREATE TRIGGER TestTrig
ON Test
INSTEAD OF UPDATE
AS
PRINT 'Trigger nest level ' + CAST(TRIGGER_NESTLEVEL() AS varchar(3))
UPDATE Test
SET B = (SELECT inserted.B
FROM inserted
WHERE inserted.A = Test.A)
WHERE EXISTS (SELECT inserted.B
FROM inserted
WHERE inserted.A = Test.A)
go
UPDATE Test
SET B = 2
WHERE A = 1
go
SELECT * FROM Test
go
DROP TRIGGER TestTrig
DROP TABLE Test
go

Best, Hugo




Hugo Kornelis, SQL Server MVP
Visit my SQL Server blog: http://sqlblog.com/blogs/hugo_kornelis
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