Calculated columns with a trigger

 

Some say that calculated columns is bad design because it does not follow the relational model. It is true but performance can be greatly enhanced. When a function is applied in a query on a indexed column, the query optimizer will not use the index. It is thus sometimes better to have an index on the calculated column because queries from the front end applications will run faster.

In this simple example, we have a table with 3 columns. The first and the second are given by the user and the third is calculated by a trigger. We add a condition : x * 0 = 0 * x = x (This fantasy comes from the requirements of a customer).  It is done with the case expression.

Some say that calculated columns is bad design because it does not follow the relational model. It is true but performance can be greatly enhanced.

The condition : x * 0 = 0 * x = x is implemented with a case construct.

drop table if exists tup;

create table tup (
     col1   numeric(10,2)
    ,col2   numeric(10,2)
    ,col3   numeric(10,2)
);

insert into tup(col1,col2) values
     (2.87      ,3.77)
    ,(4         ,5.11)
    ,(2.12      ,0)
    ,(0.0       ,3);

update tup
    set col3 =     (case col1 when 0 then 1 else col1 end)
                *  (case col2 when 0 then 1 else col2 end);

select * from tup;

will give

col1     col2   col3
---------------------
2.87     3.77   10.82
4.00     5.11   20.44
2.12     0.00    2.12
0.00     3.00    3.00

Let now add the trigger and the trigger function :

create or replace function calculate_columns() returns trigger as $$
begin

  new.col3 =   (case new.col1 when 0 then 1 else new.col1 end)
             * (case new.col2 when 0 then 1 else new.col2 end);

  return new;

end $$ language plpgsql;

create trigger calculated_columns  
    before insert or update 
    on tup
    for each row
    execute procedure calculate_columns();

Note that we do a before insert or update trigger and that we update the columns in the row new.

insert into tup(col1, col2) values
     (6.23      ,2)
    ,(0         ,55.11);

select * from tup;

will give :

col1     col2   col3
---------------------
2.87     3.77   10.82
4.00     5.11   20.44
2.12     0.00    2.12
0.00     3.00    3.00
6.23     2.00   12.46
0.00    55.11   55.11

The deal is in the bag!

How to safely delete records ?

To collect accurate data is expensive !

To structure data is very expensive !

To record accurate structured data is very very expensive !

Then…

Once data is recorded in a database, it is not a good idea to definitely delete it. It is better to archive the records we don’t want to see anymore in the database.

We will build a very simple framework for a soft delete with the PostgreSQL trigger functions. In a previous post, we developed an audit system that we will use again. We have just to modify the pre-delete trigger.

The components are :

  • a schema called ‘deleted’ having the same tables that the database
  • a trigger pre-delete on each table

and, inherited from the audit system :

  • an additional column on each table called audit_id
  • a table called audit_history

Let’s begin with the creation of the schema ‘deleted’ :

create or replace function public.create_schema_deleted() returns void as $$
declare 
 r	record;
 stmt	varchar;
begin

 execute 'create schema deleted;'
 
 for r in
  select 
   quote_ident(table_name) as table_name
  from 
   information_schema.tables 
  where 
   table_schema = 'public'

  loop

   stmt :=    'create table deleted.' 
     || r.table_name 
     || ' (like public.' 
     || r.table_name 
     || ')';

   execute stmt;

  end loop;
  
  execute 'grant usage on schema deleted to generic user'
  execute 'grant insert on all tables in schema deleted to generic_user;'

end $$ language 'plpgsql' volatile;

select public.create_schema_deleted();

This schema contains all the table of your production database without indexes, without pk/fk constraints, without sequences and without triggers. The role generic_user is granted to actual users.

Just after the creation of the schema, the tables are empty.

Each table has a column audit_id. It is a big serial that is incremented automatically when we insert a record in the production database.

The tables in the schema ‘deleted’ have of course also this column.

We create now the trigger function that will be executed each time an user deletes a record in the production database :

create or replace function public.pre_delete() returns trigger as $$
declare
 stmt 	varchar;
