File: add-audits.tmpl

package info (click to toggle)
libchado-perl 1.23-2
  • links: PTS, VCS
  • area: main
  • in suites: jessie, jessie-kfreebsd
  • size: 23,976 kB
  • ctags: 10,378
  • sloc: xml: 192,540; sql: 165,945; perl: 28,339; sh: 101; python: 73; makefile: 46
file content (51 lines) | stat: -rw-r--r-- 2,046 bytes parent folder | download | duplicates (6)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
--audit tables generated from 
-- % sqlt -f PostgreSQL -t TTSchema --template add-audits.tmpl nofuncs.sql>audit_tables.sql

[% FOREACH table IN schema.get_tables %]
   DROP TABLE audit_[% table.name %];
   CREATE TABLE audit_[% table.name %] ( [% FOREACH field IN table.get_fields %]
       [% field.name %] [% IF field.data_type == 'serial'; 'int'; ELSE; field.data_type; END %][% IF field.size AND (field.data_type == 'char' OR field.data_type == 'varchar') %]([% field.size.join(', ') %])[% END %], [% END %]
       transaction_date timestamp not null default now(),
       transaction_type char(1) not null
   );
   GRANT ALL on audit_[% table.name %] to PUBLIC;

   CREATE OR REPLACE FUNCTION audit_update_delete_[% table.name %]() RETURNS trigger AS
   '
   DECLARE
       [% FOREACH field IN table.get_fields %][% field.name %]_var [% IF field.data_type == 'serial'; 'int'; ELSE; field.data_type; END %][% IF field.size AND (field.data_type == 'char' OR field.data_type == 'varchar') %]([% field.size.join(', ') %])[% END %]; 
       [% END %]
       transaction_type_var char;
   BEGIN
       [% FOREACH field IN table.get_fields %][% field.name %]_var = OLD.[% field.name %];
       [% END %]
       IF TG_OP = ''DELETE'' THEN
           transaction_type_var = ''D'';
       ELSE
           transaction_type_var = ''U'';
       END IF;

       INSERT INTO audit_[% table.name %] ( [% FOREACH field IN table.get_fields %]
             [% field.name %], [% END %]
             transaction_type
       ) VALUES ( [% FOREACH field IN table.get_fields %]
             [% field.name %]_var, [% END %]
             transaction_type_var
       );

       IF TG_OP = ''DELETE'' THEN
           return OLD;
       ELSE
           return NEW;
       END IF;
   END
   '
   LANGUAGE plpgsql; 

   DROP TRIGGER [% table.name %]_audit_ud ON [% table.name %];
   CREATE TRIGGER [% table.name %]_audit_ud
       BEFORE UPDATE OR DELETE ON [% table.name %]
       FOR EACH ROW
       EXECUTE PROCEDURE audit_update_delete_[% table.name %] ();

[% END %]