Sunday, January 22, 2017

Re: audit trail functionality in database model

Enrico,

the DB trigger approach sounds very exciting to me because I really need to be sure that there is no way to manipulate records without audit trail. I also would be very interested in the trigger code for MySQL you mentioned.
OK.  I'll append some sample code below.

You also mentioned that you did something similar in the past, what was your approach to store information in the audit trail table? At the moment, I have two ways in front of me and I am not quite sure which way to go. Assuming my primary table (rooms) stores the fields id, room, number, size and version.

So I could go for one record for each change with audit trail table fields like id, rooms_id, room_old, room_new, number_old, number_new, size_old, size_new, version_old, version_new.
Or with a record for each field, id, rooms_id, field, old, new. There for every field a record is listed.

Do you know other suitable approaches to store audit trail information or did you go one of the listed ways? My main aim here again is to be able to build reasonable audit trail views where a user can see the history of a record with easy query's behind it.
My approach was one audit record per changed primary record,
not one audit record per changed primary field.  More like your
1st example above. 

But there's no need to store old and new values in the audit table.
Just store new values in the audit table.  You can find the old value
in a previous row of the audit table (sorted by creation time of the
audit table records), from when it was a new value being inserted
or updated.

Make sure you store all new values in the audit table, including the
first INSERT.  Then you can see a complete audit trail in the audit
tables, even if the value has never changed.  In a previous project,
I made the mistake of only putting old values into the audit tables,
after they changed in the primary tables.  So, I had to look at the
audit tables for all old values and at the primary tables for the
current value, which was more complicated.

Be sure to use triggers for DELETE, not just INSERT and UPDATE.
Otherwise, the audit table won't have a record of whether the
row was deleted.

Here are a set of tables (primary and audit) and triggers (INSERT,
UPDATE, and DELETE) for a typical table in my DB.  This is valid
MySQL code.  In this code, you'll see some other conventions I
always follow:

- Naming conventions of:
   -- Tables (prefixed with app name ("ITF" in this case))
   -- PKs (table name, plus suffix "_id")
   -- Constraints (prefixes like "pk_", fk1_", "fk2_", etc for PK and
        potentially multiple FKs)
   -- Audit tables (prefixed with app name plus "A")
   -- Triggers ("ai_", "au_", "ad_" prefixes for audit triggers for
        INSERT, UPDATE, and DELETE)

- All primary tables contain these extra fields which dramatically
   reduce the number of times you have to go to the audit tables:
   -- create_user (string name of user who created row)
   -- create_dt (date/time of row creation)
   -- update_user (string name of user who last updated row)
   -- update_dt (date/time of last row update)

- All primary tables contain this extra field, which I use to track
   the status of the row (active, inactive, archived, etc.).  I never
   actually delete a row.  Just mark it inactive, which makes
   undelete possible w/o having to go to the audit table.
   -- status_id