begin

 insert into public.audit_history
  (table_name, operation, audit_id, user_name, audit_date)
 values 
  (TG_TABLE_NAME, TG_OP, old.audit_id, current_user, now())

  stmt :=    'insert into deleted.'
   || quote_ident(TG_TABLE_NAME)
   || ' select * from public.'
   || quote_ident(TG_TABLE_NAME)
   || ' where audit_id = $1;';

  execute stmt using old.audit_id;
        
  return old;

end; $$ language 'plpgsql'; 

and a trigger pre-delete for each table :

create or replace function public.create_pre_delete_triggers() 
   returns void as $$
declare
 r	record;
 stmt	varchar;
begin
 for r in 
    select table_name 
    from information_schema.tables 
    where table_schema = 'public'
  loop

    stmt :=    'create trigger ' 
     || quote_ident(r.table_name || '_pre_delete')
     || ' after insert on public.' 
     || quote_ident(r.table_name)
     || ' for each row execute procedure public.pre_delete();';

    execute stmt;

  end loop;

end; $$ language 'plpgsql'; 

select public.create_pre_delete_triggers();

If we want to find a deleted record, we have a look in the table audit_history that has the following structure :

 id_audit_history  bigserial unique 
,table_name        text 
,operation         text 
,audit_id          bigint 
,user_name         text 
,audit_date        timestamp

And we do a select in the schema ‘deleted’ for this table and for this audit_id.

That’s simple !

A simple audit system

Let’s suppose we want to audit all insert, update and delete committed on a database.

We create a table to store relevant data :

drop table if exists audit_history;
create table audit_history (
  id_audit_history       serial
 ,table_name             text
 ,operation              text
 ,audit_id               bigint
 ,user_name              text
 ,insertion_date         timestamp       default now()
);

drop sequence if exists audit_history_seq;
create sequence audit_history_seq;

We create two test tables with a pk constraints and one having a fk constraint to the other. Note that this fk constraint has the clause on delete cascade.

drop table if exists app_table_ref;
drop table if exists app_table;

create table app_table (
  pk             integer         primary key
 ,info           varchar
 ,audit_id       bigserial
);

create table app_table_ref (
  pk             integer         primary key
 ,info           varchar
 ,fk             integer references app_table(pk) on delete cascade
 ,audit_id       bigserial
);

Note the presence of the column audit_id, a bigserial that is not a pk.

We create now the trigger function, a generic fonction for the two triggers : after insert or update and before delete.

create or replace function populate_audit_history() 
   returns trigger as $$
begin

  if (TG_OP = 'INSERT' or TG_OP = 'UPDATE') then

      insert into audit_history
        (table_name, operation, audit_id, user_name)
      values
        (TG_TABLE_NAME, TG_OP, new.audit_id, current_user);

      return new;

  else
  
     insert into audit_history
        (table_name, operation, audit_id, user_name)
      values
        (TG_TABLE_NAME, TG_OP, old.audit_id, current_user);

     return old;

  end if;
end;
$$ language 'plpgsql';


create or replace function create_audit_triggers() 
   returns void as $$
declare
   r       record;
   stmt    varchar;
begin
  for r in select table_name from information_schema.tables 
              where table_name like 'app_table%' loop

     stmt :=    'create trigger '
             || quote_ident(r.table_name || '_audit_after_iu')
             || ' after insert or update on '
             || quote_ident(r.table_name)
             || ' for each row 
                    execute procedure populate_audit_history();';

     execute stmt;
   
     stmt :=    'create trigger '
             || quote_ident(r.table_name || '_audit_before_d')
             || ' before delete on '
             || quote_ident(r.table_name)
             || ' for each row 
                    execute procedure populate_audit_history();';

     execute stmt;

   end loop;
end;
$$ language 'plpgsql';

select create_audit_triggers();

Note the execute instruction that allows us to execute dynamic SQL statements.

We do now some transactions on those two tables :

