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


Audit script


Audit script

Author
Message
adonado
adonado
Forum Newbie
Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)

Group: General Forum Members
Points: 8 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?
maechismo_8514
maechismo_8514
SSCrazy
SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)

Group: General Forum Members
Points: 2316 Visits: 2228
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.
Lowell
Lowell
SSC-Dedicated
SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)

Group: General Forum Members
Points: 37207 Visits: 40280
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

--
help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

RBarryYoung
RBarryYoung
SSCoach
SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)

Group: General Forum Members
Points: 19652 Visits: 9518
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."
adonado
adonado
Forum Newbie
Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)

Group: General Forum Members
Points: 8 Visits: 8
Thank yo i will try it, and you know how can i get the name of the updated column?
Lowell
Lowell
SSC-Dedicated
SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)

Group: General Forum Members
Points: 37207 Visits: 40280
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

--
help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

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