From: Andreas 'ac0v' Specht Date: Wed, 6 Apr 2011 18:20:02 +0000 (+0200) Subject: fixed alter_drop_constraint for foreign keys and applying multiple changes via alter_... X-Git-Tag: v0.11011~80 X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=commitdiff_plain;h=c50d1a0afe9acf17c421acdfae25cf050b1da92e;p=dbsrgits%2FSQL-Translator.git fixed alter_drop_constraint for foreign keys and applying multiple changes via alter_field to a column in Postgres Producer --- diff --git a/AUTHORS b/AUTHORS index c0775c7..2e18e14 100644 --- a/AUTHORS +++ b/AUTHORS @@ -4,6 +4,7 @@ The following people have contributed to the SQLFairy project: - Allen Day - Amiri Barksdale - Anders Nor Berle +- Andreas 'ac0v' Specht - Andrew Moore - Andrew Pam - Arthur Axel "fREW" Schmidt diff --git a/Changes b/Changes index db1fc00..ddb3489 100644 --- a/Changes +++ b/Changes @@ -1,6 +1,8 @@ * 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) +* Fixed alter_drop_constraint for foreign keys and applying multiple changes + via alter_field to a column in Postgres Producer # ---------------------------------------------------------- # 0.11010 2011-10-05 diff --git a/lib/SQL/Translator/Producer/PostgreSQL.pm b/lib/SQL/Translator/Producer/PostgreSQL.pm index c01b2ea..66b295b 100644 --- a/lib/SQL/Translator/Producer/PostgreSQL.pm +++ b/lib/SQL/Translator/Producer/PostgreSQL.pm @@ -775,8 +775,19 @@ sub alter_field my @out; # drop geometry column and constraints - push @out, drop_geometry_column($from_field) if is_geometry($from_field); - push @out, drop_geometry_constraints($from_field) if is_geometry($from_field); + push @out, drop_geometry_column($from_field) if is_geometry($from_field); + push @out, drop_geometry_constraints($from_field) if is_geometry($from_field); + + # it's necessary to start with rename column cause this would affect + # all of the following statements which would be broken if do the + # rename later + # BUT: drop geometry is done before the rename, cause it work's on the + # $from_field directly + push @out, sprintf('ALTER TABLE %s RENAME COLUMN %s TO %s', + $to_field->table->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', $to_field->table->name, @@ -796,11 +807,6 @@ sub alter_field $to_field->name, $to_dt) if($to_dt ne $from_dt); - push @out, sprintf('ALTER TABLE %s RENAME COLUMN %s TO %s', - $to_field->table->name, - $from_field->name, - $to_field->name) if($from_field->name ne $to_field->name); - my $old_default = $from_field->default_value; my $new_default = $to_field->default_value; my $default_value = $to_field->default_value; @@ -833,7 +839,7 @@ sub alter_field push @out, add_geometry_column($to_field) if is_geometry($to_field); push @out, add_geometry_constraints($to_field) if is_geometry($to_field); - return wantarray ? @out : join("\n", @out); + return wantarray ? @out : join(";\n", @out); } sub rename_field { alter_field(@_) } @@ -853,12 +859,15 @@ sub add_field sub drop_field { - my ($old_field) = @_; + my ($old_field, $options) = @_; + + my $qt = $options->{quote_table_names} ||''; + my $qf = $options->{quote_field_names} ||''; my $out = sprintf('ALTER TABLE %s DROP COLUMN %s', - $old_field->table->name, - $old_field->name); - $out .= "\n".drop_geometry_column($old_field) if is_geometry($old_field); + $qt . $old_field->table->name . $qt, + $qf . $old_field->name . $qf); + $out .= "\n".drop_geometry_column($old_field) if is_geometry($old_field); return $out; } @@ -957,10 +966,17 @@ sub alter_drop_constraint { my ($c, $options) = @_; my $qt = $options->{quote_table_names} || ''; my $qc = $options->{quote_field_names} || ''; - my $out = sprintf('ALTER TABLE %s DROP CONSTRAINT %s', - $qt . $c->table->name . $qt, - $qc . $c->name . $qc ); - return $out; + + return sprintf( + 'ALTER TABLE %s DROP CONSTRAINT %s', + $qt . $c->table->name . $qt, + # attention: Postgres has a very special naming structure + # for naming foreign keys, it names them uses the name of + # the table as prefix and fkey as suffix, concatenated by a underscore + $c->type eq FOREIGN_KEY + ? $qc . $c->table->name . '_' . ($c->fields)[0] . '_fkey' . $qc + : $qc . $c->name . $qc + ); } sub alter_create_constraint { diff --git a/t/30sqlt-new-diff-pgsql.t b/t/30sqlt-new-diff-pgsql.t index 83acc2e..eb39f01 100644 --- a/t/30sqlt-new-diff-pgsql.t +++ b/t/30sqlt-new-diff-pgsql.t @@ -45,6 +45,7 @@ my $out = SQL::Translator::Diff::schema_diff( } } ); + eq_or_diff($out, <<'## END OF DIFF', "Diff as expected"); -- Convert schema 'create1.yml' to 'create2.yml':; @@ -56,7 +57,7 @@ CREATE TABLE added ( ALTER TABLE old_name RENAME TO new_name; -ALTER TABLE employee DROP CONSTRAINT FK5302D47D93FE702E; +ALTER TABLE employee DROP CONSTRAINT employee_employee_id_fkey; ALTER TABLE person DROP CONSTRAINT UC_age_name; diff --git a/t/47postgres-producer.t b/t/47postgres-producer.t index 46d4dea..ebb0888 100644 --- a/t/47postgres-producer.t +++ b/t/47postgres-producer.t @@ -14,7 +14,7 @@ use FindBin qw/$Bin/; #============================================================================= BEGIN { - maybe_plan(41, + maybe_plan(48, 'SQL::Translator::Producer::PostgreSQL', 'Test::Differences', ) @@ -64,12 +64,89 @@ my $field2 = SQL::Translator::Schema::Field->new( name => 'myfield', is_foreign_key => 0, is_unique => 0 ); +my $pk_constraint = SQL::Translator::Schema::Constraint->new( + table => $table, + name => 'foo', + fields => [qw(myfield)], + type => 'PRIMARY_KEY', +); + +my ($pk_constraint_def_ref, $pk_constraint_fk_ref ) = SQL::Translator::Producer::PostgreSQL::create_constraint($pk_constraint); +ok(@{$pk_constraint_def_ref} == 1 && @{$pk_constraint_fk_ref} == 0, 'precheck of create_Primary Key constraint'); +is($pk_constraint_def_ref->[0], 'CONSTRAINT foo PRIMARY KEY (myfield)', 'Create Primary Key Constraint works'); + +my $alter_pk_constraint = SQL::Translator::Producer::PostgreSQL::alter_drop_constraint($pk_constraint); +is($alter_pk_constraint, 'ALTER TABLE mytable DROP CONSTRAINT foo', 'Alter drop Primary Key constraint works'); + +my $table2 = SQL::Translator::Schema::Table->new( name => 'mytable2'); + +my $field1_2 = SQL::Translator::Schema::Field->new( name => 'myfield_2', + table => $table, + data_type => 'VARCHAR', + size => 10, + default_value => undef, + is_auto_increment => 0, + is_nullable => 1, + is_foreign_key => 0, + is_unique => 0 ); + +my $fk_constraint = SQL::Translator::Schema::Constraint->new( + table => $table, + name => 'foo', + fields => [qw(myfield)], + type => 'FOREIGN_KEY', + reference_table => $table2, + reference_fields => [qw(myfield_2)], +); + +my ($fk_constraint_def_ref, $fk_constraint_fk_ref ) = SQL::Translator::Producer::PostgreSQL::create_constraint($fk_constraint); + +ok(@{$fk_constraint_def_ref} == 0 && @{$fk_constraint_fk_ref} == 1, 'precheck of create_Foreign Key constraint'); +is($fk_constraint_fk_ref->[0], 'ALTER TABLE mytable ADD FOREIGN KEY (myfield) + REFERENCES mytable2 (myfield_2) DEFERRABLE', 'Create Foreign Key Constraint works'); + +my $alter_fk_constraint = SQL::Translator::Producer::PostgreSQL::alter_drop_constraint($fk_constraint); +is($alter_fk_constraint, 'ALTER TABLE mytable DROP CONSTRAINT mytable_myfield_fkey', 'Alter drop Foreign Key constraint works'); + my $alter_field = SQL::Translator::Producer::PostgreSQL::alter_field($field1, $field2); -is($alter_field, qq[ALTER TABLE mytable ALTER COLUMN myfield SET NOT NULL +is($alter_field, qq[ALTER TABLE mytable ALTER COLUMN myfield SET NOT NULL; ALTER TABLE mytable ALTER COLUMN myfield TYPE character varying(25)], 'Alter field works'); +my $field1_complex = SQL::Translator::Schema::Field->new( + name => 'my_complex_field', + table => $table, + data_type => 'VARCHAR', + size => 10, + default_value => undef, + is_auto_increment => 0, + is_nullable => 1, + is_foreign_key => 0, + is_unique => 0 +); + +my $field2_complex = SQL::Translator::Schema::Field->new( + name => 'my_altered_field', + table => $table, + data_type => 'VARCHAR', + size => 60, + default_value => 'whatever', + is_auto_increment => 0, + is_nullable => 1, + is_foreign_key => 0, + is_unique => 0 +); + +my $alter_field_complex = SQL::Translator::Producer::PostgreSQL::alter_field($field1_complex, $field2_complex); +is( + $alter_field_complex, + q{ALTER TABLE mytable RENAME COLUMN my_complex_field TO my_altered_field; +ALTER TABLE mytable ALTER COLUMN my_altered_field TYPE character varying(60); +ALTER TABLE mytable ALTER COLUMN my_altered_field SET DEFAULT 'whatever'}, + 'Complex Alter field works' +); + $field1->name('field3'); my $add_field = SQL::Translator::Producer::PostgreSQL::add_field($field1); diff --git a/t/63-spacial-pgsql.t b/t/63-spacial-pgsql.t index fc4c418..9eddc0c 100644 --- a/t/63-spacial-pgsql.t +++ b/t/63-spacial-pgsql.t @@ -69,19 +69,19 @@ my $field2 = SQL::Translator::Schema::Field->new( name => 'myfield', my $alter_field = SQL::Translator::Producer::PostgreSQL::alter_field($field1, $field2); -is($alter_field, qq[DELETE FROM geometry_columns WHERE f_table_schema = 'myschema' AND f_table_name = 'mytable' AND f_geometry_column = 'myfield' +is($alter_field, qq[DELETE FROM geometry_columns WHERE f_table_schema = 'myschema' AND f_table_name = 'mytable' AND f_geometry_column = 'myfield'; ALTER TABLE mytable DROP CONSTRAINT enforce_dims_myfield ALTER TABLE mytable DROP CONSTRAINT enforce_srid_myfield -ALTER TABLE mytable DROP CONSTRAINT enforce_geotype_myfield -ALTER TABLE mytable ALTER COLUMN myfield SET NOT NULL +ALTER TABLE mytable DROP CONSTRAINT enforce_geotype_myfield; +ALTER TABLE mytable ALTER COLUMN myfield SET NOT NULL; ALTER TABLE mytable ALTER COLUMN myfield TYPE character varying(25)], 'Alter field geometry to non geometry works'); my $alter_field2 = SQL::Translator::Producer::PostgreSQL::alter_field($field2, $field1); -is($alter_field2, qq[ALTER TABLE mytable ALTER COLUMN myfield DROP NOT NULL -ALTER TABLE mytable ALTER COLUMN myfield TYPE geometry -INSERT INTO geometry_columns VALUES ('','myschema','mytable','myfield','2','-1','POINT') +is($alter_field2, qq[ALTER TABLE mytable ALTER COLUMN myfield DROP NOT NULL; +ALTER TABLE mytable ALTER COLUMN myfield TYPE geometry; +INSERT INTO geometry_columns VALUES ('','myschema','mytable','myfield','2','-1','POINT'); ALTER TABLE mytable ADD CONSTRAINT enforce_dims_myfield CHECK ((ST_NDims(myfield) = 2)) ALTER TABLE mytable ADD CONSTRAINT enforce_srid_myfield CHECK ((ST_SRID(myfield) = -1)) ALTER TABLE mytable ADD CONSTRAINT enforce_geotype_myfield CHECK ((GeometryType(myfield) = 'POINT'::text OR myfield IS NULL))],