- Each audit table has exactly the same fields as its primary table,
   plus 3 additional fields:
   -- audited_change_user (string name of user who made the change)
   -- audited_change_dt (date/time time of the change.'
   -- audited_change_type ('INSERT', 'UPDATE', or 'DELETE')

- Audit tables have no need for unique, FK, or PK constraints. 
   Just values.

Here's the code:

--
-- ITF_PRODUCT
--

DROP TABLE IF EXISTS itf_product;
CREATE TABLE itf_product
 (itf_product_id                 INTEGER      NOT NULL AUTO_INCREMENT
                                                       COMMENT 'Primary key'
 ,name                           VARCHAR(255) NOT NULL COMMENT 'Unique user-assigned and user-visible name'
 ,descrip                        VARCHAR(255) NOT NULL COMMENT 'Description'
 ,notes                          VARCHAR(255) NOT NULL COMMENT 'User notes'
 ,create_user                    VARCHAR(255) NOT NULL COMMENT 'User who created this database row.  String, not foreign key, to preserve history when users are deleted.'
 ,create_dt                      DATETIME     NOT NULL COMMENT 'Date and time of creation of this database row.'
 ,update_user                    VARCHAR(255) NOT NULL COMMENT 'User who last updated this database row.  String, not foreign key, to preserve history when users are deleted.'
 ,update_dt                      DATETIME     NOT NULL COMMENT 'Date and time of last update of this database row.'
 ,status_id                      INTEGER      NOT NULL COMMENT 'The status of the data in this database row (active, inactive, archived, etc.).  FK to itf_dict value of category STATUS_LOOKUP.'
 ,CONSTRAINT pk_product PRIMARY KEY (itf_product_id)
 )
  COMMENT='Products'
  ENGINE=InnoDB
;

ALTER TABLE     itf_product
 ADD CONSTRAINT fk1_product
    FOREIGN KEY fk1_product (status_id) REFERENCES itf_dict (itf_dict_id)
;

-- Disallow multiple products with same name.
-- No, we really want to disallow only for records with STATUS=ACTIVE,
-- which can't be done here with a UNIQUE constraint, so this is enforced
-- in the Java BO code instead of here.
-- CREATE UNIQUE INDEX ak1_product ON itf_product (name);

GRANT SELECT, INSERT, UPDATE, DELETE ON itf_product to itfweb;

DROP TABLE IF EXISTS itfa_product;
CREATE TABLE itfa_product
 (audited_change_user            VARCHAR(255) NOT NULL COMMENT 'User who made this change.  String, not foreign key, to preserve history when users are deleted.'
 ,audited_change_dt              DATETIME     NOT NULL COMMENT 'Date and time of this change.'
 ,audited_change_type            VARCHAR(255) NOT NULL COMMENT 'INSERT, UPDATE, or DELETE.  No need for lookup in ITF_DICT since there are only these 3 types of triggers.'
 ,itf_product_id                 INTEGER          NULL COMMENT 'Copied from audited table.'
 ,name                           VARCHAR(255)     NULL COMMENT 'Copied from audited table.'
 ,descrip                        VARCHAR(255)     NULL COMMENT 'Copied from audited table.'
 ,notes                          VARCHAR(255)     NULL COMMENT 'Copied from audited table.'
 ,create_user                    VARCHAR(255)     NULL COMMENT 'Copied from audited table.'
 ,create_dt                      DATETIME         NULL COMMENT 'Copied from audited table.'
 ,update_user                    VARCHAR(255)     NULL COMMENT 'Copied from audited table.'
 ,update_dt                      DATETIME         NULL COMMENT 'Copied from audited table.'
 ,status_id                      INTEGER          NULL COMMENT 'Copied from audited table.'
 )
  COMMENT='Audit table.  No need for constraints.'
  ENGINE=InnoDB
;

GRANT SELECT, INSERT, UPDATE, DELETE ON itfa_product to itfweb;

-- DROP TRIGGER itft_ai_product;
DELIMITER ;;
CREATE TRIGGER itft_ai_product
BEFORE INSERT
ON itf_product
FOR EACH ROW
BEGIN
    -- Purpose: Inserts an audit record into audit table.
    --
    -- MODIFICATION HISTORY
    -- Person        Date           Comments
    -- ---------     ----------     -------------------------------------------
    -- Fred Stluka   2/12/2007      Original version.
    --
    INSERT INTO itfa_product
        (audited_change_user   
        ,audited_change_dt      
        ,audited_change_type
        ,itf_product_id
        ,name
        ,descrip
        ,notes
        ,create_user
        ,create_dt
        ,update_user
        ,update_dt
        ,status_id
        )
    VALUES
        (NEW.update_user
        ,SYSDATE()
        ,'INSERT'
        ,1 + (SELECT IFNULL(MAX(itf_product_id),0) from itf_product)
                -- Can't just use NEW.itf_product_id.  AUTO_INCREMENT
                -- hasn't yet generated a non-zero value.  This works OK
                -- as long as the highest generated value hasn't been
                -- deleted from the table.
                --
                -- Can't use:  1 + (SELECT MAX(itf_product_id) from itf_product)
                -- because it causes the first INSERT to fail.
                -- MAX comes up NULL and gets added to 1 which produces NULL.
                -- IFNULL fixes that.
                --
                -- Could perhaps use an AFTER trigger instead of a BEFORE
                -- trigger, and NEW.itf_product_id would work??
        ,NEW.name
        ,NEW.descrip
        ,NEW.notes
        ,NEW.create_user
        ,NEW.create_dt
        ,NEW.update_user
        ,NEW.update_dt
        ,NEW.status_id
        );
END;
;;
DELIMITER ;

-- DROP TRIGGER itft_au_product;
DELIMITER ;;
CREATE TRIGGER itft_au_product
BEFORE UPDATE
ON itf_product
FOR EACH ROW
BEGIN
    -- Purpose: Inserts an audit record into audit table.
    --
    -- MODIFICATION HISTORY
    -- Person        Date           Comments
    -- ---------     ----------     -------------------------------------------
    -- Fred Stluka   2/12/2007      Original version.
    --
    INSERT INTO itfa_product
        (audited_change_user   
        ,audited_change_dt      
        ,audited_change_type
        ,itf_product_id
        ,name
        ,descrip
        ,notes
        ,create_user
        ,create_dt
        ,update_user
        ,update_dt
        ,status_id
        )
    VALUES
        (NEW.update_user
        ,SYSDATE()
        ,'UPDATE'
        ,NEW.itf_product_id
        ,NEW.name
        ,NEW.descrip
        ,NEW.notes
        ,NEW.create_user
        ,NEW.create_dt
        ,NEW.update_user
        ,NEW.update_dt
        ,NEW.status_id
        );
END;
;;
DELIMITER ;

-- DROP TRIGGER itft_ad_product;
DELIMITER ;;
CREATE TRIGGER itft_ad_product
BEFORE DELETE
ON itf_product
FOR EACH ROW
BEGIN
    -- Purpose: Inserts an audit record into audit table.
    --
    -- MODIFICATION HISTORY
    -- Person        Date           Comments
    -- ---------     ----------     -------------------------------------------
    -- Fred Stluka   2/12/2007      Original version.
    --
    INSERT INTO itfa_product
        (audited_change_user   
        ,audited_change_dt      
        ,audited_change_type
        ,itf_product_id
        ,name
        ,descrip
        ,notes
        ,create_user
        ,create_dt
        ,update_user
        ,update_dt
        ,status_id
        )
    VALUES
        (USER()                         -- Any better solution for DELETE??
                                        -- Could have convention of doing an
                                        -- UPDATE immediately before the
                                        -- DELETE and use OLD.update_user
        ,SYSDATE()
        ,'DELETE'
        ,OLD.itf_product_id
        ,OLD.name
        ,OLD.descrip
        ,OLD.notes
        ,OLD.create_user
        ,OLD.create_dt
        ,OLD.update_user
        ,OLD.update_dt
        ,OLD.status_id
        );
END;
;;
DELIMITER ;


Hope this helps!
--Fred

Fred Stluka -- mailto:fred@bristle.com -- http://bristle.com/~fred/
Bristle Software, Inc -- http://bristle.com -- Glad to be of service!
Open Source: Without walls and fences, we need no Windows or Gates.

On 1/22/17 5:52 AM, enrico baranski wrote:
Hi Fed,

the DB trigger approach sounds very exciting to me because I really need to be sure that there is no way to manipulate records without audit trail. I also would be very interested in the trigger code for MySQL you mentioned.

You also mentioned that you did something similar in the past, what was your approach to store information in the audit trail table? At the moment, I have two ways in front of me and I am not quite sure which way to go. Assuming my primary table (rooms) stores the fields id, room, number, size and version.

So I could go for one record for each change with audit trail table fields like id, rooms_id, room_old, room_new, number_old, number_new, size_old, size_new, version_old, version_new.
Or with a record for each field, id, rooms_id, field, old, new. There for every field a record is listed.

Do you know other suitable approaches to store audit trail information or did you go one of the listed ways? My main aim here again is to be able to build reasonable audit trail views where a user can see the history of a record with easy query's behind it.

Thanks for reply,
Enrico
--
You received this message because you are subscribed to the Google Groups "Django users" group.
To unsubscribe from this group and stop receiving emails from it, send an email to django-users+unsubscribe@googlegroups.com.
To post to this group, send email to django-users@googlegroups.com.
Visit this group at https://groups.google.com/group/django-users.
To view this discussion on the web visit https://groups.google.com/d/msgid/django-users/7458b627-f70d-4613-b4c2-3fe53d67452d%40googlegroups.com.
For more options, visit https://groups.google.com/d/optout.

No comments:

Post a Comment