diff --git a/lib/SQL/Translator/Diff.pm b/lib/SQL/Translator/Diff.pm index e3d8b0f8..570496c1 100644 --- a/lib/SQL/Translator/Diff.pm +++ b/lib/SQL/Translator/Diff.pm @@ -40,11 +40,47 @@ has table_diff_hash => ( lazy => 1, default => quote_sub '{}', ); +has triggers_to_drop => ( + is => 'rw', + lazy => 1, + default => quote_sub '[]', +); +has triggers_to_modify => ( + is => 'rw', + lazy => 1, + default => quote_sub '[]', +); +has triggers_to_create => ( + is => 'rw', + lazy => 1, + default => quote_sub '[]', +); +has procedures_to_drop => ( + is => 'rw', + lazy => 1, + default => quote_sub '[]', +); +has procedures_to_modify => ( + is => 'rw', + lazy => 1, + default => quote_sub '[]', +); +has procedures_to_create => ( + is => 'rw', + lazy => 1, + default => quote_sub '[]', +); my @diff_arrays = qw/ tables_to_drop tables_to_create - /; + triggers_to_drop + triggers_to_modify + triggers_to_create + procedures_to_drop + procedures_to_modify + procedures_to_create +/; my @diff_hash_keys = qw/ constraints_to_create @@ -115,10 +151,11 @@ sub compute_differences { } my %src_tables_checked = (); - my @tar_tables = sort { $a->name cmp $b->name } $target_schema->get_tables; + my %src_tables_deleted = (); + my @tar_tables = sort { $a->qualified_name cmp $b->qualified_name } $target_schema->get_tables; ## do original/source tables exist in target? for my $tar_table (@tar_tables) { - my $tar_table_name = $tar_table->name; + my $tar_table_name = $tar_table->qualified_name; my $src_table; @@ -143,7 +180,7 @@ sub compute_differences { next; } - my $src_table_name = $src_table->name; + my $src_table_name = $src_table->qualified_name; $src_table_name = lc $src_table_name if $self->case_insensitive; $src_tables_checked{$src_table_name} = 1; @@ -158,12 +195,75 @@ sub compute_differences { } # end of target_schema->get_tables loop for my $src_table ($source_schema->get_tables) { - my $src_table_name = $src_table->name; + my $src_table_name = $src_table->qualified_name; $src_table_name = lc $src_table_name if $self->case_insensitive; - push @{ $self->tables_to_drop }, $src_table - unless $src_tables_checked{$src_table_name}; + next if $src_tables_checked{$src_table_name}; + push @{ $self->tables_to_drop}, $src_table; + $src_tables_deleted{$src_table_name} = 1; + } + + my %src_triggers_checked = (); + my @tgt_triggers = sort { $a->name cmp $b->name } $target_schema->get_triggers; + for my $tgt_trigger ( @tgt_triggers ) { + my $name = $tgt_trigger->name; + + my $src_trigger = $source_schema->get_trigger( $name, $self->case_insensitive ); + + unless ( $src_trigger ) { + push @{$self->triggers_to_create}, $tgt_trigger; + next; + } + + my $src_trigger_name = $src_trigger->name; + $src_trigger_name = lc $src_trigger_name if $self->case_insensitive; + $src_triggers_checked{$src_trigger_name} = 1; + + # Compare trigger + push @{$self->triggers_to_modify}, $tgt_trigger + unless $src_trigger->equals( $tgt_trigger ); + } + + for my $src_trigger ( $source_schema->get_triggers ) { + my $name = $src_trigger->name; + $name = lc $name if $self->case_insensitive; + + my $src_table_name = $src_trigger->on_table; + $src_table_name = lc $src_table_name if $self->case_insensitive; + + push @{ $self->triggers_to_drop }, $src_trigger + unless $src_triggers_checked{$name} or $src_tables_deleted{$src_table_name}; + } + + my %src_procedures_checked = (); + my @tgt_procedures = sort { $a->name cmp $b->name } $target_schema->get_procedures; + for my $tgt_procedure ( @tgt_procedures ) { + my $name = $tgt_procedure->name; + + my $src_procedure = $source_schema->get_procedure( $name, $self->case_insensitive ); + + unless ( $src_procedure ) { + push @{$self->procedures_to_create}, $tgt_procedure; + next; + } + + my $src_procedure_name = $src_procedure->name; + $src_procedure_name = lc $src_procedure_name if $self->case_insensitive; + $src_procedures_checked{$src_procedure_name} = 1; + + # Compare SQL in procedure declaration + next unless $src_procedure->sql ne $tgt_procedure->sql; + push @{$self->procedures_to_modify}, $tgt_procedure; + } + + for my $src_procedure ( $source_schema->get_procedures ) { + my $name = $src_procedure->name; + + $name = lc $name if $self->case_insensitive; + + push @{ $self->procedures_to_drop}, $src_procedure + unless $src_procedures_checked{$name}; } return $self; @@ -280,6 +380,96 @@ sub produce_diff_sql { : die "$producer_class cant drop_table"; } + if (my @triggers = @{ $self->triggers_to_create } ) { + my $translator = SQL::Translator->new( + producer_type => $self->output_db, + add_drop_table => 0, + no_comments => 1, + # TODO: sort out options + %{ $self->producer_args } + ); + $translator->producer_args->{no_transaction} = 1; + my $schema = $translator->schema; + + $schema->add_trigger($_) for @triggers; + + push @diffs, + # Remove begin/commit here, since we wrap everything in one. + grep { $_ !~ /^(?:COMMIT|START(?: TRANSACTION)?|BEGIN(?: TRANSACTION)?)/ } $producer_class->can('produce')->($translator); + } + + if (my @triggers_to_drop = @{ $self->{triggers_to_drop} || []} ) { + my $meth = $producer_class->can('drop_trigger'); + + push @diffs, $meth ? ( map { $meth->($_, $self->producer_args) } @triggers_to_drop) + : $self->ignore_missing_methods + ? "-- $producer_class cant drop_trigger" + : die "$producer_class cant drop_trigger"; + } + + if (my @triggers = @{ $self->triggers_to_modify } ) { + my $translator = SQL::Translator->new( + producer_type => $self->output_db, + add_drop_table => 1, + no_comments => 1, + # TODO: sort out options + %{ $self->producer_args } + ); + $translator->producer_args->{no_transaction} = 1; + my $schema = $translator->schema; + + $schema->add_trigger($_) for @triggers; + + push @diffs, + # Remove begin/commit here, since we wrap everything in one. + grep { $_ !~ /^(?:COMMIT|START(?: TRANSACTION)?|BEGIN(?: TRANSACTION)?)/ } $producer_class->can('produce')->($translator); + } + + if (my @procedures = @{ $self->procedures_to_create } ) { + my $translator = SQL::Translator->new( + producer_type => $self->output_db, + add_drop_table => 0, + no_comments => 1, + # TODO: sort out options + %{ $self->producer_args } + ); + $translator->producer_args->{no_transaction} = 1; + my $schema = $translator->schema; + + $schema->add_procedure($_) for @procedures; + + push @diffs, + # Remove begin/commit here, since we wrap everything in one. + grep { $_ !~ /^(?:COMMIT|START(?: TRANSACTION)?|BEGIN(?: TRANSACTION)?)/ } $producer_class->can('produce')->($translator); + } + + if (my @procedures_to_drop = @{ $self->{procedures_to_drop} || []} ) { + my $meth = $producer_class->can('drop_procedure'); + + push @diffs, $meth ? ( map { $meth->($_, $self->producer_args) } @procedures_to_drop) + : $self->ignore_missing_methods + ? "-- $producer_class cant drop_procedure" + : die "$producer_class cant drop_procedure"; + } + + if (my @procedures_to_modify = @{ $self->{procedures_to_modify} || []} ) { + my $translator = SQL::Translator->new( + producer_type => $self->output_db, + add_drop_table => 1, + no_comments => 1, + # TODO: sort out options + %{ $self->producer_args } + ); + $translator->producer_args->{no_transaction} = 1; + my $schema = $translator->schema; + + $schema->add_procedure($_) for @procedures_to_modify; + + push @diffs, + # Remove begin/commit here, since we wrap everything in one. + grep { $_ !~ /^(?:COMMIT|START(?: TRANSACTION)?|BEGIN(?: TRANSACTION)?)/ } $producer_class->can('produce')->($translator); + } + if (@diffs) { unshift @diffs, "BEGIN"; push @diffs, "\nCOMMIT"; @@ -375,7 +565,7 @@ sub diff_table_fields { if (my $old_name = $tar_table_field->extra->{renamed_from}) { my $src_table_field = $src_table->get_field($old_name, $self->case_insensitive); unless ($src_table_field) { - carp qq#Renamed column can't find old column "@{[$src_table->name]}.$old_name" for renamed column\n#; + carp qq#Renamed column can't find old column "@{[$src_table->qualified_name]}.$old_name" for renamed column\n#; delete $tar_table_field->extra->{renamed_from}; } else { push @{ $self->table_diff_hash->{$tar_table}{fields_to_rename} }, [ $src_table_field, $tar_table_field ]; diff --git a/lib/SQL/Translator/Generator/DDL/SQLServer.pm b/lib/SQL/Translator/Generator/DDL/SQLServer.pm index c738e26f..6d4a09e5 100644 --- a/lib/SQL/Translator/Generator/DDL/SQLServer.pm +++ b/lib/SQL/Translator/Generator/DDL/SQLServer.pm @@ -53,15 +53,15 @@ sub field_autoinc { ($_[1]->is_auto_increment ? 'IDENTITY' : ()) } sub primary_key_constraint { 'CONSTRAINT ' - . $_[0]->quote($_[1]->name || $_[1]->table->name . '_pk') + . $_[0]->quote($_[1]->name || $_[1]->table->qualified_name . '_pk') . ' PRIMARY KEY (' . join(', ', map $_[0]->quote($_), $_[1]->fields) . ')'; } sub index { 'CREATE INDEX ' - . $_[0]->quote($_[1]->name || $_[1]->table->name . '_idx') . ' ON ' - . $_[0]->quote($_[1]->table->name) . ' (' + . $_[0]->quote($_[1]->name || $_[1]->table->qualified_name . '_idx') . ' ON ' + . $_[0]->quote($_[1]->table->qualified_name) . ' (' . join(', ', map $_[0]->quote($_), $_[1]->fields) . ');'; } @@ -76,7 +76,7 @@ sub unique_constraint_single { sub unique_constraint_name { my ($self, $constraint) = @_; - $self->quote($constraint->name || $constraint->table->name . '_uc'); + $self->quote($constraint->name || $constraint->table->qualified_name . '_uc'); } sub unique_constraint_multiple { @@ -84,7 +84,7 @@ sub unique_constraint_multiple { 'CREATE UNIQUE NONCLUSTERED INDEX ' . $self->unique_constraint_name($constraint) . ' ON ' - . $self->quote($constraint->table->name) . ' (' + . $self->quote($constraint->table->qualified_name) . ' (' . join(', ', map $self->quote($_), $constraint->fields) . ')' . ' WHERE ' . join(' AND ', map $self->quote($_->name) . ' IS NOT NULL', grep { $_->is_nullable } $constraint->fields) . ';'; @@ -103,9 +103,9 @@ sub foreign_key_constraint { } 'ALTER TABLE ' - . $self->quote($constraint->table->name) + . $self->quote($constraint->table->qualified_name) . ' ADD CONSTRAINT ' - . $self->quote($constraint->name || $constraint->table->name . '_fk') + . $self->quote($constraint->name || $constraint->table->qualified_name . '_fk') . ' FOREIGN KEY' . ' (' . join(', ', map $self->quote($_), $constraint->fields) . ') REFERENCES ' @@ -163,7 +163,7 @@ sub table { join("\n", $self->table_comments($table), '') . join("\n\n", 'CREATE TABLE ' - . $self->quote($table->name) . " (\n" + . $self->quote($table->qualified_name) . " (\n" . join(",\n", map {" $_"} $self->fields($table), $self->constraints($table),) . "\n);", $self->unique_constraints_multiple($table), $self->indices($table),); } @@ -182,14 +182,14 @@ sub unique_constraints_multiple { sub drop_table { my ($self, $table) = @_; - my $name = $table->name; + my $name = $table->qualified_name; my $q_name = $self->quote($name); "IF EXISTS (SELECT name FROM sysobjects WHERE name = '$name' AND type = 'U')" . " DROP TABLE $q_name;"; } sub remove_table_constraints { my ($self, $table) = @_; - my $name = $table->name; + my $name = $table->qualified_name; my $q_name = $self->quote($name); "IF EXISTS (SELECT name FROM sysobjects WHERE name = '$name' AND type = 'U')" . " ALTER TABLE $q_name NOCHECK CONSTRAINT all;"; @@ -228,7 +228,7 @@ sub schema { $self->header_comments . $self->drop_tables($schema) - . join("\n\n", map $self->table($_), grep { $_->name } $schema->get_tables) . "\n" + . join("\n\n", map $self->table($_), grep { $_->qualified_name } $schema->get_tables) . "\n" . join "\n", $self->foreign_key_constraints($schema); } diff --git a/lib/SQL/Translator/Parser/Oracle.pm b/lib/SQL/Translator/Parser/Oracle.pm index 4058a0b7..6c56ce3f 100644 --- a/lib/SQL/Translator/Parser/Oracle.pm +++ b/lib/SQL/Translator/Parser/Oracle.pm @@ -206,19 +206,25 @@ index_expr: parens_name_list $return = "$item[2]($arg_list)"; } -create : /create/i /or replace/i /trigger/i table_name not_end m#^/$#im +dml_event: /DELETE|INSERT|UPDATE/i { + $item[1] +} + +create : /create/i /or replace/i /trigger/i table_name /BEFORE|AFTER|INSTEAD OF/i dml_event(s) /ON/i table_name not_end m#^/$#im { @table_comments = (); my $trigger_name = $item[4]; # Hack to strip owner from trigger name $trigger_name =~ s#.*\.##; my $owner = ''; - my $action = "$item[1] $item[2] $item[3] $item[4] $item[5]"; - - $triggers{ $trigger_name }{'order'} = ++$trigger_order; - $triggers{ $trigger_name }{'name'} = $trigger_name; - $triggers{ $trigger_name }{'owner'} = $owner; - $triggers{ $trigger_name }{'action'} = $action; + my $action = "$item[1] $item[2] $item[3] $item[4] $item[5] " + .(join ' ', @{$item[6]}) ." $item[7] $item[8]\n$item[9]"; + + $triggers{ $trigger_name }{'order'} = ++$trigger_order; + $triggers{ $trigger_name }{'name'} = $trigger_name; + $triggers{ $trigger_name }{'on_table'} = $item[8]; + $triggers{ $trigger_name }{'owner'} = $owner; + $triggers{ $trigger_name }{'action'} = $action; } create : /create/i /or replace/i /procedure/i table_name not_end m#^/$#im @@ -732,12 +738,13 @@ sub parse { ); } - my @triggers = sort { $result->{triggers}->{$a}->{'order'} <=> $result->{triggers}->{$b}->{'order'} } - keys %{ $result->{triggers} }; + my $trg = $result->{triggers}; + my @triggers = sort { $trg->{$a}->{'order'} <=> $trg->{$b}->{'order'} } keys %$trg; foreach my $trigger_name (@triggers) { $schema->add_trigger( - name => $trigger_name, - action => $result->{triggers}->{$trigger_name}->{action}, + name => $trigger_name, + action => $trg->{$trigger_name}->{action}, + on_table => $trg->{$trigger_name}->{on_table}, ); } diff --git a/lib/SQL/Translator/Parser/PostgreSQL.pm b/lib/SQL/Translator/Parser/PostgreSQL.pm index 0fc5363a..957be9ba 100644 --- a/lib/SQL/Translator/Parser/PostgreSQL.pm +++ b/lib/SQL/Translator/Parser/PostgreSQL.pm @@ -101,7 +101,8 @@ our @EXPORT_OK = qw(parse); our $GRAMMAR = <<'END_OF_GRAMMAR'; -{ my ( %tables, @views, @triggers, $table_order, $field_order, @table_comments) } +{ my ( %tables, @views, @triggers, $table_order, $field_order, @table_comments, + @procedures, $trigger_order, $procedure_order ) } # # The "eofile" rule makes the parser fail if any "statement" rule @@ -114,6 +115,7 @@ startrule : statement(s) eofile { tables => \%tables, views => \@views, triggers => \@triggers, + procedures => \@procedures, } } @@ -192,17 +194,19 @@ update : /update/i statement_body(s?) ';' # create : CREATE temporary(?) TABLE table_id '(' create_definition(s? /,/) ')' table_option(s?) ';' { - my $table_info = $item{'table_id'}; - my $schema_name = $table_info->{'schema_name'}; - my $table_name = $table_info->{'table_name'}; - $tables{ $table_name }{'order'} = ++$table_order; - $tables{ $table_name }{'schema_name'} = $schema_name; - $tables{ $table_name }{'table_name'} = $table_name; + my $table_info = $item{'table_id'}; + my $schema_name = $table_info->{'schema_name'}; + my $table_name = $table_info->{'table_name'}; + my $qualified_name = $table_name; + $qualified_name = $schema_name . '.' . $qualified_name if $schema_name; + $tables{ $qualified_name }{'order'} = ++$table_order; + $tables{ $qualified_name }{'schema_name'} = $schema_name; + $tables{ $qualified_name }{'table_name'} = $table_name; - $tables{ $table_name }{'temporary'} = $item[2][0]; + $tables{ $qualified_name }{'temporary'} = $item[2][0]; if ( @table_comments ) { - $tables{ $table_name }{'comments'} = [ @table_comments ]; + $tables{ $qualified_name }{'comments'} = [ @table_comments ]; @table_comments = (); } @@ -210,25 +214,25 @@ create : CREATE temporary(?) TABLE table_id '(' create_definition(s? /,/) ')' ta for my $definition ( @{ $item[6] } ) { if ( $definition->{'supertype'} eq 'field' ) { my $field_name = $definition->{'name'}; - $tables{ $table_name }{'fields'}{ $field_name } = + $tables{ $qualified_name }{'fields'}{ $field_name } = { %$definition, order => $field_order++ }; for my $constraint ( @{ $definition->{'constraints'} || [] } ) { $constraint->{'fields'} = [ $field_name ]; - push @{ $tables{ $table_name }{'constraints'} }, + push @{ $tables{ $qualified_name }{'constraints'} }, $constraint; } } elsif ( $definition->{'supertype'} eq 'constraint' ) { - push @{ $tables{ $table_name }{'constraints'} }, $definition; + push @{ $tables{ $qualified_name }{'constraints'} }, $definition; } elsif ( $definition->{'supertype'} eq 'index' ) { - push @{ $tables{ $table_name }{'indices'} }, $definition; + push @{ $tables{ $qualified_name }{'indices'} }, $definition; } } for my $option ( @{ $item[8] } ) { - $tables{ $table_name }{'table_options(s?)'}{ $option->{'type'} } = + $tables{ $qualified_name }{'table_options(s?)'}{ $option->{'type'} } = $option; } @@ -240,7 +244,10 @@ create : CREATE unique(?) /(index|key)/i index_name /on/i table_id using_method( my $table_info = $item{'table_id'}; my $schema_name = $table_info->{'schema_name'}; my $table_name = $table_info->{'table_name'}; - push @{ $tables{ $table_name }{'indices'} }, + my $qualified_name = $table_name; + $qualified_name = $schema_name . '.' . $qualified_name if $schema_name; + + push @{ $tables{ $qualified_name }{'indices'} }, { name => $item{'index_name'}, supertype => $item{'unique'}[0] ? 'constraint' : 'index', @@ -295,16 +302,145 @@ create : CREATE /TRIGGER/i trigger_name before_or_after database_events /ON/i ta my $action = $item{trigger_action}; $action =~ s/;$//; + my $table_info = $item{'table_id'}; + my $schema_name = $table_info->{'schema_name'}; + my $table_name = $table_info->{'table_name'}; + my $qualified_name = $table_name; + $qualified_name = $schema_name . '.' . $qualified_name if $schema_name; + push @triggers, { name => $item{trigger_name}, + order => ++$trigger_order, perform_action_when => $item{before_or_after}, database_events => $item{database_events}, - on_table => $item{table_id}{table_name}, + on_table => $qualified_name, scope => $item{'trigger_scope(?)'}[0], action => $action, } } +DOLQDELIMITER : '$' /((?:[^\$])*)/ '$' { $item[2] } + +DOLQSTRING : DOLQDELIMITER /(.*?)(?=\$$item{DOLQDELIMITER}\$)/s DOLQDELIMITER + { + { + quote => join('', '$', $item[1], '$'), + body => $item[3], + } + } + +argmode : /IN|OUT|INOUT|VARIADIC/i { $return = uc $1 } + +ARGUMENT : argmode(?) NAME(?) /((?:[^,\)])*)/ + { $return = { + argmode => $item[1][0], + name => $item[2][0], + type => $item[3] || undef, # Get rid of additional space if type was not provided + } + } + +function_args : '(' ARGUMENT(s? /,/) ')' + { + my @arguments; + foreach my $arg ( @{ $item[2] } ) { + push @arguments, $arg; + } + + $return = \@arguments; + } + +function_id : schema_qualification(?) NAME { + $return = { schema_name => $item[1][0], function_name => $item[2] } +} + +function_return : /RETURNS/i /(.*?)(?=AS|LANGUAGE|COST|IMMUTABLE|STABLE|VOLATILE|(NOT|)LEAKPROOF|;|RETURN|BEGIN ATOMIC)/is + { + my $type = $item[2]; + $type =~ s/\s*$//g; + { type => $type } + } + +function_def : /LANGUAGE/i WORD { { language => $item[2] } } | + /(IMMUTABLE|STABLE|VOLATILE|(NOT|)LEAKPROOF)/i { { attribute => lc $item[1] } } | + /COST/i DIGITS { { cost => $item[2] } } | + /AS/i SQSTRING { { body => $item[2], quote => '\'' } } | + /AS/i DOLQSTRING { $item[2] } | + /RETURN [^;]+/i { { sql => $item[1] } } | + /BEGIN ATOMIC .*?END/i { { sql => $item[1] } } + + +# XXX: roundtrip.xml has configuration which is not applicable to PostgreSQL (see 'sql' property). +# Allow empty body until better solution will be implemented +create : CREATE or_replace(?) /FUNCTION/i function_id function_args function_return(?) function_def(s?) ';' + { + my $function_info = $item{function_id}; + my $func_name = $function_info->{function_name}; + my $schema_name = $function_info->{schema_name}; + my $qualified_name = $func_name; + $qualified_name = $schema_name . '.' . $qualified_name if $schema_name; + + my $sql = 'CREATE FUNCTION '; + $sql .= $qualified_name; + $sql .= ' ('; + my @args = (); + my $has_out; + foreach my $arg (@{$item{function_args}}) { + push @args, join(' ', map $arg->{$_}, + grep defined($arg->{$_}), + qw/argmode name type/); + $has_out ||= defined $arg->{out}; + } + $sql .= join(', ', @args); + $sql .= ')'; + $sql .= "\n"; + + if($item{'function_return(?)'}[0]{type}) { + $sql .= ' RETURNS ' . $item{'function_return(?)'}[0]{type}; + } + elsif(!$has_out) { + # https://www.postgresql.org/docs/current/sql-createfunction.html#rettype + # > If the function is not supposed to return a value, specify void as the return type. + $sql .= ' RETURNS void'; + } + + foreach my $def (@{$item{'function_def(s?)'}}) { + next if !keys %$def; # Do not generate empty line if an empty definition passed + $sql .= "\n"; + $sql .= ' '; + if($def->{body}) { + $sql .= 'AS '; + $sql .= $def->{quote}; + $sql .= $def->{body}; + $sql .= $def->{quote}; + } elsif($def->{language}) { + $sql .= 'LANGUAGE '; + $sql .= $def->{language}; + } elsif($def->{attribute}) { + $sql .= uc $def->{attribute}; + } elsif($def->{cost}) { + $sql .= 'COST '; + $sql .= $def->{cost}; + } elsif($def->{sql}) { + # XXX: Restore original value. See below. + $sql = delete $def->{sql}; + last; + } + } + + # XXX: This is weird: roundtrip.xml defines something under 'sql', + # but here we overwrite that value. + push @procedures, { + name => $qualified_name, + order => ++$procedure_order, + sql => $sql, + parameters => $item{function_args}, + extra => { + returns => $item{'function_return(?)'}[0], + definitions => $item{'function_def(s?)'} + } + }; + } + # # Create anything else (e.g., domain, etc.) # @@ -515,7 +651,7 @@ view_target : '(' /select/i / [^;]+ (?= \) ) /x ')' { view_target_spec : -schema_qualification : NAME '.' +schema_qualification : NAME '.' { $item[1] } schema_name : NAME @@ -793,8 +929,14 @@ key_mutation : /no action/i { $return = 'no_action' } alter : alter_table table_id add_column field ';' { + my $table_info = $item{'table_id'}; + my $schema_name = $table_info->{'schema_name'}; + my $table_name = $table_info->{'table_name'}; + my $qualified_name = $table_name; + $qualified_name = $schema_name . '.' . $qualified_name if $schema_name; + my $field_def = $item[4]; - $tables{ $item[2]->{'table_name'} }{'fields'}{ $field_def->{'name'} } = { + $tables{ $qualified_name }{'fields'}{ $field_def->{'name'} } = { %$field_def, order => $field_order++ }; 1; @@ -802,21 +944,38 @@ alter : alter_table table_id add_column field ';' alter : alter_table table_id ADD table_constraint ';' { - my $table_name = $item[2]->{'table_name'}; + my $table_info = $item{'table_id'}; + my $schema_name = $table_info->{'schema_name'}; + my $table_name = $table_info->{'table_name'}; + my $qualified_name = $table_name; + $qualified_name = $schema_name . '.' . $qualified_name if $schema_name; + my $constraint = $item[4]; - push @{ $tables{ $table_name }{'constraints'} }, $constraint; + push @{ $tables{ $qualified_name }{'constraints'} }, $constraint; 1; } alter : alter_table table_id drop_column NAME restrict_or_cascade(?) ';' { - $tables{ $item[2]->{'table_name'} }{'fields'}{ $item[4] }{'drop'} = 1; + my $table_info = $item{'table_id'}; + my $schema_name = $table_info->{'schema_name'}; + my $table_name = $table_info->{'table_name'}; + my $qualified_name = $table_name; + $qualified_name = $schema_name . '.' . $qualified_name if $schema_name; + + $tables{ $qualified_name }{'fields'}{ $item[4] }{'drop'} = 1; 1; } alter : alter_table table_id alter_column NAME alter_default_val ';' { - $tables{ $item[2]->{'table_name'} }{'fields'}{ $item[4] }{'default'} = + my $table_info = $item{'table_id'}; + my $schema_name = $table_info->{'schema_name'}; + my $table_name = $table_info->{'table_name'}; + my $qualified_name = $table_name; + $qualified_name = $schema_name . '.' . $qualified_name if $schema_name; + + $tables{ $qualified_name }{'fields'}{ $item[4] }{'default'} = $item[5]->{'value'}; 1; } @@ -1082,9 +1241,8 @@ sub parse { for my $table_name (@tables) { my $tdata = $result->{tables}{$table_name}; my $table = $schema->add_table( - - #schema => $tdata->{'schema_name'}, - name => $tdata->{'table_name'}, + schema_qualifier => $tdata->{'schema_name'}, + name => $tdata->{'table_name'}, ) or die "Couldn't create table '$table_name': " . $schema->error; $table->extra(temporary => 1) if $tdata->{'temporary'}; @@ -1127,7 +1285,7 @@ sub parse { type => uc $idata->{'type'}, fields => $idata->{'fields'}, options => \@options - ) or die $table->error . ' ' . $table->name; + ) or die $table->error . ' ' . $table->qualified_name; } for my $cdata (@{ $tdata->{'constraints'} || [] }) { @@ -1152,7 +1310,7 @@ sub parse { or die "Can't add constraint of type '" . $cdata->{'type'} . "' to table '" - . $table->name . "': " + . $table->qualified_name . "': " . $table->error; } } @@ -1173,6 +1331,10 @@ sub parse { $schema->add_trigger(%$trigger); } + for my $procedure (@{ $result->{procedures} }) { + $schema->add_procedure( %$procedure ); + } + return 1; } diff --git a/lib/SQL/Translator/Parser/XML/SQLFairy.pm b/lib/SQL/Translator/Parser/XML/SQLFairy.pm index dc671bc7..045e5297 100644 --- a/lib/SQL/Translator/Parser/XML/SQLFairy.pm +++ b/lib/SQL/Translator/Parser/XML/SQLFairy.pm @@ -222,8 +222,28 @@ sub parse { # Procedures # @nodes = $xp->findnodes('/sqlf:schema/sqlf:procedure|/sqlf:schema/sqlf:procedures/sqlf:procedure'); - foreach (@nodes) { - my %data = get_tagfields($xp, $_, "sqlf:", qw/name sql parameters owner comments order extra/); + foreach my $procn (@nodes) { + my %data = get_tagfields($xp, $procn, "sqlf:", qw/name sql parameters owner comments order extra/); + + my @subnodes = $xp->findnodes('sqlf:extra/sqlf:returns', $procn); + foreach my $retn (@subnodes) { + foreach ($retn->getAttributes) { + $data{extra}{returns}{ $_->getName } = $_->getData; + } + } + + my $defs = $data{extra}{definitions} = []; + @subnodes = $xp->findnodes('sqlf:extra/sqlf:definitions/sqlf:definition', $procn); + foreach my $defn (@subnodes) { + my %definition; + foreach ($defn->getAttributes) { + $definition{ $_->getName } = $_->getData; + } + push @$defs, \%definition if keys %definition; + } + + if(!@$defs) { delete $data{extra}{definitions} } + $schema->add_procedure(%data) or die $schema->error; } diff --git a/lib/SQL/Translator/Producer/MySQL.pm b/lib/SQL/Translator/Producer/MySQL.pm index 50926e50..f44ff1f6 100644 --- a/lib/SQL/Translator/Producer/MySQL.pm +++ b/lib/SQL/Translator/Producer/MySQL.pm @@ -457,7 +457,7 @@ sub create_table { my ($table, $options) = @_; my $generator = _generator($options); - my $table_name = $generator->quote($table->name); + my $table_name = $generator->quote($table->qualified_name); debug("PKG: Looking at table '$table_name'\n"); # @@ -679,7 +679,7 @@ sub _quote_string { sub alter_create_index { my ($index, $options) = @_; - my $table_name = _generator($options)->quote($index->table->name); + my $table_name = _generator($options)->quote($index->table->qualified_name); return join(' ', 'ALTER TABLE', $table_name, 'ADD', create_index(@_)); } @@ -707,7 +707,7 @@ sub create_index { sub alter_drop_index { my ($index, $options) = @_; - my $table_name = _generator($options)->quote($index->table->name); + my $table_name = _generator($options)->quote($index->table->qualified_name); return join(' ', 'ALTER TABLE', $table_name, 'DROP', 'INDEX', $index->name || $index->fields); @@ -717,7 +717,7 @@ sub alter_drop_constraint { my ($c, $options) = @_; my $generator = _generator($options); - my $table_name = $generator->quote($c->table->name); + my $table_name = $generator->quote($c->table->qualified_name); my @out = ('ALTER', 'TABLE', $table_name, 'DROP'); if ($c->type eq PRIMARY_KEY) { @@ -731,7 +731,7 @@ sub alter_drop_constraint { sub alter_create_constraint { my ($index, $options) = @_; - my $table_name = _generator($options)->quote($index->table->name); + my $table_name = _generator($options)->quote($index->table->qualified_name); return join(' ', 'ALTER TABLE', $table_name, 'ADD', create_constraint(@_)); } @@ -788,7 +788,7 @@ sub create_constraint { if (@rfields) { $def .= ' (' . join(', ', map { $generator->quote($_) } @rfields) . ')'; } else { - warn "FK constraint on " . $table->name . '.' . join('', @fields) . " has no reference fields\n" + warn "FK constraint on " . $table->qualified_name . '.' . join('', @fields) . " has no reference fields\n" if $options->{show_warnings}; } @@ -821,7 +821,7 @@ sub alter_table { my ($to_table, $options) = @_; my $table_options = generate_table_options($to_table, $options) || ''; - my $table_name = _generator($options)->quote($to_table->name); + my $table_name = _generator($options)->quote($to_table->qualified_name); my $out = sprintf('ALTER TABLE %s%s', $table_name, $table_options); return $out; @@ -833,7 +833,7 @@ sub alter_field { my ($from_field, $to_field, $options) = @_; my $generator = _generator($options); - my $table_name = $generator->quote($to_field->table->name); + my $table_name = $generator->quote($to_field->table->qualified_name); my $out = sprintf( 'ALTER TABLE %s CHANGE COLUMN %s %s', @@ -848,7 +848,7 @@ sub alter_field { sub add_field { my ($new_field, $options) = @_; - my $table_name = _generator($options)->quote($new_field->table->name); + my $table_name = _generator($options)->quote($new_field->table->qualified_name); my $out = sprintf('ALTER TABLE %s ADD COLUMN %s', $table_name, create_field($new_field, $options)); @@ -860,7 +860,7 @@ sub drop_field { my ($old_field, $options) = @_; my $generator = _generator($options); - my $table_name = $generator->quote($old_field->table->name); + my $table_name = $generator->quote($old_field->table->qualified_name); my $out = sprintf('ALTER TABLE %s DROP COLUMN %s', $table_name, $generator->quote($old_field->name)); @@ -905,7 +905,7 @@ sub batch_alter_table { # rename_table makes things a bit more complex my $renamed_from = ""; - $renamed_from = $generator->quote($diff_hash->{rename_table}[0][0]->name) + $renamed_from = $generator->quote($diff_hash->{rename_table}[0][0]->qualified_name) if $diff_hash->{rename_table} && @{ $diff_hash->{rename_table} }; return unless @stmts; @@ -915,7 +915,7 @@ sub batch_alter_table { # Now strip off the 'ALTER TABLE xyz' of all but the first one - my $table_name = $generator->quote($table->name); + my $table_name = $generator->quote($table->qualified_name); my $re = $renamed_from diff --git a/lib/SQL/Translator/Producer/PostgreSQL.pm b/lib/SQL/Translator/Producer/PostgreSQL.pm index a0d4ac99..956dcc96 100644 --- a/lib/SQL/Translator/Producer/PostgreSQL.pm +++ b/lib/SQL/Translator/Producer/PostgreSQL.pm @@ -219,6 +219,53 @@ and table_constraint is: [ USING acc_method ] ( func_name( column [, ... ]) [ ops_name ] ) [ WHERE predicate ] +=head1 Create Schema Syntax + + CREATE SCHEMA schema_name [ AUTHORIZATION role_specification ] [ schema_element [ ... ] ] + CREATE SCHEMA IF NOT EXISTS schema_name [ AUTHORIZATION role_specification ] + +=head1 Create Trigger Syntax + + CREATE [ CONSTRAINT ] TRIGGER name { BEFORE | AFTER | INSTEAD OF } { event [ OR ... ] } + ON table_name + [ FROM referenced_table_name ] + [ NOT DEFERRABLE | [ DEFERRABLE ] [ INITIALLY IMMEDIATE | INITIALLY DEFERRED ] ] + [ FOR [ EACH ] { ROW | STATEMENT } ] + [ WHEN ( condition ) ] + EXECUTE PROCEDURE function_name ( arguments ) + + where event can be one of: + + INSERT + UPDATE [ OF column_name [, ... ] ] + DELETE + TRUNCATE + + DROP TRIGGER [ IF EXISTS ] name ON table_name [ CASCADE | RESTRICT ] + +=head1 Create Function Syntax + + CREATE [ OR REPLACE ] FUNCTION + name ( [ [ argmode ] [ argname ] argtype [ { DEFAULT | = } default_expr ] [, ...] ] ) + [ RETURNS rettype + | RETURNS TABLE ( column_name column_type [, ...] ) ] + { LANGUAGE lang_name + | TRANSFORM { FOR TYPE type_name } [, ... ] + | WINDOW + | IMMUTABLE | STABLE | VOLATILE | [ NOT ] LEAKPROOF + | CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT + | [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER + | COST execution_cost + | ROWS result_rows + | SET configuration_parameter { TO value | = value | FROM CURRENT } + | AS 'definition' + | AS 'obj_file', 'link_symbol' + } ... + [ WITH ( attribute [, ...] ) ] + + DROP FUNCTION [ IF EXISTS ] name ( [ [ argmode ] [ argname ] argtype [, ...] ] ) + [ CASCADE | RESTRICT ] + =cut sub produce { @@ -281,6 +328,18 @@ sub produce { ); } + for my $procedure ($schema->get_procedures) { + push @table_defs, + create_procedure( + $procedure, + { + add_drop_procedure => $add_drop_table, + generator => $generator, + no_comments => $no_comments, + } + ); + } + push @output, map {"$_;\n\n"} values %type_defs; push @output, map {"$_;\n\n"} @table_defs; if (@fks) { @@ -364,11 +423,21 @@ sub create_table { my $type_defs = $options->{type_defs} || {}; my $attach_comments = $options->{attach_comments}; - my $table_name = $table->name or next; + my $table_name = $table->qualified_name or next; my $table_name_qt = $generator->quote($table_name); my (@comments, @field_defs, @index_defs, @constraint_defs, @fks); + if ( my $schema_name = $table->schema_qualifier and $table->schema ) { + if ( not defined $table->schema->extra->{schema_qualifiers}->{$schema_name} ) { + push @comments, "--\n-- Schema: $schema_name\n--\n" unless $no_comments; + + push @comments, "CREATE SCHEMA IF NOT EXISTS " . + $generator->quote($schema_name) . ";\n"; + } + $table->schema->extra->{schema_qualifiers}->{$schema_name}{$table->qualified_name} = 1; + } + push @comments, "--\n-- Table: $table_name\n--\n" unless $no_comments; my @comment_statements; @@ -521,7 +590,7 @@ sub _enum_typename_and_values { if ($field->extra->{custom_type_name}) { return ($field->extra->{custom_type_name}, $field->extra->{list}); } elsif ($field->data_type eq 'enum') { - my $name = $field->table->name . '_' . $field->name . '_type'; + my $name = $field->table->qualified_name . '_' . $field->name . '_type'; return ($name, $field->extra->{list}); } } @@ -536,7 +605,7 @@ sub _enum_typename_and_values { my ($field, $options) = @_; my $generator = _generator($options); - my $table_name = $field->table->name; + my $table_name = $field->table->qualified_name; my $constraint_defs = $options->{constraint_defs} || []; my $postgres_version = $options->{postgres_version} || 0; my $type_defs = $options->{type_defs} || {}; @@ -660,7 +729,7 @@ sub _extract_extras_from_options { my ($index, $options) = @_; my $generator = _generator($options); - my $table_name = $index->table->name; + my $table_name = $index->table->qualified_name; my $postgres_version = $options->{postgres_version} || 0; my ($index_def, @constraint_defs); @@ -714,7 +783,7 @@ sub create_constraint { my $generator = _generator($options); my $postgres_version = $options->{postgres_version} || 0; - my $table_name = $c->table->name; + my $table_name = $c->table->qualified_name; my (@constraint_defs, @fks); my %constraint_extras; _extract_extras_from_options( @@ -793,25 +862,118 @@ sub create_trigger { my @statements; - push @statements, sprintf('DROP TRIGGER IF EXISTS %s', $generator->quote($trigger->name)) - if $options->{add_drop_trigger}; + push @statements, sprintf( 'DROP TRIGGER IF EXISTS %s ON %s', + $generator->quote($trigger->name), + $generator->quote($trigger->table->qualified_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', + "CREATE TRIGGER %s %s %s\n ON %s%s %s", $generator->quote($trigger->name), $trigger->perform_action_when, join(' OR ', @{ $trigger->database_events }), - $generator->quote($trigger->on_table), + $generator->quote($trigger->table->qualified_name), $scope, $trigger->action, ); return @statements; } +sub drop_trigger { + my ($trigger, $options) = @_; + my $generator = _generator($options); + + my $out = sprintf( 'DROP TRIGGER %s ON %s', + $generator->quote($trigger->name), + $generator->quote($trigger->table->qualified_name) ); + + return $out; +} + +sub create_procedure { + my ($procedure,$options) = @_; + my $generator = _generator($options); + + my @statements; + + push @statements, sprintf( 'DROP FUNCTION IF EXISTS %s', $generator->quote($procedure->name) ) + if $options->{add_drop_procedure}; + + my $sql = 'CREATE FUNCTION '; + $sql .= $generator->quote($procedure->name); + $sql .= ' ('; + my @args = (); + my $has_out; + foreach my $arg (@{$procedure->parameters}) { + $arg = {name => $arg} if ref($arg) ne 'HASH'; + push @args, join(' ', map $arg->{$_}, + grep defined($arg->{$_}), + qw/argmode name type/); + $has_out ||= defined $arg->{out}; + } + $sql .= join(', ', @args); + $sql .= ')'; + $sql .= "\n"; + if($procedure->extra->{returns}{type}) { + $sql .= ' RETURNS ' . $procedure->extra->{returns}{type}; + } + elsif(!$has_out) { + # https://www.postgresql.org/docs/current/sql-createfunction.html#rettype + # > If the function is not supposed to return a value, specify void as the return type. + $sql .= ' RETURNS void'; + } + + my $has_body; + my $language; + foreach my $def (@{$procedure->extra->{definitions}}) { + next if !keys %$def; # Do not generate empty line if an empty definition passed. + $sql .= "\n"; + $sql .= ' '; + if($def->{body}) { + $has_body = 1; + $sql .= 'AS '; + $sql .= $def->{quote}; + $sql .= $def->{body}; + $sql .= $def->{quote}; + } elsif($def->{language}) { + $language = uc $def->{language}; + $sql .= 'LANGUAGE '; + $sql .= $def->{language}; + } elsif($def->{attribute}) { + $sql .= uc $def->{attribute}; + } elsif($def->{cost}) { + $sql .= 'COST '; + $sql .= $def->{cost}; + } + } + + # PostgreSQL allows 'RETURN expr' or 'BEGIN ATOMIC stmt; stmt; END' as sql_body + # only for SQL language. https://www.postgresql.org/docs/current/sql-createfunction.html#sql_body + my $proc_sql = $procedure->sql; + if(!$has_body && (!$language || $language eq 'SQL') && $proc_sql) { + # We can not allow 'SELECT ...' because this DDL will be not parseable later. + # XXX: Right now this mistake is silently ignored. + $sql .= $proc_sql =~ /^RETURN|^BEGIN ATOMIC/i? "\n " . $proc_sql : ''; + } + + push @statements, $sql; + + return @statements; +} + +sub drop_procedure { + my ($procedure, $options) = @_; + my $generator = _generator($options); + + my $out = "DROP FUNCTION " . $generator->quote($procedure->name); + + return $out; +} + sub convert_datatype { my ($field) = @_; @@ -896,7 +1058,7 @@ sub alter_field { my ($from_field, $to_field, $options) = @_; die "Can't alter field in another table" - if ($from_field->table->name ne $to_field->table->name); + if ($from_field->table->qualified_name ne $to_field->table->qualified_name); my $generator = _generator($options); my @out; @@ -912,24 +1074,24 @@ sub alter_field { # $from_field directly push @out, sprintf('ALTER TABLE %s RENAME COLUMN %s TO %s', - map($generator->quote($_), $to_field->table->name, $from_field->name, $to_field->name,),) + map($generator->quote($_), $to_field->table->qualified_name, $from_field->name, $to_field->name,),) if ($from_field->name ne $to_field->name); push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s SET NOT NULL', - map($generator->quote($_), $to_field->table->name, $to_field->name),) + map($generator->quote($_), $to_field->table->qualified_name, $to_field->name),) if (!$to_field->is_nullable and $from_field->is_nullable); push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s DROP NOT NULL', - map($generator->quote($_), $to_field->table->name, $to_field->name),) + map($generator->quote($_), $to_field->table->qualified_name, $to_field->name),) if (!$from_field->is_nullable and $to_field->is_nullable); my $from_dt = convert_datatype($from_field); my $to_dt = convert_datatype($to_field); push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s TYPE %s', - map($generator->quote($_), $to_field->table->name, $to_field->name), $to_dt,) + map($generator->quote($_), $to_field->table->qualified_name, $to_field->name), $to_dt,) if ($to_dt ne $from_dt); my ($from_enum_typename, $from_list) = _enum_typename_and_values($from_field); @@ -970,7 +1132,7 @@ sub alter_field { push @out, sprintf( 'ALTER TABLE %s ALTER COLUMN %s SET DEFAULT %s', - map($generator->quote($_), $to_field->table->name, $to_field->name,), + map($generator->quote($_), $to_field->table->qualified_name, $to_field->name,), $default_value, ) if (defined $new_default @@ -981,7 +1143,7 @@ sub alter_field { push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s DROP DEFAULT', - map($generator->quote($_), $to_field->table->name, $to_field->name,),) + map($generator->quote($_), $to_field->table->qualified_name, $to_field->name,),) if (!defined $new_default && defined $old_default); # add geometry column and constraints @@ -998,13 +1160,13 @@ sub add_field { my $out = sprintf( 'ALTER TABLE %s ADD COLUMN %s', - _generator($options)->quote($new_field->table->name), + _generator($options)->quote($new_field->table->qualified_name), create_field($new_field, $options) ); $out .= ";\n" . add_geometry_column($new_field, $options) . ";\n" . add_geometry_constraints($new_field, $options) if is_geometry($new_field); - return $out; + return $out; } sub drop_field { @@ -1014,11 +1176,12 @@ sub drop_field { my $out = sprintf( 'ALTER TABLE %s DROP COLUMN %s', - $generator->quote($old_field->table->name), + $generator->quote($old_field->table->qualified_name), $generator->quote($old_field->name) ); $out .= ";\n" . drop_geometry_column($old_field, $options) if is_geometry($old_field); + return $out; } @@ -1030,7 +1193,7 @@ sub add_geometry_column { map(__PACKAGE__->_quote_string($_), '', $field->table->schema->name, - $options->{table} ? $options->{table} : $field->table->name, + $options->{table} ? $options->{table} : $field->table->qualified_name, $field->name, $field->extra->{dimensions}, $field->extra->{srid}, @@ -1044,7 +1207,7 @@ sub drop_geometry_column { return sprintf("DELETE FROM geometry_columns WHERE f_table_schema = %s AND f_table_name = %s AND f_geometry_column = %s", - map(__PACKAGE__->_quote_string($_), $field->table->schema->name, $field->table->name, $field->name,),); + map(__PACKAGE__->_quote_string($_), $field->table->schema->name, $field->table->qualified_name, $field->name)); } sub add_geometry_constraints { @@ -1063,7 +1226,7 @@ sub drop_geometry_constraints { sub alter_table { my ($to_table, $options) = @_; my $generator = _generator($options); - my $out = sprintf('ALTER TABLE %s %s', $generator->quote($to_table->name), $options->{alter_table_action}); + my $out = sprintf('ALTER TABLE %s %s', $generator->quote($to_table->qualified_name), $options->{alter_table_action}); $out .= ";\n" . $options->{geometry_changes} if $options->{geometry_changes}; return $out; @@ -1090,7 +1253,7 @@ sub alter_create_index { my ($idef, $constraints) = create_index($index, $options); return $index->type eq NORMAL ? $idef - : sprintf('ALTER TABLE %s ADD %s', $generator->quote($index->table->name), join(q{}, @$constraints)); + : sprintf('ALTER TABLE %s ADD %s', $generator->quote($index->table->qualified_name), join(q{}, @$constraints)); } sub alter_drop_index { @@ -1117,7 +1280,7 @@ sub alter_drop_constraint { $c_name = $c->name; } else { # if the name is dotted we need the table, not schema nor database - my ($tablename) = reverse split /[.]/, $c->table->name; + my ($tablename) = reverse split /[.]/, $c->table->qualified_name; if ($c->type eq FOREIGN_KEY) { # Doesn't have a name, and is foreign key, append '_fkey' @@ -1129,7 +1292,7 @@ sub alter_drop_constraint { } } - return sprintf('ALTER TABLE %s DROP CONSTRAINT %s', map { $generator->quote($_) } $c->table->name, $c_name,); + return sprintf('ALTER TABLE %s DROP CONSTRAINT %s', map { $generator->quote($_) } $c->table->qualified_name, $c_name,); } sub alter_create_constraint { @@ -1144,7 +1307,7 @@ sub alter_create_constraint { return unless (@{$defs} || @{$fks}); return $index->type eq FOREIGN_KEY ? join(q{}, @{$fks}) - : join(' ', 'ALTER TABLE', $generator->quote($index->table->name), 'ADD', join(q{}, @{$defs}, @{$fks})); + : join(' ', 'ALTER TABLE', $generator->quote($index->table->qualified_name), 'ADD', join(q{}, @{$defs}, @{$fks})); } sub drop_table { diff --git a/lib/SQL/Translator/Producer/XML/SQLFairy.pm b/lib/SQL/Translator/Producer/XML/SQLFairy.pm index e0a0eca1..eb6a866f 100644 --- a/lib/SQL/Translator/Producer/XML/SQLFairy.pm +++ b/lib/SQL/Translator/Producer/XML/SQLFairy.pm @@ -295,11 +295,37 @@ sub produce { # # Procedures # - xml_obj_children( - $xml, $schema, - tag => 'procedure', - methods => [qw/name sql parameters owner comments order extra/], - ); + $xml->startTag([ $Namespace => "procedures" ]); + for my $proc ($schema->get_procedures) { + xml_obj( + $xml, $proc, + tag => "procedure", + methods => [qw/name sql parameters owner comments order/], + end_tag => 0 + ); + my $extra = $proc->extra; + my $rets = delete $extra->{returns}; + my $defs = delete $extra->{definitions}; + + $xml->startTag([ $Namespace => 'extra' ], map { ($_, $extra->{$_}) } sort keys %$extra); + + if( $rets && %$rets ) { + $xml->emptyTag([ $Namespace => 'returns' ], map { ($_, $rets->{$_}) } sort keys %$rets); + } + + if( $defs && @$defs ) { + $xml->startTag([ $Namespace => 'definitions' ]); + for my $def ( @$defs ) { + $xml->emptyTag([ $Namespace => 'definition' ], map { ($_, $def->{$_}) } sort keys %$def) + } + $xml->endTag([ $Namespace => 'definitions' ]); + } + + $xml->endTag([ $Namespace => 'extra' ]); + + $xml->endTag([ $Namespace => 'procedure' ]); + } + $xml->endTag([ $Namespace => 'procedures' ]); $xml->endTag([ $Namespace => 'schema' ]); $xml->end; diff --git a/lib/SQL/Translator/Schema.pm b/lib/SQL/Translator/Schema.pm index fcea2930..b1e1407f 100644 --- a/lib/SQL/Translator/Schema.pm +++ b/lib/SQL/Translator/Schema.pm @@ -120,7 +120,7 @@ not be created. $table->order(++$self->_order->{table}); # We know we have a name as the Table->new above errors if none given. - my $table_name = $table->name; + my $table_name = $table->qualified_name; if (defined $self->_tables->{$table_name}) { return $self->error(qq[Can't use table name "$table_name": table exists]); diff --git a/lib/SQL/Translator/Schema/Table.pm b/lib/SQL/Translator/Schema/Table.pm index c15f985f..d0640307 100644 --- a/lib/SQL/Translator/Schema/Table.pm +++ b/lib/SQL/Translator/Schema/Table.pm @@ -40,8 +40,8 @@ our $VERSION = '1.66'; # accidentally set it to undef. We also have to tweak bool so the object is # still true when it doesn't have a name (which shouldn't happen!). use overload - '""' => sub { shift->name }, - 'bool' => sub { $_[0]->name || $_[0] }, + '""' => sub { shift->qualified_name }, + 'bool' => sub { $_[0]->qualified_name || $_[0] }, fallback => 1, ; @@ -56,6 +56,20 @@ Object constructor. name => 'foo', ); +=cut + +around BUILDARGS => sub { + my ($orig, $self, @args) = @_; + my $args = $self->$orig(@args); + + if ( defined $args->{name} and $args->{name} =~ /^(.*?)\.(.*)$/ ) { + $args->{schema_qualifier} = $1; + $args->{name} = $2; + } + + return $args; +}; + =head2 add_constraint Add a constraint to the table. Returns the newly created @@ -673,17 +687,46 @@ has name => ( around name => sub { my $orig = shift; my $self = shift; + my @args = @_; if (my ($arg) = @_) { + if ( $arg =~ /^(.*?)\.(.*)$/ ) { + $self->schema_qualifier($1); + $arg = $2; + @args = ($arg); + } + + $arg = join('.', $self->schema_qualifier, $arg) if ( $self->schema_qualifier ); if (my $schema = $self->schema) { return $self->error(qq[Can't use table name "$arg": table exists]) if $schema->get_table($arg); } } - return ex2err($orig, $self, @_); + return ex2err($orig, $self, @args); }; +=head2 schema_qualifier + +Get or set table's schema qualifier (database schema name). + +=cut + +has schema_qualifier => ( is => 'rw' ); + +=head2 qualified_name + +Get qualified name, with optional schema qualifier + +=cut + +sub qualified_name { + my $self = shift; + my @components = ($self->name); + unshift @components, $self->schema_qualifier if $self->schema_qualifier; + return join('.', @components); +} + =head2 schema Get or set the table's schema object. diff --git a/lib/SQL/Translator/Schema/Trigger.pm b/lib/SQL/Translator/Schema/Trigger.pm index f9843f60..b49969f0 100644 --- a/lib/SQL/Translator/Schema/Trigger.pm +++ b/lib/SQL/Translator/Schema/Trigger.pm @@ -193,7 +193,7 @@ Gets or set the table name on which the trigger works, as a string. if !$table; $self->table($table); } - return $self->table->name; + return $self->table->qualified_name; } =head2 action diff --git a/t/13schema.t b/t/13schema.t index 6fd63af6..10cc7278 100644 --- a/t/13schema.t +++ b/t/13schema.t @@ -824,4 +824,24 @@ require_ok('SQL::Translator::Schema'); ok(!$t4->can_link($t1, $t2)->[0], 'Self-link table can\'t link other'); } + +# +# Support for schema qualifiers +# + +{ + my $s = SQL::Translator::Schema->new; + my $t1 = $s->add_table( name => 'sec.person' ); + + is( $t1->name, 'person', 'sec.person name is person'); + is( $t1->schema_qualifier, 'sec', 'sec.person schema qualifier is sec'); + is( $t1->qualified_name, 'sec.person', 'sec.person qualified name is ok'); + + $t1->name('pri.person'); + + is( $t1->schema_qualifier, 'pri', 'sec.person schema qualifier changed to pri'); + is( $t1->name, 'person', 'pri.person name is person'); + is( $t1->qualified_name, 'pri.person', 'pri.person qualified name is ok'); +} + done_testing; diff --git a/t/14postgres-parser.t b/t/14postgres-parser.t index b27b4d26..2c74ec1d 100644 --- a/t/14postgres-parser.t +++ b/t/14postgres-parser.t @@ -121,6 +121,24 @@ baz $foo$, create materialized view if not exists baa (black, sheep) as select foo black, bar sheep from baz; + -- Triggers + CREATE TRIGGER test_trigger before update OR insert ON t_test1 + FOR EACH ROW EXECUTE PROCEDURE test_trigger_proc(); + + -- Functions + CREATE FUNCTION test_func1(arg1 character varying) + RETURNS character varying + AS 'my ($arg1) = @_; return "Hello: " . ($arg1 // "unnamed");' + LANGUAGE plperl; + + CREATE FUNCTION test_func2 () RETURNS int AS $$function body$$; + + create table secschema.t_test1 ( + f_serial serial NOT NULL primary key + ); + + alter table secschema.t_test1 add f_fk2s integer; + commit; }; @@ -131,7 +149,7 @@ my $schema = $t->schema; isa_ok($schema, 'SQL::Translator::Schema', 'Schema object'); my @tables = $schema->get_tables; -is(scalar @tables, 5, 'Five tables'); +is(scalar @tables, 6, 'Six tables'); my $t1 = shift @tables; is($t1->name, 't_test1', 'Table t_test1 exists'); @@ -409,6 +427,8 @@ is($schema->get_table('products_2')->extra('temporary'), 1, "Table i is($schema->get_table('products_3')->extra('temporary'), 1, "Table is TEMPORARY"); # test trigger +my @triggers = $schema->get_triggers; +ok( @triggers == 1, 'one trigger defined'); 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"); @@ -449,4 +469,42 @@ is_deeply( 'Index is using hash method and has predicate right and include INCLUDE' ); +# Procedures +my @procedures = $schema->get_procedures; +#use Data::Dumper; +#print STDERR Dumper(\@procedures); +ok( @procedures == 2, 'two procedures parsed' ); + +my $p1 = shift @procedures; +is ($p1->name, 'test_func1', 'First procedure is "test_func1"'); + +my $p2 = shift @procedures; +is ($p2->name, 'test_func2', 'Second procedure is "test_func2"'); + +# Qualified with schema +my $t1s = pop @tables; + +is( $t1s->name, 't_test1', 'Table t_test1 from secschema schema exists' ); +is( $t1s->schema_qualifier, 'secschema', 'Table t_test1 has correct schema: secschema' ); +is( $t1s->qualified_name, 'secschema.t_test1', 'Table t_test1 from secschema schema has correct qualified name' ); + +my @t1s_fields = $t1s->get_fields; +is( scalar @t1s_fields, 2, '2 fields secschema.in t_test1' ); + +my $t1s_f1 = shift @t1s_fields; +is( $t1s_f1->name, 'f_serial', 'First field is "f_serial"' ); +is( $t1s_f1->data_type, 'integer', 'Field is an integer' ); +is( $t1s_f1->is_nullable, 0, 'Field cannot be null' ); +is( $t1s_f1->size, 11, 'Size is "11"' ); +is( $t1s_f1->default_value, undef, 'Default value is undefined' ); +is( $t1s_f1->is_primary_key, 1, 'Field is PK' ); + +my $t1s_f2 = shift @t1s_fields; +is( $t1s_f2->name, 'f_fk2s', 'Second field is "f_fk2s"' ); +is( $t1s_f2->data_type, 'integer', 'Field is an integer' ); +is( $t1s_f2->is_nullable, 1, 'Field can be null' ); +is( $t1s_f2->size, 10, 'Size is "10"' ); +is( $t1s_f2->default_value, undef, 'Default value is undefined' ); +is( $t1s_f2->is_primary_key, 0, 'Field is not PK' ); + done_testing; diff --git a/t/17sqlfxml-producer.t b/t/17sqlfxml-producer.t index 09e78ada..7ecd18f3 100644 --- a/t/17sqlfxml-producer.t +++ b/t/17sqlfxml-producer.t @@ -255,7 +255,7 @@ EOXML select foo from bar Go Sox! - + diff --git a/t/30sqlt-new-diff-pgsql.t b/t/30sqlt-new-diff-pgsql.t index 3d269ae9..b4b2980d 100644 --- a/t/30sqlt-new-diff-pgsql.t +++ b/t/30sqlt-new-diff-pgsql.t @@ -96,6 +96,30 @@ ALTER TABLE "person" ADD CONSTRAINT "UC_age_name" UNIQUE ("age", "name"); DROP TABLE "deleted" CASCADE; +CREATE TRIGGER "trg_created" before update OR insert + ON "employee" FOR EACH row EXECUTE PROCEDURE something(); + +DROP TRIGGER "trg_deleted" ON "employee"; + +DROP TRIGGER IF EXISTS "trg_modify" ON "employee"; + +CREATE TRIGGER "trg_modify" before update OR insert + ON "employee" FOR EACH row EXECUTE PROCEDURE something_else(); + +CREATE FUNCTION "new_proc" () + RETURNS int + LANGUAGE plpgsql + AS $$RETURN 3 + 3;$$; + +DROP FUNCTION "deleted_proc"; + +DROP FUNCTION IF EXISTS "modified_proc"; + +CREATE FUNCTION "modified_proc" () + RETURNS int + LANGUAGE plpgsql + AS $$RETURN 3 + 2;$$; + COMMIT; @@ -156,6 +180,30 @@ ALTER TABLE person ADD CONSTRAINT UC_age_name UNIQUE (age, name); DROP TABLE deleted CASCADE; +CREATE TRIGGER trg_created before update OR insert + ON employee FOR EACH row EXECUTE PROCEDURE something(); + +DROP TRIGGER trg_deleted ON employee; + +DROP TRIGGER IF EXISTS trg_modify ON employee; + +CREATE TRIGGER trg_modify before update OR insert + ON employee FOR EACH row EXECUTE PROCEDURE something_else(); + +CREATE FUNCTION new_proc () + RETURNS int + LANGUAGE plpgsql + AS $$RETURN 3 + 3;$$; + +DROP FUNCTION deleted_proc; + +DROP FUNCTION IF EXISTS modified_proc; + +CREATE FUNCTION modified_proc () + RETURNS int + LANGUAGE plpgsql + AS $$RETURN 3 + 2;$$; + COMMIT; diff --git a/t/46xml-to-pg.t b/t/46xml-to-pg.t index 70fa37fc..e61b6fe9 100644 --- a/t/46xml-to-pg.t +++ b/t/46xml-to-pg.t @@ -63,13 +63,20 @@ CREATE VIEW "email_list" ( "email" ) AS SELECT email FROM Basic WHERE (email IS NOT NULL) ; -DROP TRIGGER IF EXISTS "foo_trigger"; +DROP TRIGGER IF EXISTS "foo_trigger" ON "Basic"; -CREATE TRIGGER "foo_trigger" after insert ON "Basic" FOR EACH row update modified=timestamp();; +CREATE TRIGGER "foo_trigger" after insert + ON "Basic" FOR EACH row update modified=timestamp();; -DROP TRIGGER IF EXISTS "bar_trigger"; +DROP TRIGGER IF EXISTS "bar_trigger" ON "Basic"; -CREATE TRIGGER "bar_trigger" before insert OR update ON "Basic" FOR EACH row update modified2=timestamp();; +CREATE TRIGGER "bar_trigger" before insert OR update + ON "Basic" FOR EACH row update modified2=timestamp();; + +DROP FUNCTION IF EXISTS "foo_proc"; + +CREATE FUNCTION "foo_proc" (foo, bar) + RETURNS void; ALTER TABLE "Basic" ADD FOREIGN KEY ("another_id") REFERENCES "Another" ("id") DEFERRABLE; diff --git a/t/47postgres-producer.t b/t/47postgres-producer.t index 56f9a2c9..fc04b4bf 100644 --- a/t/47postgres-producer.t +++ b/t/47postgres-producer.t @@ -42,7 +42,7 @@ my $PRODUCER = \&SQL::Translator::Producer::PostgreSQL::create_field; my ($create, $fks) = SQL::Translator::Producer::PostgreSQL::create_table($table, { quote_table_names => q{"}, attach_comments => 1 }); - is($table->name, 'foo.bar'); + is($table->qualified_name, 'foo.bar'); my $expected = <new( name => 'view_foo', fields => [qw/id name/], @@ -871,4 +873,53 @@ my $mat_view_sql_expected = "CREATE MATERIALIZED VIEW view_foo ( id, name ) AS "; is($mat_view_sql, $mat_view_sql_expected, 'correct "MATERIALIZED VIEW" SQL'); + + +# Triggers +{ + my $schema = SQL::Translator::Schema->new(); + my $table = $schema->add_table( name => 'test_table' ); + my $trigger1 = $schema->add_trigger( + name => 'test_trigger', + perform_action_when => 'BEFORE', + database_events => [qw/UPDATE INSERT/], + on_table => 'test_table', + action => 'EXECUTE PROCEDURE test_trigger_proc()', + scope => 'ROW', + ); + + my $create_trigger_opts = { add_drop_trigger => 1, no_comments => 1 }; + my @trigger1_sqls = SQL::Translator::Producer::PostgreSQL::create_trigger($trigger1, $create_trigger_opts); + ok(@trigger1_sqls == 2, "DROP & CREATE TRIGGER"); + is($trigger1_sqls[0], "DROP TRIGGER IF EXISTS test_trigger ON test_table", "trigger dropped"); + is($trigger1_sqls[1], "CREATE TRIGGER test_trigger before update OR insert\n ON test_table " + . "FOR EACH ROW EXECUTE PROCEDURE test_trigger_proc()", "trigger created"); +} + +# Functions +{ + my $func1_sql = 'CREATE FUNCTION test_func1 (arg1 character varying)' . "\n" . + ' RETURNS character varying' . "\n" . + ' AS \'my ($arg1) = @_; return "Hello: " . ($arg1 // "unnamed");\'' . "\n" . + ' LANGUAGE plperl'; + my $function1 = SQL::Translator::Schema::Procedure->new( + name => 'test_func1', + sql => $func1_sql, + parameters => [{name => 'arg1', type => 'character varying'}], + extra => { + returns => {type => 'character varying'}, + definitions => [ + {quote => "'", body => 'my ($arg1) = @_; return "Hello: " . ($arg1 // "unnamed");'}, + {language => 'plperl'}, + ] + } + ); + + my $create_function_opts = { add_drop_procedure => 1, no_comments => 1 }; + my @function1_sqls = SQL::Translator::Producer::PostgreSQL::create_procedure($function1, $create_function_opts); + ok(@function1_sqls == 2, "DROP & CREATE FUNCTION"); + eq_or_diff($function1_sqls[0], "DROP FUNCTION IF EXISTS test_func1", "function dropped"); + eq_or_diff($function1_sqls[1], $func1_sql, "function created"); +} + done_testing; diff --git a/t/75-sqlserver-producer.t b/t/75-sqlserver-producer.t index 97c24e6b..03b4a687 100644 --- a/t/75-sqlserver-producer.t +++ b/t/75-sqlserver-producer.t @@ -105,4 +105,4 @@ my $generator = $sqlt->translate(\$yaml_in) ok $generator ne "", "Produced something!"; my $correct = join("\n", @stmts); -eq_or_diff $correct, $generator, "Scalar output looks correct"; +eq_or_diff $generator, $correct, "Scalar output looks correct"; diff --git a/t/data/diff/pgsql/create1.yml b/t/data/diff/pgsql/create1.yml index 04b47c06..524a2b12 100644 --- a/t/data/diff/pgsql/create1.yml +++ b/t/data/diff/pgsql/create1.yml @@ -1,6 +1,39 @@ --- schema: - procedures: {} + procedures: + deleted_proc: + order: 1 + name: deleted_proc + extra: + returns: + type: int + definitions: + - language: plpgsql + - body: 'RETURN 1 + 1;' + quote: '$$' + sql: 'CREATE FUNCTION deleted_proc () RETURNS int LANGUAGE plpgsql AS $$RETURN 1 + 1;$$' + modified_proc: + order: 2 + name: modified_proc + extra: + returns: + type: int + definitions: + - language: plpgsql + - body: 'RETURN 1 + 2;' + quote: '$$' + sql: 'CREATE FUNCTION modified_proc () RETURNS int LANGUAGE plpgsql AS $$RETURN 1 + 2;$$' + some_proc: + order: 3 + name: some_proc + extra: + returns: + type: int + definitions: + - language: plpgsql + - body: 'RETURN 2 + 2;' + quote: '$$' + sql: 'CREATE FUNCTION some_proc () RETURNS int LANGUAGE plpgsql AS $$RETURN 2 + 2;$$' tables: deleted: constraints: @@ -233,7 +266,47 @@ schema: type: UNIQUE name: person order: 1 - triggers: {} + triggers: + trg_deleted: + order: 1 + name: trg_deleted + perform_action_when: before + database_events: + - update + - insert + on_table: employee + action: 'EXECUTE PROCEDURE something()' + scope: row + trg_keep: + order: 2 + name: trg_keep + perform_action_when: before + database_events: + - update + - insert + on_table: employee + action: 'EXECUTE PROCEDURE something()' + scope: row + trg_modify: + order: 3 + name: trg_modify + perform_action_when: before + database_events: + - update + - insert + on_table: employee + action: 'EXECUTE PROCEDURE something()' + scope: row + trg_on_deleted: + order: 4 + name: trg_on_deleted + perform_action_when: before + database_events: + - update + - insert + on_table: deleted + action: 'EXECUTE PROCEDURE something()' + scope: row views: {} translator: add_drop_table: 0 diff --git a/t/data/diff/pgsql/create2.yml b/t/data/diff/pgsql/create2.yml index b58fdee8..839e7510 100644 --- a/t/data/diff/pgsql/create2.yml +++ b/t/data/diff/pgsql/create2.yml @@ -1,6 +1,39 @@ --- schema: - procedures: {} + procedures: + modified_proc: + order: 2 + name: 'modified_proc' + extra: + returns: + type: int + definitions: + - language: plpgsql + - body: 'RETURN 3 + 2;' + quote: '$$' + sql: 'CREATE FUNCTION modified_proc () RETURNS int LANGUAGE plpgsql AS $$RETURN 3 + 2;$$' + some_proc: + order: 3 + name: 'some_proc' + extra: + returns: + type: int + definitions: + - language: plpgsql + - body: 'RETURN 2 + 2;' + quote: '$$' + sql: 'CREATE FUNCTION some_proc () RETURNS int LANGUAGE plpgsql AS $$RETURN 2 + 2;$$' + new_proc: + order: 4 + name: 'new_proc' + extra: + returns: + type: int + definitions: + - language: plpgsql + - body: 'RETURN 3 + 3;' + quote: '$$' + sql: 'CREATE FUNCTION new_proc () RETURNS int LANGUAGE plpgsql AS $$RETURN 3 + 3;$$' tables: added: constraints: [] @@ -232,7 +265,37 @@ schema: type: UNIQUE name: person order: 1 - triggers: {} + triggers: + trg_keep: + order: 2 + name: trg_keep + perform_action_when: before + database_events: + - update + - insert + on_table: employee + action: 'EXECUTE PROCEDURE something()' + scope: row + trg_modify: + order: 3 + name: trg_modify + perform_action_when: before + database_events: + - update + - insert + on_table: employee + action: 'EXECUTE PROCEDURE something_else()' + scope: row + trg_created: + order: 5 + name: trg_created + perform_action_when: before + database_events: + - update + - insert + on_table: employee + action: 'EXECUTE PROCEDURE something()' + scope: row views: {} translator: add_drop_table: 0 diff --git a/t/data/roundtrip.xml b/t/data/roundtrip.xml index 98fff7e6..abea97a8 100644 --- a/t/data/roundtrip.xml +++ b/t/data/roundtrip.xml @@ -1,11 +1,11 @@ - - + @@ -143,6 +143,19 @@ Created on Fri Aug 15 15:08:18 2003 Go Sox! + + RETURN 5 + + + + + + + + + + + + -