+* 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)
$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
# 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/
}
}
+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.)
#
index_name : name_with_opt_quotes
+
data_type : pg_data_type parens_value_list(?)
{
my $data_type = $item[1];
$view->extra ( temporary => 1 ) if $vinfo->{is_temporary};
}
+ for my $trigger (@{ $result->{triggers} }) {
+ $schema->add_trigger( %$trigger );
+ }
+
return 1;
}
});
}
+ 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 ) {
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) = @_;
on_table => 'foo', # table name
action => '...', # text of trigger
schema => $schema, # Schema object
+ scope => 'row', # or statement
);
=head1 DESCRIPTION
__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
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
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
name text,
price numeric
);
-
+
CREATE TEMP TABLE products_2 (
product_no integer,
name text,
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);
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;
alter table t_test1 owner to foo;
commit;
-];
+};
$| = 1;
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");
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;