Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Audit script Expand / Collapse
Author
Message
Posted Friday, May 08, 2009 4:06 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, March 04, 2010 6:04 AM
Points: 2, Visits: 8
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?
Post #713404
Posted Sunday, May 10, 2009 3:35 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Friday, August 24, 2012 8:11 AM
Points: 1,097, Visits: 2,157
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.

Post #713681
Posted Sunday, May 10, 2009 6:01 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 2:26 PM
Points: 12,744, Visits: 31,071
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

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #713702
Posted Sunday, May 10, 2009 1:04 PM


SSCrazy Eights

SSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy Eights

Group: General Forum Members
Last Login: Friday, March 28, 2014 2:25 PM
Points: 9,902, Visits: 9,479
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?


-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
Post #713756
Posted Monday, May 11, 2009 8:57 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, March 04, 2010 6:04 AM
Points: 2, Visits: 8
Thank yo i will try it, and you know how can i get the name of the updated column?
Post #714196
Posted Monday, May 11, 2009 9:04 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 2:26 PM
Points: 12,744, Visits: 31,071
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

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #714202
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse