Skip to content
Browse files

Gestion des triggers applicatifs

  • Loading branch information...
1 parent 828b5f0 commit cd80340e2107eb25e54433d8f7d2081e7416d6b9 Sébastien Lardière committed Jan 25, 2011
Showing with 103 additions and 11 deletions.
  1. +17 −8 part_api.sql
  2. +34 −0 part_triggers.sql
  3. +12 −1 partition.sql
  4. +40 −2 tests/parttesttable.sql
View
25 part_api.sql
@@ -51,6 +51,7 @@ as $BODY$
spart text ;
col text ;
qname text = i_schema || '.' || i_table ;
+ v_triggerdef text ;
begin
tables = 0 ;
@@ -72,12 +73,6 @@ as $BODY$
|| ' check ( '|| i_column ||' >= ' || quote_literal( loval ) || ' and '|| i_column ||' < ' || quote_literal( hival ) || ' )) '
|| ' inherits ( ' || qname || ') ;' ;
- begin
- execute 'alter table ' || a_tables[counter] || ' add primary key (id ) ; ' ;
- exception when others then
- raise notice ' Create PK : % ', SQLERRM ;
- end ;
-
tables := tables + 1 ;
FOR col IN SELECT * FROM (VALUES ( i_column )) t(c)
@@ -86,6 +81,21 @@ as $BODY$
indexes := indexes + 1;
END LOOP;
+ -- create trigger
+
+ for v_triggerdef in select replace( triggerdef, qname , i_schema || '.' || spart )
+ from partition.trigger
+ where schemaname= i_schema and tablename = i_table
+ loop
+
+ raise notice 'Trigger : % ', v_triggerdef ;
+
+ execute v_triggerdef ;
+
+ end loop ;
+
+ -- grant role
+
exception when duplicate_table then
raise notice 'Create Part : % ', SQLERRM ;
end ;
@@ -326,8 +336,7 @@ returns record
language sql
as $BODY$
-select case when count(missing_tables) > 0 then 2::int else 0::int end, 'Missing : ' || string_agg( missing_tables,', ')
--- string_agg( missing_tables, ', ')
+select case when count(missing_tables) > 0 then 2::int else 0::int end, 'Missing : ' || string_agg( missing_tables,', ')
from ( select
t.schemaname ||'.'|| t.tablename
||'_'|| to_char ( now() + p.next_part , p.to_char_pattern )
View
34 part_triggers.sql
@@ -55,3 +55,37 @@ $PART$ ; ' ;
end ;
$BODY$
;
+
+
+create or replace function partition.set_trigger_def()
+returns trigger
+language plpgsql
+as $BODY$
+declare
+ r_trigg record ;
+begin
+ if TG_OP = 'INSERT' then
+ for r_trigg in select n.nspname, c.relname,
+ t.tgname, pg_get_triggerdef( t.oid ) as triggerdef
+ from pg_class c
+ join pg_namespace n on c.relnamespace=n.oid
+ join pg_trigger t on c.oid=t.tgrelid
+ where c.relkind='r'
+ and ( t.tgconstraint is null or t.tgconstraint = 0 )
+ and n.nspname = new.schemaname and c.relname = new.tablename
+ loop
+
+ insert into partition.trigger values ( r_trigg.nspname, r_trigg.relname, r_trigg.tgname, r_trigg.triggerdef ) ;
+
+ execute 'drop trigger ' || r_trigg.tgname || ' on ' || r_trigg.nspname || '.' || r_trigg.relname ;
+
+ end loop ;
+
+ end if ;
+ return new ;
+end ;
+$BODY$ ;
+
+create trigger _settrigg after insert on partition.table
+for each row
+execute procedure partition.set_trigger_def() ;
View
13 partition.sql
@@ -25,6 +25,17 @@ create table partition.table (
primary key ( schemaname, tablename )
);
+create table partition.trigger (
+ schemaname text not null,
+ tablename text not null,
+ triggername text not null,
+ triggerdef text not null,
+
+ foreign key ( schemaname, tablename ) references partition.table ( schemaname, tablename )
+) ;
+
+
+
insert into partition.pattern values
('Y','year','YYYY', '1 month'),
('M','month','YYYYMM', '1 week'),
@@ -35,4 +46,4 @@ insert into partition.pattern values
\i part_triggers.sql
-commit ;
+commit ;
View
42 tests/parttesttable.sql
@@ -7,6 +7,40 @@ create table test.test1an ( id serial, ev_date timestamptz default now() ) ;
create table test.test1mois ( id serial, ev_date timestamptz default now() ) ;
create table test.test1jour ( id serial, ev_date timestamptz default now() ) ;
+create or replace function test.test_trigger ()
+returns trigger
+language plpgsql
+as $BODY$
+begin
+ if TG_OP = 'INSERT' then
+ raise notice 'Fct triggered on %', TG_OP ;
+ return new ;
+ elsif TG_OP = 'UPDATE' then
+ raise notice 'Fct triggered on %', TG_OP ;
+ return new ;
+ elsif TG_OP = 'DELETE' then
+ raise notice 'Fct triggered on %', TG_OP ;
+ return old ;
+ end if;
+ return null;
+end;
+$BODY$ ;
+
+create trigger _delev after delete
+ on test.test1mois
+ for each row
+ execute procedure test.test_trigger () ;
+
+create trigger _insev before insert
+ on test.test1mois
+ for each row
+ execute procedure test.test_trigger () ;
+
+create trigger _insupdev before insert or update
+ on test.test1jour
+ for each row
+ execute procedure test.test_trigger () ;
+
insert into partition.table (schemaname, tablename, keycolumn, pattern, cleanable, retention_period) values
('test','test1an','ev_date','Y','t','3 year'),
('test','test1mois','ev_date','M','f', null),
@@ -16,7 +50,11 @@ select partition.create_part_trigger('test','test1an') ;
select partition.create_part_trigger('test','test1mois') ;
select partition.create_part_trigger('test','test1jour') ;
-select * from partition.create ('2011-01-01') ;
+select * from partition.create ( now()::date , now()::date + interval '3 day' ) ;
-commit ;
+insert into test.test1jour ( ev_date ) values ( now() ) ;
+insert into test.test1jour ( ev_date ) values ( now() ) ;
+update test.test1jour set ev_date=now() where id=1 ;
+update test.test1jour set ev_date=now() where id=2 ;
+commit ;

0 comments on commit cd80340

Please sign in to comment.
Something went wrong with that request. Please try again.