----select dropall('f_audit_build'); create or replace function meta.f_audit_build( p_mode integer = 0, p_schema text default '' ) returns table( scriptpriority integer ,scripttype citext ,objectname citext ,scriptcode citext ,schemaname citext ) language plpgsql volatile as $$ ---p_mode= --0:all --1:only functions --2:only creates --3:only drops declare --Error Handling-- m_funcname text = 'f_audit_build'; m_errmsg text; m_errcontext text; m_errdetail text; m_errhint text; m_errstate text; m_retval integer; --Error Handling-- m_sql citext; m_sql2 citext; m_auditcol citext; m_dkeyfield citext; m_pkfield citext; m_skipcoreschema citext[]; r_record record; r_recsub record; begin --columntype: -- 0=Normal Audited --, 1=Primary Key --, 2=Primary Key Audited --, 3=UserColumn --, 4=Normal Encrypted Audited --, 5 = Parent Table Primary Key for lookup (Must give Foreign Table) --, 6 = Parent Table Primary Key for delete (Must give Foreign Table) --, 9=View only, used for custom audit. e.g pplan --specialtype: -- 0,null = Leave alone. -- 1=Convert int date to sql date. -- 2=Convert int time to sql time., -- 3=Status Field, --Note that when ColumnType is 3,Status field, the ForeignTable column must have the name of the search sent to F_GetDescription_Code -- 4=ForeignTable -- 5=ForeignTable, tableprefix -- 6 = Blob Column, will compare with size only -- 7 = Blob Column, will compare with hash only -- 8 = Hide m_skipcoreschema = array[]::citext[]; SET LOCAL statement_timeout = '90s'; drop table if exists tmp_f_audittables; CREATE TEMP TABLE tmp_f_audittables( tablename citext ,schemaname citext ,tableprefix citext ,columnname citext ,columndesc citext ,columntype integer ,datatype citext ,specialtype integer ,foreigntable citext ,foreigncolumn citext ,foreignpk citext ,addversion integer ,savetoschema citext ,PRIMARY KEY(columnname, schemaname,tablename, columntype) ); --CREATE INDEX idx_tmp_f_audittables ON tmp_f_audittables (tablename, columnname); if exists ( select r.routine_name from information_schema.routines r where r.routine_name::citext = 'f_getauditinfo' and r.specific_schema = 'public' ) and exists ( select 1 from information_schema.columns c where c.table_name = 't_adproclientcreditorl1' and c.table_schema = 'public' ) then m_skipcoreschema = array_append(m_skipcoreschema,'public'::citext); insert into tmp_f_audittables(tablename ,schemaname ,tableprefix ,columnname ,columndesc ,columntype ,datatype ,specialtype ,foreigntable ,foreigncolumn ,foreignpk ,savetoschema ) select distinct on (r.columnname, r.tablename, r.columntype) r.tablename ,'public' as schemaname ,r.tableprefix ,r.columnname ,r.columndescription ,r.columntype ,r.datatype ,r.specialtype ,r.foreigntable ,r.foreigncolumn ,r.foreignpk ,'public' as savetoschema from meta.migration_table t2 inner join public.f_getauditinfo(t2.tablename) r on t2.ismodel and t2.tablename = r.tablename and t2.schemaname = 'public' ; end if; if exists ( select r.routine_name from information_schema.routines r where r.routine_name::citext = 'f_getauditinfo' and r.specific_schema = 'meta' ) then insert into tmp_f_audittables(tablename ,schemaname ,tableprefix ,columnname ,columndesc ,columntype ,datatype ,specialtype ,foreigntable ,foreigncolumn ,foreignpk ,savetoschema ) select distinct on (r.columnname, r.tablename, r.columntype) r.tablename ,r.schemaname ,r.tableprefix ,r.columnname ,r.columndescription ,r.columntype ,r.datatype ,r.specialtype ,r.foreigntable ,r.foreigncolumn ,r.foreignpk ,case when t2.schemaname = 'public' then 'public' else 'core' end as savetoschema from meta.migration_table t2 inner join meta.f_getauditinfo(format('%s.%s',t2.schemaname,t2.tablename)) r on t2.ismodel and t2.tablename = r.tablename and t2.schemaname = r.schemaname and coalesce(r.schemaname,'') not in ('meta','') where coalesce(r.schemaname,'') <> all(m_skipcoreschema) ; delete from tmp_f_audittables a where a.tablename in ( select distinct b.tablename from tmp_f_audittables b where b.columntype = 9 ); if exists ( select r.routine_name from information_schema.routines r where r.routine_name::citext = 'f_getauditversion' and r.specific_schema = 'meta' ) then update tmp_f_audittables at set addversion = av.mode from ( select r.tablename ,r.columnname ,r.mode from meta.f_getauditversion('') r ) av where at.tablename::citext = av.tablename::citext and at.columnname::citext = av.columnname::citext ; end if; end if; delete from tmp_f_audittables t where t.tablename in ( 'version', 'upgrades', 'upgradescript', 'eventlog', 'event_notify', 'atevent', 'atdetail', 'procused', 'lastprocrun', 'intface_transmission', 'setting','programmodule' ,'_loginsession','event_notify','bt_enums','authsession' ) or t.tablename in (select t.tablename from meta.f_upgrade_table() t ); for r_record in ( select distinct on (a.tablename,a.schemaname ,a.tableprefix) nv(a.tablename)::citext as tablename ,nv(a.schemaname)::citext as schemaname ,nv(a.tableprefix)::citext as tableprefix ,COALESCE((select 1 from tmp_f_audittables a2 where a2.tablename = a.tablename and a2.addversion = 2 limit 1 ),0) as addversion ,nv(a.savetoschema,'core') as savetoschema from tmp_f_audittables a inner join information_schema.tables t on lower(t.table_name) = lower(a.tablename) and lower(t.table_schema) = lower(a.schemaname) ) loop m_sql = ''; m_sql2 = ''; m_auditcol = 'if ( '; m_dkeyfield = ''; m_pkfield = ''; --raise notice 'Tbl: %', r_record.tableprefix; for r_recsub in ( select nv(a.columnname) as columnname ,nv(a.columntype) as columntype ,nv(a.datatype) as datatype ,nv(a.specialtype) as specialtype ,nv(a.foreigntable) as foreigntable ,nv(a.foreigncolumn) as foreigncolumn ,nv(a.foreignpk) as foreignpk ,nv(a.addversion) as addversion ,row_number() over (order by a.tablename, a.columnname) rownr ,r_record.savetoschema as savetoschema from tmp_f_audittables a where a.tablename = r_record.tablename and a.schemaname = r_record.schemaname and exists ( select 1 from information_schema.columns c where lower(c.table_name) = lower(a.tablename) and lower(c.table_schema) = lower(a.schemaname) and lower(c.column_name) = lower(a.columnname) ) ) loop --raise notice 'Col: %' ,r_recsub.columnname; if r_recsub.columntype in (0,2,4) then if r_recsub.datatype = 'jsonb' then m_sql = m_sql || chr(13) || chr(10) || ' ' || 'if (old.'|| r_recsub.columnname ||' IS DISTINCT FROM new.'|| r_recsub.columnname || ') then' || chr(13) || chr(10) || ' ' || case when r_recsub.savetoschema = 'core' then 'insert into core.atdetail(rid_atevent, datacolumn, changedfrom, changedto)' else 'insert into public.atdetail(rid_parent, datacolumn, changedfrom, changedto)' end || chr(13) || chr(10) || $SS$ select m_atevent, k , case when r.jsonvalue->k->>'action' = 'insert' then null else r.jsonvalue->k->>'oldvalue' end as changedfrom , case when r.jsonvalue->k->>'action' = 'delete' then null else r.jsonvalue->k->>'value' end as changedto from f_json_keydiff(to_jsonb(new.$SS$|| r_recsub.columnname || $SS$), to_jsonb(old.$SS$|| r_recsub.columnname || $SS$),'$SS$|| r_recsub.columnname || $SS$') r(jsonvalue) cross join jsonb_object_keys(r.jsonvalue) k ; $SS$ || chr(13) || chr(10) || ' end if;' || chr(13) || chr(10) ; else --detail for updates m_sql = m_sql || chr(13) || chr(10) || ' ' || 'if (old.'|| r_recsub.columnname ||' IS DISTINCT FROM new.'|| r_recsub.columnname || ') then' || chr(13) || chr(10) || ' ' || case when r_recsub.savetoschema = 'core' then 'insert into core.atdetail(rid_atevent, datacolumn, changedfrom, changedto)' else 'insert into public.atdetail(rid_parent, datacolumn, changedfrom, changedto)' end || chr(13) || chr(10) || ' ' || 'values (m_atevent, '''|| r_recsub.columnname ||''', substr(' || case --OLD --TIME when r_recsub.specialtype = 2 then 'f_inttotm(old.'|| r_recsub.columnname || ')::text' --desc code lookup when r_recsub.specialtype = 3 and r_recsub.columntype = 0 and COALESCE(r_recsub.foreigntable,'') <> '' then 'f_getdesccode(''' || r_recsub.foreigntable || ''', old.'|| r_recsub.columnname || '::text)::text' --foreign table sub select when r_recsub.specialtype in (4,9) and r_recsub.columntype = 0 and COALESCE(r_recsub.foreigntable,'') <> '' then case when r_recsub.foreigncolumn ilike '(%' then '(select ' else '(select ft.' end --Detect sub select. || r_recsub.foreigncolumn || ' from ' || r_recsub.foreigntable || ' ft where ft.'|| r_recsub.foreignpk ||' = old.'|| r_recsub.columnname || ' limit 1)::text' --blobs, size when r_recsub.specialtype = 6 and r_recsub.columntype in (0,3,4) and r_recsub.datatype = 'bytea' then 'octet_length(old.' || r_recsub.columnname ||')::text' --blobs, md5 when r_recsub.specialtype = 7 and r_recsub.columntype in (0,3,4) and r_recsub.datatype = 'bytea' then '( select h.p_hash from pl_hashbytes(old.' || r_recsub.columnname ||') h limit 1 )::text' --Hide (All) when r_recsub.specialtype = 8 or r_recsub.columntype = 4 then '''****************''::text' --default else ' old.'|| r_recsub.columnname || '::text' end ||',1,1000) , substr(' || case --NEW --TIME when r_recsub.specialtype = 2 then 'f_inttotm(new.'|| r_recsub.columnname || ')::text' --desc code lookup when r_recsub.specialtype = 3 and r_recsub.columntype = 0 and COALESCE(r_recsub.foreigntable,'') <> '' then 'f_getdesccode(''' || r_recsub.foreigntable || ''', new.'|| r_recsub.columnname || '::text)::text' --foreign table sub select when r_recsub.specialtype = 4 and r_recsub.columntype = 0 and COALESCE(r_recsub.foreigntable,'') <> '' then '(select ft.' || r_recsub.foreigncolumn || ' from ' || r_recsub.foreigntable || ' ft where ft.'|| r_recsub.foreignpk ||' = new.'|| r_recsub.columnname || ' limit 1)::text' --foreign table sub select with table prefix when r_recsub.specialtype = 5 and COALESCE(r_recsub.foreigntable,'') <> '' then '(select ft.' || r_recsub.foreigncolumn || ' from ' || r_recsub.foreigntable || ' ft where ft.'|| r_recsub.foreignpk ||' = new.'|| r_recsub.columnname || ' limit 1)::text' --blobs, size when r_recsub.specialtype = 6 and r_recsub.columntype in (0,3,4) and r_recsub.datatype = 'bytea' then 'octet_length(new.' || r_recsub.columnname ||')::text' --blobs, md5 when r_recsub.specialtype = 7 and r_recsub.columntype in (0,3,4) and r_recsub.datatype = 'bytea' then '( select h.p_hash from pl_hashbytes(new.' || r_recsub.columnname ||') h limit 1 )::text' --Hide (All) when r_recsub.specialtype = 8 or r_recsub.columntype = 4 then '''****************''::text' --default else ' new.'|| r_recsub.columnname || '::text' end ||',1,1000));' || chr(13) || chr(10) || ' ' || case when r_recsub.addversion = 1 then E'\n ' || case when r_recsub.savetoschema = 'public' then E' insert into public.atdetail(rid_parent, datacolumn, changedfrom, changedto) select m_atevent, ''version'', null,(select version from version limit 1) \n where not exists ( select 1 from public.atdetail ad where ad.rid_parent = m_atevent and ad.datacolumn = ''version'' ) and not (changedfrom is null and changedto is null) ;\n ' else E' insert into core.atdetail(rid_atevent, datacolumn, changedfrom, changedto) select m_atevent, ''version'', null,(select version from version limit 1) \n where not exists ( select 1 from core.atdetail ad where ad.rid_atevent = m_atevent and ad.datacolumn = ''version'' ) and not (changedfrom is null and changedto is null) ;\n' end || E' \n' else '' end || chr(13) || chr(10) || ' end if;' || chr(13) || chr(10) ; end if; --detail for deletes m_sql2 = m_sql2 || chr(13) || chr(10) || ' ' || case when r_recsub.savetoschema = 'public' then 'insert into public.atdetail(rid_parent, datacolumn, changedfrom, changedto)' else 'insert into core.atdetail(rid_atevent, datacolumn, changedfrom, changedto)' end || chr(13) || chr(10) || ' ' || 'values (m_atevent, '''|| r_recsub.columnname ||''', ' || case when r_recsub.datatype ilike '%bytea%' then '( select h.p_hash from pl_hashbytes(old.' || r_recsub.columnname ||') h limit 1 )::text ' when r_recsub.datatype ilike '%int%' or r_recsub.datatype ilike '%numeric%' or r_recsub.datatype ilike '%real%' then ' old.'|| r_recsub.columnname ||'::text ' else ' substr(old.'|| r_recsub.columnname ||'::text,1,1000) ' end || ', null);' || chr(13) || chr(10) ; m_auditcol = m_auditcol || 'old.'|| r_recsub.columnname ||' IS DISTINCT FROM new.'|| r_recsub.columnname || case when r_recsub.rownr % 3 = 0 then chr(13) || chr(10) else '' end || ' or '; end if; if (r_recsub.columntype in (1,2)) then m_pkfield = r_recsub.columnname; end if; if r_recsub.columntype = 6 then m_dkeyfield = r_recsub.columnname; end if; end loop; m_auditcol = m_auditcol || ' 1 = 0 ) then'; if nv(p_mode) in (0,3) then return query select r.scriptpriority::integer ,r.scripttype::citext ,r.objectname::citext ,r.scriptcode::citext ,r_record.schemaname::citext from ( select 340 as scriptpriority ,'drop audit trigger' as scripttype ,'t_audit_'||r_record.tablename as objectname ,'do $C$ begin SET LOCAL statement_timeout = ''10s''; DROP TRIGGER IF EXISTS t_audit_' || r_record.tablename ||E'\n ON ' || r_record.schemaname || '.' || r_record.tablename ||'; end; $C$ ' as scriptcode ) r ; end if; if nv(m_pkfield) = '' then raise notice 'No Primary Key for %. Please fix this in f_getauditinfo.',r_record.tablename; --perform log_event(m_funcname,format(' as No Primary Key for %s %s. Please fix this in f_getauditinfo.' ,r_record.tablename, r_record.tableprefix),bt_enum('eventlog','error')); continue; end if; if nv(p_mode) in (0,1) then return query select r.scriptpriority::integer ,r.scripttype::citext ,r.objectname::citext ,r.scriptcode::citext ,r_record.schemaname::citext from ( select 345 as scriptpriority ,'create audit function ' as scripttype ,r_record.schemaname || '.' || 'ft_audit_'||rtrim(r_record.tablename) as objectname ,--------------------------- String ends at $QUOTED$ with comments. $QUOTED$ CREATE OR REPLACE FUNCTION $QUOTED$ || r_record.schemaname || $QUOTED$.ft_audit_$QUOTED$ || rtrim(r_record.tablename) || $QUOTED$ ( ) RETURNS trigger AS $body$ DECLARE --Error Handling-- m_funcname text = 'ft_audit_$QUOTED$ || rtrim(r_record.tablename) || $QUOTED$'; m_errmsg text; m_errcontext text; m_errdetail text; m_errhint text; m_errstate text; m_retval integer; --Error Handling-- r_adtrec record; m_query text; m_user citext; m_atevent integer; BEGIN if core.not_triggerable(tg_name, tg_table_schema, tg_table_name,tg_op) then return null; end if; if TG_TABLE_NAME::citext <> $QUOTED$ || quote_literal(r_record.tablename) || $QUOTED$::citext then IF (TG_OP = 'DELETE') THEN RETURN OLD; ELSIF (TG_OP = 'UPDATE') THEN RETURN NEW; ELSIF (TG_OP = 'INSERT') THEN RETURN NEW; END IF; end if; m_user = f_getuser(); if m_user::citext in ('noaudit', 'importuser') or meta.f_audit_check(TG_TABLE_NAME::text, TG_OP::text, m_user::citext, row_to_json(NEW), row_to_json(OLD)) then IF (TG_OP = 'DELETE') THEN RETURN OLD; ELSIF (TG_OP = 'UPDATE') THEN RETURN NEW; ELSIF (TG_OP = 'INSERT') THEN RETURN NEW; END IF; end if; $QUOTED$ || -------------------core-------------- case when r_record.savetoschema = 'core' then $QUOTED$ if TG_OP = 'INSERT' then with rows_ins as ( insert into core.atevent (tablename, rid_parent, changeuser, changedate,changetime,actionx) values('$QUOTED$ || r_record.tablename || $QUOTED$', new.$QUOTED$ || m_pkfield || $QUOTED$, m_user, clock_timestamp()::date, clock_timestamp()::time, 1) returning rid_atevent ) select rid_atevent from rows_ins into m_atevent; $QUOTED$ || case when r_record.addversion = 1 then E' insert into core.atdetail(rid_atevent, datacolumn, changedfrom, changedto) \n select m_atevent, $Q2$version$Q2$, null,(select version from version limit 1) \n where not exists (select 1 from core.atdetail ad where ad.rid_atevent = m_atevent and ad.datacolumn = $Q2$version$Q2$); ' else '' end || $QUOTED$ elsif TG_OP = 'UPDATE' then $QUOTED$ || m_auditcol || $QUOTED$ with rows_ins as ( insert into core.atevent (tablename, rid_parent, changeuser, changedate,changetime,actionx) values('$QUOTED$ || r_record.tablename || $QUOTED$', new.$QUOTED$ || m_pkfield || $QUOTED$, m_user, clock_timestamp()::date, clock_timestamp()::time, 2) returning rid_atevent ) select rid_atevent from rows_ins into m_atevent; $QUOTED$ || m_sql || $QUOTED$ end if; elsif TG_OP in ('DELETE', 'TRUNCATE') then with rows_ins as ( insert into core.atevent(tablename, rid_parent, changeuser, changedate,changetime,actionx, rid_deletedparent) values('$QUOTED$ || r_record.tablename || $QUOTED$' , old.$QUOTED$ || m_pkfield || $QUOTED$ , m_user , clock_timestamp()::date , clock_timestamp()::time , 3 , $QUOTED$ || case when nv(m_dkeyfield) = '' then 'null' else format('old.%s',m_dkeyfield) end || $QUOTED$) returning rid_atevent ) select rid_atevent from rows_ins into m_atevent; $QUOTED$ -------------------publio-------------- else $QUOTED$ if TG_OP = 'INSERT' then with rows_ins as ( insert into public.atevent(tableprefix, rid_parent, changeuser, changedate,changetime,actionx) values('$QUOTED$ || r_record.tableprefix || $QUOTED$', new.$QUOTED$ || m_pkfield || $QUOTED$, m_user, clock_timestamp()::date, f_tmtoint(clock_timestamp()::time), 1) returning rid_atevent ) select rid_atevent from rows_ins into m_atevent; $QUOTED$ || case when r_record.addversion = 1 then E' insert into public.atdetail(rid_atevent, datacolumn, changedfrom, changedto) \n select m_atevent, $Q2$version$Q2$, null,(select version from version limit 1) \n where not exists (select 1 from public.atdetail ad where ad.rid_atevent = m_atevent and ad.datacolumn = $Q2$version$Q2$); ' else '' end || $QUOTED$ elsif TG_OP = 'UPDATE' then $QUOTED$ || m_auditcol || $QUOTED$ with rows_ins as ( insert into public.atevent (tableprefix, rid_parent, changeuser, changedate,changetime,actionx) values('$QUOTED$ || r_record.tableprefix || $QUOTED$', new.$QUOTED$ || m_pkfield || $QUOTED$, m_user, clock_timestamp()::date, f_tmtoint(clock_timestamp()::time), 2) returning rid_atevent ) select rid_atevent from rows_ins into m_atevent; $QUOTED$ || m_sql || $QUOTED$ end if; elsif TG_OP in ('DELETE', 'TRUNCATE') then with rows_ins as ( insert into public.atevent (tableprefix, rid_parent, changeuser, changedate,changetime,actionx, rid_deletedparent) values('$QUOTED$ || r_record.tableprefix || $QUOTED$' , old.$QUOTED$ || m_pkfield || $QUOTED$ , m_user , clock_timestamp()::date , f_tmtoint(clock_timestamp()::time) , 3 , $QUOTED$ || case when nv(m_dkeyfield) = '' then 'null' else format('old.%s',m_dkeyfield) end || $QUOTED$) returning rid_atevent ) select rid_atevent from rows_ins into m_atevent; $QUOTED$ end || $QUOTED$ $QUOTED$ || m_sql2 || $QUOTED$ end if; IF (TG_OP = 'DELETE') THEN RETURN OLD; ELSIF (TG_OP = 'UPDATE') THEN RETURN NEW; ELSIF (TG_OP = 'INSERT') THEN RETURN NEW; END IF; RETURN NULL; -- result is ignored since this is an AFTER trigger EXCEPTION WHEN others THEN GET STACKED DIAGNOSTICS m_errmsg = MESSAGE_TEXT ,m_errcontext = PG_EXCEPTION_CONTEXT ,m_errdetail = PG_EXCEPTION_DETAIL ,m_errhint = PG_EXCEPTION_HINT ,m_errstate = RETURNED_SQLSTATE; m_errmsg := get_err_msg(m_funcname, m_errmsg, m_errcontext, m_errdetail, m_errhint, m_errstate); RETURN NULL; -- result is ignored since this is an AFTER trigger END; $body$ LANGUAGE 'plpgsql' VOLATILE CALLED ON NULL INPUT SECURITY INVOKER COST 1; $QUOTED$ as scriptcode --------------------------------------- ) r ; end if; if nv(p_mode) in (0,2) then return query select r.scriptpriority::integer ,r.scripttype::citext ,r.objectname::citext ,r.scriptcode::citext ,r_record.schemaname::citext from ( select distinct on (r_record.tablename) 355 as scriptpriority ,'create audit trigger' as scripttype ,'t_audit_'||r_record.tablename as objectname ,format($A$DO $TT$ BEGIN IF NOT EXISTS ( SELECT 1 FROM pg_trigger WHERE tgname = 't_audit_%2$s' AND tgrelid = '%1$s.%2$s'::regclass ) THEN -- Create the trigger if it doesn't exist CREATE TRIGGER t_audit_%2$s AFTER INSERT OR UPDATE OR DELETE ON %1$s.%2$s FOR EACH ROW EXECUTE PROCEDURE %1$s.ft_audit_%2$s(); END IF; END; $TT$; $A$, r_record.schemaname,r_record.tablename) as scriptcode ) r ; end if; end loop; exception when others then GET STACKED DIAGNOSTICS m_errmsg = MESSAGE_TEXT ,m_errcontext = PG_EXCEPTION_CONTEXT ,m_errdetail = PG_EXCEPTION_DETAIL ,m_errhint = PG_EXCEPTION_HINT ,m_errstate = RETURNED_SQLSTATE; m_errmsg := get_err_msg(m_funcname, m_errmsg, m_errcontext, m_errdetail, m_errhint, m_errstate); raise '%',m_errmsg; end; $$;