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


Audit table design


Audit table design

Author
Message
kwoznica
kwoznica
SSC Veteran
SSC Veteran (227 reputation)SSC Veteran (227 reputation)SSC Veteran (227 reputation)SSC Veteran (227 reputation)SSC Veteran (227 reputation)SSC Veteran (227 reputation)SSC Veteran (227 reputation)SSC Veteran (227 reputation)

Group: General Forum Members
Points: 227 Visits: 475
Hello all,

I am building the backend of a web application and came across a scenario for the audit logging table design that I would to receive some opinions on.

There are 2 audit tables.

Table: AuditType - Contains all of the audit types
Fields: AuditTypeID, Type, Description, CreatedBy, CreatedOn, ModifiedBy, ModifiedOn

Table: AuditLog - The associated record for each Audit Type/activity we would like to record.
Fields: AuditLogID, UserID, AuditInformation, AuditDate, AuditTypeID, CreatedBy, CreatedOn, ModifiedBy, ModifiedOn

Those two tables will be reacting to the following events (AuditType): Password Change, Logins, Logouts, Login Failure, SessionTimeout, LoginCreation, LoginDeletion

The client would like to record more detail of what occurs with the user login information. Below are two tables with fields for each login profile.

Table: UserProfile - Contains basic user login information
fields: UserDetailId, UserID, FirstName, LastName, BusinessPhone, CellPhone, PrimaryEmail, SecondaryEmail, StreetAddress, CityID, Zip, BusinessTitle, WebAccess, Createdby, Createdon, ModifiedBy, ModifiedOn.

Table:UserCustomerRelation - Linking table to associate UserProfile Records to Customers
Fields: UserCustRelationID, UserID, CustomerId, FromDate, ToDate, CreatedBy, CreatedOn, ModifiedBy, ModifiedOn


Now if a field in the UserProfile table is modified we would like that action logged. For instance if a user with a login of jsmith had 2 new customers added to his login via the UserCustomerRelation table, those new record creations would be logged.

My initial thought is to expand the AuditTypes to include new types: Customer Add, Customer Remove,Street Address Change, Primary Email Address, First Name, Last Name, Web Access.
This way when any of these fields in the UserProfile table are modified a trigger would write to the AuditLog table with the correct type.

Is this thought the optimal way of logging such activity?
what is a more optimal way to perform logging?
Would a separate trigger need to be created for each field we wish to log?
eheraux
eheraux
Grasshopper
Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)

Group: General Forum Members
Points: 13 Visits: 123

Would a separate trigger need to be created for each field we wish to log?

No. Inside one trigger you can test whether a column was changed by using the UPDATE(fieldname) built-in function. This tests whether that field had a change as a result of the calling INSERT or UPDATE to the table that's involved.
Your triggers could look something like this for every action you want to log:

CREATE TRIGGER MyTRigger
ON UserCustomerRelation
AFTER UPDATE,INSERT

IF UPDATE(LastName)
INSERT INTO AuditLog(UserID, AuditInformation, AuditDate, AuditTypeID)
SELECT UserID ,'New LastName was added: ' + LastName,CURRENT_TIMESTAMP,[IDforCustomerAdd]
FROM INSERTED

GO


...where you would repeat that UPDATE() test for each important field that might have changed, all inside of the same single trigger.

Is this thought the optimal way of logging such activity?
what is a more optimal way to perform logging?


That highly depends on what it is you'd like to get out of logging and how you plan to analyze/report on the audits. What does management actually want to know down the road? What kind of histories do they want to see?

The way you're looking to do it seems like an awful lot of records every time someone updates more than one aspect of their profile. If a woman gets married and changes last name and address, for example, your approach here requires more than one audit record just for that one profile update. Not very streamlined, but we don't know here what sort of history you'll want to see down the road.

Some shops are happy to prevent any UPDATEs to the table from the application, they'll only add a whole new record for each profile change, keep the ID# (which you could store uniquely in another table) and date stamp it to be the current record for that ID, while the old record is marked with the same date stamp as its expiration date. That way you could produce a whole history of full record changes for any ID you want without any audit procedures & triggers and the processing & space overhead that comes with them. But that's just one approach.

Hth,
-Ed



Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)

Group: General Forum Members
Points: 45241 Visits: 39927
eheraux (2/17/2014)

Would a separate trigger need to be created for each field we wish to log?

No. Inside one trigger you can test whether a column was changed by using the UPDATE(fieldname) built-in function. This tests whether that field had a change as a result of the calling INSERT or UPDATE to the table that's involved.


Oooh, be careful about that. The UPDATE(fieldname) function detects only whether or not the field was part of the triggering action, not whether the value actually changed or not. If you update (for example) a LastName column from "Smith" to "Smith", it will still be registered as a "change" even though the value didn't actually change. You'd need to compare the INSERTED to the DELETED tables to find out if the value actually changed. Of course, you'd use the UPDATE(filedname) function as the "short circuit" to see whether the column needs such a check or not. Shifting gears a bit, you wouldn't even need that if the trigger was doing "whole row" auditing instead of "field level" auditing.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
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