insert into app_table values(23,'record 23');
insert into app_table values(56,'record 56');
insert into app_table values(71,'record 71');
insert into app_table values(82,'record 82');
insert into app_table values(85,'record 85');
insert into app_table values(91,'record 91');
insert into app_table values(94,'record 94');
insert into app_table values(97,'record 97');
insert into app_table values(99,'record 99');
update app_table set info = 'modified' where pk = 23;
update app_table set info = 'modified' where pk = 56;
update app_table set info = 'modified' where pk = 97;
delete from app_table where pk = 71;
insert into app_table values(101,'record 101');
insert into app_table values(121,'record 121');
insert into app_table values(167,'record 167');
update app_table set info = 'modified' where pk = 101;
delete from app_table where pk = 121;
insert into app_table_ref values(1, 'ref1', 23);
insert into app_table_ref values(2, 'ref2', 23);
insert into app_table_ref values(3, 'ref3', 82);
delete from app_table where pk = 23;

Here is the table audit_history :

1  | app_table     | INSERT |  1 | mchl | 2017-02-08 15:01:10.28164
2  | app_table     | INSERT |  2 | mchl | 2017-02-08 15:01:10.292839
3  | app_table     | INSERT |  3 | mchl | 2017-02-08 15:01:10.304088
4  | app_table     | INSERT |  4 | mchl | 2017-02-08 15:01:10.315051
5  | app_table     | INSERT |  5 | mchl | 2017-02-08 15:01:10.32618
6  | app_table     | INSERT |  6 | mchl | 2017-02-08 15:01:10.337284
7  | app_table     | INSERT |  7 | mchl | 2017-02-08 15:01:10.348366
8  | app_table     | INSERT |  8 | mchl | 2017-02-08 15:01:10.35954
9  | app_table     | INSERT |  9 | mchl | 2017-02-08 15:01:10.370595
10 | app_table     | UPDATE |  1 | mchl | 2017-02-08 15:01:10.381727
11 | app_table     | UPDATE |  2 | mchl | 2017-02-08 15:01:10.392824
12 | app_table     | UPDATE |  8 | mchl | 2017-02-08 15:01:10.403822
13 | app_table     | DELETE |  3 | mchl | 2017-02-08 15:01:10.414956
14 | app_table     | INSERT | 10 | mchl | 2017-02-08 15:01:10.4261
15 | app_table     | INSERT | 11 | mchl | 2017-02-08 15:01:10.437168
16 | app_table     | INSERT | 12 | mchl | 2017-02-08 15:01:10.448195
17 | app_table     | UPDATE | 10 | mchl | 2017-02-08 15:01:10.459344
18 | app_table     | DELETE | 11 | mchl | 2017-02-08 15:01:10.470463
19 | app_table_ref | INSERT |  1 | mchl | 2017-02-08 15:01:10.481536
20 | app_table_ref | INSERT |  2 | mchl | 2017-02-08 15:01:10.49259
21 | app_table_ref | INSERT |  3 | mchl | 2017-02-08 15:01:10.503579
22 | app_table     | DELETE |  1 | mchl | 2017-02-08 15:01:10.514913
23 | app_table_ref | DELETE |  1 | mchl | 2017-02-08 15:01:10.514913
24 | app_table_ref | DELETE |  2 | mchl | 2017-02-08 15:01:10.514913

And here the table app_table :

  56 | modified   |        2
  82 | record 82  |        4
  85 | record 85  |        5
  91 | record 91  |        6
  94 | record 94  |        7
  97 | modified   |        8
  99 | record 99  |        9
 101 | modified   |       10
 167 | record 167 |       12

and the table app_table_ref :

  3 | ref3 | 82 |        3

We note that the delete in app_table of the record having pk = 23 has deleted also the two records of app_table_ref having fk = 23.

This design is very handy because you can add auditing on an existing database by adding a to each table : 1/  a column serial (that is not a pk) and 2/  the two triggers (after the creation of the generic function).

The applications are not touched and the referential integrity of the database is preserved.

Having for each modifications, the name of the table and the value of the audit_id, we can find, for insert and update, the rows that have changed.