From: Dagfinn Ilmari Mannsåker Date: Wed, 9 Sep 2015 14:08:09 +0000 (+0100) Subject: Fix identifier quoting in PostGIS statements X-Git-Tag: v0.11022~11 X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=commitdiff_plain;h=3963e31df68c213477886490e5d7053b398ed02d;p=dbsrgits%2FSQL-Translator.git Fix identifier quoting in PostGIS statements --- diff --git a/Changes b/Changes index 95b422f..8681c21 100644 --- a/Changes +++ b/Changes @@ -17,7 +17,7 @@ Changes for SQL::Translator * Fix multi-line comments in YAML, JSON and PostgreSQL producers * Fix identifier quoting in PostgreSQL diff producer * Fix missing semicolons between PostGIS statements - * Fix string quoting in PostGIS statements + * Fix string and identifier quoting in PostGIS statements 0.11021 2015-01-29 diff --git a/lib/SQL/Translator/Producer/PostgreSQL.pm b/lib/SQL/Translator/Producer/PostgreSQL.pm index 89b9c1b..66461f0 100644 --- a/lib/SQL/Translator/Producer/PostgreSQL.pm +++ b/lib/SQL/Translator/Producer/PostgreSQL.pm @@ -334,8 +334,8 @@ sub create_table # Geometry # if (my @geometry_columns = grep { is_geometry($_) } $table->get_fields) { - $create_statement .= join(";\n", '', map{ drop_geometry_column($_) } @geometry_columns) if $options->{add_drop_table}; - $create_statement .= join(";\n", '', map{ add_geometry_column($_) } @geometry_columns); + $create_statement .= join(";\n", '', map{ drop_geometry_column($_, $options) } @geometry_columns) if $options->{add_drop_table}; + $create_statement .= join(";\n", '', map{ add_geometry_column($_, $options) } @geometry_columns); } return $create_statement, \@fks; @@ -450,7 +450,7 @@ sub create_view { # Geometry constraints # if (is_geometry($field)) { - foreach ( create_geometry_constraints($field) ) { + foreach ( create_geometry_constraints($field, $options) ) { my ($cdefs, $fks) = create_constraint($_, { generator => $generator, }); @@ -464,25 +464,26 @@ sub create_view { } sub create_geometry_constraints { - my $field = shift; + my ($field, $options) = @_; + my $fname = _generator($options)->quote($field); my @constraints; push @constraints, SQL::Translator::Schema::Constraint->new( name => "enforce_dims_".$field->name, - expression => "(ST_NDims($field) = ".$field->extra->{dimensions}.")", + expression => "(ST_NDims($fname) = ".$field->extra->{dimensions}.")", table => $field->table, type => CHECK_C, ); push @constraints, SQL::Translator::Schema::Constraint->new( name => "enforce_srid_".$field->name, - expression => "(ST_SRID($field) = ".$field->extra->{srid}.")", + expression => "(ST_SRID($fname) = ".$field->extra->{srid}.")", table => $field->table, type => CHECK_C, ); push @constraints, SQL::Translator::Schema::Constraint->new( name => "enforce_geotype_".$field->name, - expression => "(GeometryType($field) = '".$field->extra->{geometry_type}."'::text OR $field IS NULL)", + expression => "(GeometryType($fname) = ". __PACKAGE__->_quote_string($field->extra->{geometry_type}) ."::text OR $fname IS NULL)", table => $field->table, type => CHECK_C, ); @@ -732,8 +733,8 @@ sub alter_field # drop geometry column and constraints push @out, - drop_geometry_column($from_field), - drop_geometry_constraints($from_field), + drop_geometry_column($from_field, $options), + drop_geometry_constraints($from_field, $options), if is_geometry($from_field); # it's necessary to start with rename column cause this would affect @@ -813,8 +814,8 @@ sub alter_field # add geometry column and constraints push @out, - add_geometry_column($to_field), - add_geometry_constraints($to_field) + add_geometry_column($to_field, $options), + add_geometry_constraints($to_field, $options), if is_geometry($to_field); return wantarray ? @out : join(";\n", @out); @@ -829,8 +830,8 @@ sub add_field my $out = sprintf('ALTER TABLE %s ADD COLUMN %s', _generator($options)->quote($new_field->table->name), create_field($new_field, $options)); - $out .= ";\n".add_geometry_column($new_field) - . ";\n".add_geometry_constraints($new_field) + $out .= ";\n".add_geometry_column($new_field, $options) + . ";\n".add_geometry_constraints($new_field, $options) if is_geometry($new_field); return $out; @@ -845,7 +846,7 @@ sub drop_field my $out = sprintf('ALTER TABLE %s DROP COLUMN %s', $generator->quote($old_field->table->name), $generator->quote($old_field->name)); - $out .= ";\n".drop_geometry_column($old_field) + $out .= ";\n".drop_geometry_column($old_field, $options) if is_geometry($old_field); return $out; } @@ -883,15 +884,15 @@ sub drop_geometry_column { sub add_geometry_constraints { my ($field, $options) = @_; - return join(";\n", map { alter_create_constraint($_) } - create_geometry_constraints($field)); + return join(";\n", map { alter_create_constraint($_, $options) } + create_geometry_constraints($field, $options)); } sub drop_geometry_constraints { my ($field, $options) = @_; - return join(";\n", map { alter_drop_constraint($_) } - create_geometry_constraints($field)); + return join(";\n", map { alter_drop_constraint($_, $options) } + create_geometry_constraints($field, $options)); } @@ -911,8 +912,8 @@ sub rename_table { $options->{alter_table_action} = "RENAME TO " . $generator->quote($new_table); my @geometry_changes = map { - drop_geometry_column($_), - add_geometry_column($_, { table => $new_table }), + drop_geometry_column($_, $options), + add_geometry_column($_, { %{$options}, table => $new_table }), } grep { is_geometry($_) } $old_table->get_fields; $options->{geometry_changes} = join (";\n",@geometry_changes) if @geometry_changes; diff --git a/t/63-spacial-pgsql.t b/t/63-spacial-pgsql.t index b6ee7c4..cf7c24b 100644 --- a/t/63-spacial-pgsql.t +++ b/t/63-spacial-pgsql.t @@ -22,11 +22,11 @@ BEGIN { use Test::Differences; use SQL::Translator; -my $PRODUCER = \&SQL::Translator::Producer::PostgreSQL::create_field; +my $options = { quote_identifiers => 1 }; my $schema = SQL::Translator::Schema->new( name => 'myschema' ); -my $table = SQL::Translator::Schema::Table->new( name => 'mytable', schema => $schema ); +my $table = SQL::Translator::Schema::Table->new( name => 'my\'table', schema => $schema ); my $field1 = SQL::Translator::Schema::Field->new( name => 'myfield', table => $table, @@ -42,19 +42,19 @@ my $field1 = SQL::Translator::Schema::Field->new( name => 'myfield', is_foreign_key => 0, is_unique => 0 ); -my $field1_sql = SQL::Translator::Producer::PostgreSQL::create_field($field1); +my $field1_sql = SQL::Translator::Producer::PostgreSQL::create_field($field1, $options); -is($field1_sql, 'myfield geometry', 'Create geometry field works'); +is($field1_sql, '"myfield" geometry', 'Create geometry field works'); -my $field1_geocol = SQL::Translator::Producer::PostgreSQL::add_geometry_column($field1); +my $field1_geocol = SQL::Translator::Producer::PostgreSQL::add_geometry_column($field1, $options); -is($field1_geocol, "INSERT INTO geometry_columns VALUES ('','myschema','mytable','myfield','2','-1','POINT')", 'Add geometry column works'); +is($field1_geocol, "INSERT INTO geometry_columns VALUES ('','myschema','my''table','myfield','2','-1','POINT')", 'Add geometry column works'); -my $field1_geocon = SQL::Translator::Producer::PostgreSQL::add_geometry_constraints($field1); +my $field1_geocon = SQL::Translator::Producer::PostgreSQL::add_geometry_constraints($field1, $options); -is($field1_geocon, qq[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))], +is($field1_geocon, qq[ALTER TABLE "my'table" ADD CONSTRAINT "enforce_dims_myfield" CHECK ((ST_NDims("myfield") = 2)); +ALTER TABLE "my'table" ADD CONSTRAINT "enforce_srid_myfield" CHECK ((ST_SRID("myfield") = -1)); +ALTER TABLE "my'table" ADD CONSTRAINT "enforce_geotype_myfield" CHECK ((GeometryType("myfield") = 'POINT'::text OR "myfield" IS NULL))], 'Add geometry constraints works'); my $field2 = SQL::Translator::Schema::Field->new( name => 'myfield', @@ -68,38 +68,39 @@ my $field2 = SQL::Translator::Schema::Field->new( name => 'myfield', is_unique => 0 ); 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'; -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 ALTER COLUMN myfield TYPE character varying(25)], + $field2, $options); +is($alter_field, qq[DELETE FROM geometry_columns WHERE f_table_schema = 'myschema' AND f_table_name = 'my''table' AND f_geometry_column = 'myfield'; +ALTER TABLE "my'table" DROP CONSTRAINT "enforce_dims_myfield"; +ALTER TABLE "my'table" DROP CONSTRAINT "enforce_srid_myfield"; +ALTER TABLE "my'table" DROP CONSTRAINT "enforce_geotype_myfield"; +ALTER TABLE "my'table" ALTER COLUMN "myfield" SET NOT NULL; +ALTER TABLE "my'table" 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'); -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))], + $field1, $options); +is($alter_field2, qq[ALTER TABLE "my'table" ALTER COLUMN "myfield" DROP NOT NULL; +ALTER TABLE "my'table" ALTER COLUMN "myfield" TYPE geometry; +INSERT INTO geometry_columns VALUES ('','myschema','my''table','myfield','2','-1','POINT'); +ALTER TABLE "my'table" ADD CONSTRAINT "enforce_dims_myfield" CHECK ((ST_NDims("myfield") = 2)); +ALTER TABLE "my'table" ADD CONSTRAINT "enforce_srid_myfield" CHECK ((ST_SRID("myfield") = -1)); +ALTER TABLE "my'table" ADD CONSTRAINT "enforce_geotype_myfield" CHECK ((GeometryType("myfield") = 'POINT'::text OR "myfield" IS NULL))], 'Alter field non geometry to geometry works'); $field1->name('field3'); -my $add_field = SQL::Translator::Producer::PostgreSQL::add_field($field1); +my $add_field = SQL::Translator::Producer::PostgreSQL::add_field($field1, $options); -is($add_field, qq[ALTER TABLE mytable ADD COLUMN field3 geometry; -INSERT INTO geometry_columns VALUES ('','myschema','mytable','field3','2','-1','POINT'); -ALTER TABLE mytable ADD CONSTRAINT enforce_dims_field3 CHECK ((ST_NDims(field3) = 2)); -ALTER TABLE mytable ADD CONSTRAINT enforce_srid_field3 CHECK ((ST_SRID(field3) = -1)); -ALTER TABLE mytable ADD CONSTRAINT enforce_geotype_field3 CHECK ((GeometryType(field3) = 'POINT'::text OR field3 IS NULL))], +is($add_field, qq[ALTER TABLE "my'table" ADD COLUMN "field3" geometry; +INSERT INTO geometry_columns VALUES ('','myschema','my''table','field3','2','-1','POINT'); +ALTER TABLE "my'table" ADD CONSTRAINT "enforce_dims_field3" CHECK ((ST_NDims("field3") = 2)); +ALTER TABLE "my'table" ADD CONSTRAINT "enforce_srid_field3" CHECK ((ST_SRID("field3") = -1)); +ALTER TABLE "my'table" ADD CONSTRAINT "enforce_geotype_field3" CHECK ((GeometryType("field3") = 'POINT'::text OR "field3" IS NULL))], 'Add geometry field works'); -my $drop_field = SQL::Translator::Producer::PostgreSQL::drop_field($field1); -is($drop_field, qq[ALTER TABLE mytable DROP COLUMN field3; -DELETE FROM geometry_columns WHERE f_table_schema = 'myschema' AND f_table_name = 'mytable' AND f_geometry_column = 'field3'], 'Drop geometry field works'); +my $drop_field = SQL::Translator::Producer::PostgreSQL::drop_field($field1, $options); +is($drop_field, qq[ALTER TABLE "my'table" DROP COLUMN "field3"; +DELETE FROM geometry_columns WHERE f_table_schema = 'myschema' AND f_table_name = 'my''table' AND f_geometry_column = 'field3'], + 'Drop geometry field works'); $table->add_field($field1); @@ -117,26 +118,29 @@ my $field4 = SQL::Translator::Schema::Field->new( name => 'field4', is_unique => 0 ); $table->add_field($field4); -my ($create_table,$fks) = SQL::Translator::Producer::PostgreSQL::create_table($table); +my ($create_table,$fks) = SQL::Translator::Producer::PostgreSQL::create_table($table, $options); is($create_table,qq[-- --- Table: mytable +-- Table: my'table -- -CREATE TABLE mytable ( - field3 geometry, - field4 geography(POINT,-1), - CONSTRAINT enforce_dims_field3 CHECK ((ST_NDims(field3) = 2)), - CONSTRAINT enforce_srid_field3 CHECK ((ST_SRID(field3) = -1)), - CONSTRAINT enforce_geotype_field3 CHECK ((GeometryType(field3) = 'POINT'::text OR field3 IS NULL)) +CREATE TABLE "my'table" ( + "field3" geometry, + "field4" geography(POINT,-1), + CONSTRAINT "enforce_dims_field3" CHECK ((ST_NDims("field3") = 2)), + CONSTRAINT "enforce_srid_field3" CHECK ((ST_SRID("field3") = -1)), + CONSTRAINT "enforce_geotype_field3" CHECK ((GeometryType("field3") = 'POINT'::text OR "field3" IS NULL)) ); -INSERT INTO geometry_columns VALUES ('','myschema','mytable','field3','2','-1','POINT')],'Create table with geometry works.'); +INSERT INTO geometry_columns VALUES ('','myschema','my''table','field3','2','-1','POINT')], + 'Create table with geometry works.'); -my $rename_table = SQL::Translator::Producer::PostgreSQL::rename_table($table, "table2"); -is($rename_table,qq[ALTER TABLE mytable RENAME TO table2; -DELETE FROM geometry_columns WHERE f_table_schema = 'myschema' AND f_table_name = 'mytable' AND f_geometry_column = 'field3'; -INSERT INTO geometry_columns VALUES ('','myschema','table2','field3','2','-1','POINT')],'Rename table with geometry works.'); +my $rename_table = SQL::Translator::Producer::PostgreSQL::rename_table($table, "table2", $options); +is($rename_table,qq[ALTER TABLE "my'table" RENAME TO "table2"; +DELETE FROM geometry_columns WHERE f_table_schema = 'myschema' AND f_table_name = 'my''table' AND f_geometry_column = 'field3'; +INSERT INTO geometry_columns VALUES ('','myschema','table2','field3','2','-1','POINT')], + 'Rename table with geometry works.'); $table->name("table2"); -my $drop_table = SQL::Translator::Producer::PostgreSQL::drop_table($table); -is($drop_table, qq[DROP TABLE table2 CASCADE; -DELETE FROM geometry_columns WHERE f_table_schema = 'myschema' AND f_table_name = 'table2' AND f_geometry_column = 'field3'], 'Drop table with geometry works.'); +my $drop_table = SQL::Translator::Producer::PostgreSQL::drop_table($table, $options); +is($drop_table, qq[DROP TABLE "table2" CASCADE; +DELETE FROM geometry_columns WHERE f_table_schema = 'myschema' AND f_table_name = 'table2' AND f_geometry_column = 'field3'], + 'Drop table with geometry works.');