From: Aaron Schrab Date: Tue, 10 May 2011 22:15:26 +0000 (-0400) Subject: Add trigger support to PostgreSQL producer and parser (including trigger scope) X-Git-Tag: v0.11011~64 X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?p=dbsrgits%2FSQL-Translator.git;a=commitdiff_plain;h=c96cd4a82bc9447c278ecf2416a7f8fb052853a7 Add trigger support to PostgreSQL producer and parser (including trigger scope) PostgreSQL triggers can be fired either once for a statement (the default), or for each row affected by the statement. Add support to declare which type of trigger should is wanted by setting the "scope" of the trigger. --- diff --git a/Changes b/Changes index 166246a..a0cc90e 100644 --- a/Changes +++ b/Changes @@ -1,3 +1,4 @@ +* Support for triggers in PostgreSQL producer and parser * Correct Data Type in SQLT::Parser::DBI::PostgreSQL (patch from Andrew Pam) * Fix index issue in SQLT::Parser::DBI::PostgreSQL * Add column and table comments in SQLT::Parser::DBI::PostgreSQL(patch from Andrew Pam) diff --git a/lib/SQL/Translator/Parser/PostgreSQL.pm b/lib/SQL/Translator/Parser/PostgreSQL.pm index b3f91d7..8bb119b 100644 --- a/lib/SQL/Translator/Parser/PostgreSQL.pm +++ b/lib/SQL/Translator/Parser/PostgreSQL.pm @@ -106,7 +106,7 @@ $::RD_HINT = 1; # Give out hints to help fix problems. $GRAMMAR = q! -{ my ( %tables, @views, $table_order, $field_order, @table_comments) } +{ my ( %tables, @views, @triggers, $table_order, $field_order, @table_comments) } # # The "eofile" rule makes the parser fail if any "statement" rule @@ -114,7 +114,13 @@ $GRAMMAR = q! # won't cause the failure needed to know that the parse, as a whole, # failed. -ky # -startrule : statement(s) eofile { { tables => \%tables, views => \@views } } +startrule : statement(s) eofile { + { + tables => \%tables, + views => \@views, + triggers => \@triggers, + } +} eofile : /^\Z/ @@ -262,6 +268,34 @@ create : CREATE or_replace(?) temporary(?) VIEW view_id view_fields(?) /AS/i vie } } +trigger_name : name_with_opt_quotes + +trigger_scope : /FOR/i /EACH/i /(ROW|STATEMENT)/i { $return = lc $1 } + +before_or_after : /(before|after)/i { $return = lc $1 } + +trigger_action : /.+/ + +database_event : /insert|update|delete/i +database_events : database_event(s /OR/) + +create : CREATE /TRIGGER/i trigger_name before_or_after database_events /ON/i table_id trigger_scope(?) trigger_action + { + # Hack to pass roundtrip tests which have trigger statements terminated by double semicolon + # and expect the returned data to have the same + my $action = $item{trigger_action}; + $action =~ s/;$//; + + push @triggers, { + name => $item{trigger_name}, + perform_action_when => $item{before_or_after}, + database_events => $item{database_events}, + on_table => $item{table_id}{table_name}, + scope => $item{'trigger_scope(?)'}[0], + action => $action, + } + } + # # Create anything else (e.g., domain, etc.) # @@ -493,6 +527,7 @@ double_quote: /"/ index_name : name_with_opt_quotes + data_type : pg_data_type parens_value_list(?) { my $data_type = $item[1]; @@ -1088,6 +1123,10 @@ sub parse { $view->extra ( temporary => 1 ) if $vinfo->{is_temporary}; } + for my $trigger (@{ $result->{triggers} }) { + $schema->add_trigger( %$trigger ); + } + return 1; } diff --git a/lib/SQL/Translator/Producer/PostgreSQL.pm b/lib/SQL/Translator/Producer/PostgreSQL.pm index 025ab73..c994817 100644 --- a/lib/SQL/Translator/Producer/PostgreSQL.pm +++ b/lib/SQL/Translator/Producer/PostgreSQL.pm @@ -201,6 +201,13 @@ sub produce { }); } + for my $trigger ( $schema->get_triggers ) { + push @table_defs, create_trigger( $trigger, { + add_drop_trigger => $add_drop_table, + no_comments => $no_comments, + }); + } + push @output, map { "$_;\n\n" } values %type_defs; push @output, map { "$_;\n\n" } @table_defs; if ( @fks ) { @@ -634,6 +641,30 @@ sub create_constraint return \@constraint_defs, \@fks; } +sub create_trigger { + my ($trigger,$options) = @_; + + my @statements; + + push @statements, sprintf( 'DROP TRIGGER IF EXISTS %s', $trigger->name ) + if $options->{add_drop_trigger}; + + my $scope = $trigger->scope || ''; + $scope = " FOR EACH $scope" if $scope; + + push @statements, sprintf( + 'CREATE TRIGGER %s %s %s ON %s%s %s', + $trigger->name, + $trigger->perform_action_when, + join( ' OR ', @{ $trigger->database_events } ), + $trigger->on_table, + $scope, + $trigger->action, + ); + + return @statements; +} + sub convert_datatype { my ($field) = @_; diff --git a/lib/SQL/Translator/Schema/Trigger.pm b/lib/SQL/Translator/Schema/Trigger.pm index 1939fb1..f320fb2 100644 --- a/lib/SQL/Translator/Schema/Trigger.pm +++ b/lib/SQL/Translator/Schema/Trigger.pm @@ -17,6 +17,7 @@ SQL::Translator::Schema::Trigger - SQL::Translator trigger object on_table => 'foo', # table name action => '...', # text of trigger schema => $schema, # Schema object + scope => 'row', # or statement ); =head1 DESCRIPTION @@ -41,7 +42,7 @@ our $VERSION = '1.59'; __PACKAGE__->_attributes( qw/ name schema perform_action_when database_events database_event - fields table on_table action order + fields table on_table action order scope /); =pod @@ -301,6 +302,31 @@ Get or set the trigger's order. return $self->{'order'} || 0; } + +sub scope { + +=pod + +=head2 scope + +Get or set the trigger's scope (row or statement). + + my $scope = $trigger->scope('statement'); + +=cut + + my ( $self, $arg ) = @_; + + if ( defined $arg ) { + return $self->error( "Invalid scope '$arg'" ) + unless $arg =~ /^(row|statement)$/i; + + $self->{scope} = $arg; + } + + return $self->{scope} || ''; +} + sub schema { =pod diff --git a/t/14postgres-parser.t b/t/14postgres-parser.t index 3d29196..96390bf 100644 --- a/t/14postgres-parser.t +++ b/t/14postgres-parser.t @@ -8,12 +8,12 @@ use SQL::Translator::Schema::Constants; use Test::SQL::Translator qw(maybe_plan); BEGIN { - maybe_plan(129, 'SQL::Translator::Parser::PostgreSQL'); + maybe_plan(134, 'SQL::Translator::Parser::PostgreSQL'); SQL::Translator::Parser::PostgreSQL->import('parse'); } my $t = SQL::Translator->new( trace => 0 ); -my $sql = q[ +my $sql = q{ -- comment on t_test1 create table t_test1 ( -- this is the primary key @@ -45,7 +45,7 @@ my $sql = q[ name text, price numeric ); - + CREATE TEMP TABLE products_2 ( product_no integer, name text, @@ -58,6 +58,12 @@ my $sql = q[ price numeric ); + CREATE TRIGGER test_trigger + BEFORE INSERT OR UPDATE OR DELETE + ON products_1 + FOR EACH ROW + EXECUTE PROCEDURE foo(); + alter table t_test1 add f_fk2 integer; alter table only t_test1 add constraint c_u1 unique (f_varchar); @@ -83,7 +89,7 @@ my $sql = q[ alter table t_test1 alter f_char set statistics 10; alter table t_test1 alter f_text set storage extended; - + alter table t_test1 rename column f_text to foo; alter table t_test1 rename to foo; @@ -93,7 +99,7 @@ my $sql = q[ alter table t_test1 owner to foo; commit; -]; +}; $| = 1; @@ -294,3 +300,12 @@ is( $t2_c3->type, CHECK_C, "Constraint is a 'CHECK'" ); is( exists $schema->get_table('products_1')->extra()->{'temporary'}, "", "Table is NOT temporary"); is( $schema->get_table('products_2')->extra('temporary'), 1,"Table is TEMP"); is( $schema->get_table('products_3')->extra('temporary'), 1,"Table is TEMPORARY"); + +# test trigger +my $trigger = $schema->get_trigger('test_trigger'); +is( $trigger->on_table, 'products_1', "Trigger is on correct table"); +is_deeply( scalar $trigger->database_events, [qw(insert update delete)], "Correct events for trigger"); + +is( $trigger->perform_action_when, 'before', "Correct time for trigger"); +is( $trigger->scope, 'row', "Correct scope for trigger"); +is( $trigger->action, 'EXECUTE PROCEDURE foo()', "Correct action for trigger"); diff --git a/t/46xml-to-pg.t b/t/46xml-to-pg.t index e3b9995..61a354d 100644 --- a/t/46xml-to-pg.t +++ b/t/46xml-to-pg.t @@ -64,6 +64,14 @@ CREATE VIEW "email_list" ( "email" ) AS SELECT email FROM Basic WHERE (email IS NOT NULL) ; +DROP TRIGGER IF EXISTS foo_trigger; + +CREATE TRIGGER foo_trigger after insert ON Basic update modified=timestamp();; + +DROP TRIGGER IF EXISTS bar_trigger; + +CREATE TRIGGER bar_trigger before insert OR update ON Basic update modified2=timestamp();; + ALTER TABLE "Basic" ADD FOREIGN KEY ("another_id") REFERENCES "Another" ("id") DEFERRABLE;