From: Peter Rabbitson Date: Wed, 10 Nov 2010 22:57:13 +0000 (+0000) Subject: Add support for PostGIS Geometry and Geography data types X-Git-Tag: v0.11008~36 X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=commitdiff_plain;h=e83ad71c8681208b81dacee01240c2b78752b83e;hp=d53db6a7d551dfa839381cf6f3b21ebd7bd1fed7;p=dbsrgits%2FSQL-Translator.git Add support for PostGIS Geometry and Geography data types --- diff --git a/AUTHORS b/AUTHORS index 7c1186d..242b3ab 100644 --- a/AUTHORS +++ b/AUTHORS @@ -19,6 +19,7 @@ The following people have contributed to the SQLFairy project: - Jonathan Yu - John Goulah - Ken Youens-Clark +- Kevin McClellan - Mark Addison - Mikey Melillo - Moritz Onken diff --git a/Changes b/Changes index c9feef8..d908652 100644 --- a/Changes +++ b/Changes @@ -1,4 +1,6 @@ + * Add explicit Scalar::Util to the deplist for really old perls +* Add support for PostGIS Geometry and Geography data types in the Pg producer # ---------------------------------------------------------- # 0.11006 2010-06-03 diff --git a/lib/SQL/Translator/Producer/PostgreSQL.pm b/lib/SQL/Translator/Producer/PostgreSQL.pm index a881689..f8f5438 100644 --- a/lib/SQL/Translator/Producer/PostgreSQL.pm +++ b/lib/SQL/Translator/Producer/PostgreSQL.pm @@ -32,6 +32,9 @@ SQL::Translator::Producer::PostgreSQL - PostgreSQL producer for SQL::Translator Creates a DDL suitable for PostgreSQL. Very heavily based on the Oracle producer. +Now handles PostGIS Geometry and Geography data types on table definitions. +Does not yet support PostGIS Views. + =cut use strict; @@ -317,6 +320,12 @@ sub next_unused_name { return $name; } +sub is_geometry +{ + my $field = shift; + return 1 if $field->data_type eq 'geometry' || $field->data_type eq 'geography'; +} + sub create_table { my ($table, $options) = @_; @@ -419,6 +428,15 @@ sub create_table $create_statement .= ( $create_statement =~ /;$/ ? "\n" : q{} ) . join(";\n", @index_defs); + # + # Geometry + # + if(grep { is_geometry($_) } $table->get_fields){ + $create_statement .= ";"; + $create_statement .= "\n".join("\n", map { drop_geometry_column($_) if is_geometry($_); } $table->get_fields) if $options->{add_drop_table}; + $create_statement .= "\n".join("\n", map { add_geometry_column($_) if is_geometry($_);} $table->get_fields); + } + return $create_statement, \@fks; } @@ -520,10 +538,53 @@ sub create_view { # $field_def .= ' NOT NULL' unless $field->is_nullable; + # + # Geometry constraints + # + if(is_geometry($field)){ + foreach ( create_geometry_constraints($field) ) { + my ($cdefs, $fks) = create_constraint($_, + { + quote_field_names => $qf, + quote_table_names => $qt, + table_name => $table_name, + }); + push @$constraint_defs, @$cdefs; + push @$fks, @$fks; + } + } + return $field_def; } } +sub create_geometry_constraints{ + my $field = shift; + + my @constraints; + push @constraints, SQL::Translator::Schema::Constraint->new( + name => "enforce_dims_".$field->name, + expression => "(st_ndims($field) = ".$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}.")", + 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)", + table => $field->table, + type => CHECK_C, + ); + + return @constraints; +} + sub create_index { my ($index, $options) = @_; @@ -727,6 +788,11 @@ sub alter_field if($from_field->table->name ne $to_field->table->name); 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, sprintf('ALTER TABLE %s ALTER COLUMN %s SET NOT NULL', $to_field->table->name, $to_field->name) if(!$to_field->is_nullable and @@ -778,7 +844,10 @@ sub alter_field $to_field->name) if ( !defined $new_default && defined $old_default ); - + # add geometry column and contraints + 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); } @@ -791,6 +860,8 @@ sub add_field my $out = sprintf('ALTER TABLE %s ADD COLUMN %s', $new_field->table->name, create_field($new_field)); + $out .= "\n".add_geometry_column($new_field) if is_geometry($new_field); + $out .= "\n".add_geometry_constraints($new_field) if is_geometry($new_field); return $out; } @@ -802,16 +873,62 @@ sub drop_field 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); return $out; } +sub add_geometry_column{ + my ($field,$options) = @_; + + my $out = sprintf("INSERT INTO geometry_columns VALUES ('%s','%s','%s','%s','%s','%s','%s')", + '', + $field->table->schema->name, + $options->{table} ? $options->{table} : $field->table->name, + $field->name, + $field->{extra}{dimensions}, + $field->{extra}{srid}, + $field->{extra}{geometry_type}); + return $out; +} + +sub drop_geometry_column +{ + my $field = shift; + + my $out = sprintf("DELETE FROM geometry_columns WHERE f_table_schema = '%s' AND f_table_name = '%s' AND f_geometry_column = '%s'", + $field->table->schema->name, + $field->table->name, + $field->name); + return $out; +} + +sub add_geometry_constraints{ + my $field = shift; + + my @constraints = create_geometry_constraints($field); + + my $out = join("\n", map { alter_create_constraint($_); } @constraints); + + return $out; +} + +sub drop_geometry_constraints{ + my $field = shift; + + my @constraints = create_geometry_constraints($field); + + my $out = join("\n", map { alter_drop_constraint($_); } @constraints); + + return $out; +} + sub alter_table { my ($to_table, $options) = @_; my $qt = $options->{quote_table_names} || ''; my $out = sprintf('ALTER TABLE %s %s', $qt . $to_table->name . $qt, $options->{alter_table_action}); + $out .= "\n".$options->{geometry_changes} if $options->{geometry_changes}; return $out; } @@ -819,6 +936,13 @@ sub rename_table { my ($old_table, $new_table, $options) = @_; my $qt = $options->{quote_table_names} || ''; $options->{alter_table_action} = "RENAME TO $qt$new_table$qt"; + + my @geometry_changes; + push @geometry_changes, map { drop_geometry_column($_); } grep { is_geometry($_) } $old_table->get_fields; + push @geometry_changes, map { add_geometry_column($_, { table => $new_table }); } grep { is_geometry($_) } $old_table->get_fields; + + $options->{geometry_changes} = join ("\n",@geometry_changes) if scalar(@geometry_changes); + return alter_table($old_table, $options); } @@ -873,7 +997,12 @@ sub alter_create_constraint { sub drop_table { my ($table, $options) = @_; my $qt = $options->{quote_table_names} || ''; - return "DROP TABLE $qt$table$qt CASCADE"; + my $out = "DROP TABLE $qt$table$qt CASCADE"; + + my @geometry_drops = map { drop_geometry_column($_); } grep { is_geometry($_) } $table->get_fields; + + $out .= "\n".join("\n",@geometry_drops) if scalar(@geometry_drops); + return $out; } 1; diff --git a/t/08postgres-to-mysql.t b/t/08postgres-to-mysql.t index 775bae8..8146c24 100644 --- a/t/08postgres-to-mysql.t +++ b/t/08postgres-to-mysql.t @@ -146,6 +146,23 @@ create table cvterm_dbxref ( create index cvterm_dbxref_idx1 on cvterm_dbxref (cvterm_id); create index cvterm_dbxref_idx2 on cvterm_dbxref (dbxref_id); +-- ================================================ +-- TABLE: cvterm_geom +-- ================================================ + +create table cvterm_geom ( + cvterm_geom_id serial not null, + primary key (cvterm_geom_id), + cvterm_id int not null, + foreign key (cvterm_id) references cvterm (cvterm_id), + cvterm_geom geometry, + constraint "enforce_dims_cvterm_geom" CHECK ((st_ndims(cvterm_geom) = 2)), + constraint "enforce_srid_cvterm_geom" CHECK ((st_srid(cvterm_geom) = -1)), + constraint "enforce_geotype_cvterm_geom" CHECK ((geometrytype(cvterm_geom) = 'POINT'::text OR cvterm_geom IS NULL)), + unique(cvterm_id) +); + + |; my $tr = SQL::Translator->new( diff --git a/t/63-spacial-pgsql.t b/t/63-spacial-pgsql.t new file mode 100644 index 0000000..3ff3de3 --- /dev/null +++ b/t/63-spacial-pgsql.t @@ -0,0 +1,125 @@ +#!/usr/bin/perl + +use strict; +use warnings; + +use Test::More; +use Test::Exception; +use Test::SQL::Translator qw(maybe_plan); + +use Data::Dumper; +use FindBin qw/$Bin/; + +# Testing 1,2,3,4... +#============================================================================= + +BEGIN { + maybe_plan(10, + 'SQL::Translator::Producer::PostgreSQL', + 'Test::Differences', + ) +} +use Test::Differences; +use SQL::Translator; + +my $PRODUCER = \&SQL::Translator::Producer::PostgreSQL::create_field; + +my $schema = SQL::Translator::Schema->new( name => 'myschema' ); + +my $table = SQL::Translator::Schema::Table->new( name => 'mytable', schema => $schema ); + +my $field1 = SQL::Translator::Schema::Field->new( name => 'myfield', + table => $table, + data_type => 'geometry', + extra => { + dimensions => 2, + geometry_type => 'POINT', + srid => -1 + }, + default_value => undef, + is_auto_increment => 0, + is_nullable => 1, + is_foreign_key => 0, + is_unique => 0 ); + +my $field1_sql = SQL::Translator::Producer::PostgreSQL::create_field($field1); + +is($field1_sql, 'myfield geometry', 'Create geometry field works'); + +my $field1_geocol = SQL::Translator::Producer::PostgreSQL::add_geometry_column($field1); + +is($field1_geocol, "INSERT INTO geometry_columns VALUES ('','myschema','mytable','myfield','2','-1','POINT')", 'Add geometry column works'); + +my $field1_geocon = SQL::Translator::Producer::PostgreSQL::add_geometry_constraints($field1); + +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))], + 'Add geometry constraints works'); + +my $field2 = SQL::Translator::Schema::Field->new( name => 'myfield', + table => $table, + data_type => 'VARCHAR', + size => 25, + default_value => undef, + is_auto_increment => 0, + is_nullable => 0, + is_foreign_key => 0, + 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)], + '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))], + 'Alter field non geometry to geometry works'); + +$field1->name('field3'); +my $add_field = SQL::Translator::Producer::PostgreSQL::add_field($field1); + +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))], + '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'); + +$table->add_field($field1); +my ($create_table,$fks) = SQL::Translator::Producer::PostgreSQL::create_table($table); +is($create_table,qq[-- +-- Table: mytable +-- +CREATE TABLE mytable ( + field3 geometry, + 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.'); + +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.'); + +$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.');