May 8, 2009 at 4:06 pm
Hello, i want to create an audit script, to audit record updates inside a table, and i want to store on a table that information. I want to know how can i store on a column the name of the column that was modified (updated) on the table that I'm auditing, in order to track only the column that was update, the previous value and the new value, date, time and user that did the update. Somebody can tell me how can i do this?
May 10, 2009 at 3:35 am
Look through creating Triggers, if you want to keep track of DDL and some DML changes then Defualt trace would be handy.
After looking at these if you still need any info give us a shout.
May 10, 2009 at 6:01 am
within a trigger, there is a couple of functions you can use you can use to determine if a column has changed:
IF (UPDATE(columnname) ) returns true or false, if you are testing a single column, so you could do something like this:
CREATE TRIGGER TR_WHATEVER
ON WHATEVER
FOR INSERT,UPDATE
AS
IF (UPDATE(DESCRIP) )
BEGIN
INSERT INTO AUDIT(WHATEVERID,NEWVAL,OLDVAL,UPDATEDDT)
SELECT INSERTED.WHATEVERID,
INSERTED.DESCRIP AS NEWVAL,
DELETED.DESCRIP AS OLDVAL,
GETDATE() AS UPDATEDDT
FROM INSERTED
INNER JOIN DELETED
ON INSERTED.WHATEVERID=DELETED.WHATEVERID
END
the other function, COLUMNS_UPDATED, uses a bitmask, and references columns by their ordinal position...NOT by name, to determine whether the columns have had changes:
/*Check whether columns 2 thru 8 have been updated.
for example ,If any or all
columns 2, 3 or 4 have been changed, create an audit record. The
bitmask is: power(2,(2-1))+power(2,(3-1))+power(2,(4-1)) = 14. To test
whether all columns 2, 3, and 4 are updated, use = 14 instead of > 0
(below).
this one specifically is for 32 thru 8 is:
select power(2,(3-1))
+ power(2,(4-1))
+ power(2,(5-1))
+ power(2,(6-1))
+ power(2,(7-1))
+ power(2,(8-1)) = 252*/
IF (substring(COLUMNS_UPDATED(),1,1) & 252 )>0
--do stuff
Lowell
May 10, 2009 at 1:04 pm
adonado (5/8/2009)
I want to know how can i store on a column the name of the column that was modified (updated) on the table that I'm auditing, in order to track only the column that was update, the previous value and the new value, date, time and user that did the update.
What do you want to do if more than one column was updated?
[font="Times New Roman"]-- RBarryYoung[/font], [font="Times New Roman"] (302)375-0451[/font] blog: MovingSQL.com, Twitter: @RBarryYoung[font="Arial Black"]
Proactive Performance Solutions, Inc. [/font][font="Verdana"] "Performance is our middle name."[/font]
May 11, 2009 at 8:57 am
Thank yo i will try it, and you know how can i get the name of the updated column?
May 11, 2009 at 9:04 am
using COLUMNS_UPDATED, you can't, i guess you'd have to write your trigger to do each column individually, if that's what you wanted to do:
IF (UPDATE(DESCRIP) )
BEGIN
[same code example]
END
IF (UPDATE(COLUMN2) )
BEGIN
[same code example, just change the column names]
END
IF (UPDATE(COLUMN3) )
BEGIN
[same code example, just change the column names]
END
IF (UPDATE(COLUMN4) )
BEGIN
[same code example, just change the column names]
END
i would think it is easier to simply capture all the changes,and compare on demand for specific queiitons.
Lowell
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply