Further clean up PostGIS code
[dbsrgits/SQL-Translator.git] / lib / SQL / Translator / Producer / PostgreSQL.pm
CommitLineData
f8f0253c 1package SQL::Translator::Producer::PostgreSQL;
2
96844cae 3=head1 NAME
4
5SQL::Translator::Producer::PostgreSQL - PostgreSQL producer for SQL::Translator
6
20770e44 7=head1 SYNOPSIS
8
9 my $t = SQL::Translator->new( parser => '...', producer => 'PostgreSQL' );
10 $t->translate;
11
12=head1 DESCRIPTION
13
14Creates a DDL suitable for PostgreSQL. Very heavily based on the Oracle
15producer.
16
e83ad71c 17Now handles PostGIS Geometry and Geography data types on table definitions.
18Does not yet support PostGIS Views.
ea93df61 19
96844cae 20=cut
21
f8f0253c 22use strict;
bfb5a568 23use warnings;
0c04c5a2 24our ( $DEBUG, $WARN );
25our $VERSION = '1.59';
a25ac5d2 26$DEBUG = 0 unless defined $DEBUG;
f8f0253c 27
8d11f4cb 28use base qw(SQL::Translator::Producer);
0c43e0a1 29use SQL::Translator::Schema::Constants;
f82112a3 30use SQL::Translator::Utils qw(debug header_comment parse_dbms_version batch_alter_table_statements normalize_quote_options);
2230ed2a 31use SQL::Translator::Generator::DDL::PostgreSQL;
f8f0253c 32use Data::Dumper;
33
9c9c169c 34use constant MAX_ID_LENGTH => 62;
35
f82112a3 36{
37 my ($quoting_generator, $nonquoting_generator);
38 sub _generator {
39 my $options = shift;
40 return $options->{generator} if exists $options->{generator};
41
42 return normalize_quote_options($options)
43 ? $quoting_generator ||= SQL::Translator::Generator::DDL::PostgreSQL->new
44 : $nonquoting_generator ||= SQL::Translator::Generator::DDL::PostgreSQL->new(
45 quote_chars => [],
46 );
47 }
48}
2230ed2a 49
b14cf6f4 50my ( %translate );
bfb5a568 51
52BEGIN {
53
54 %translate = (
d529894e 55 #
56 # MySQL types
57 #
90089d63 58 double => 'double precision',
4328d7bd 59 decimal => 'numeric',
d529894e 60 int => 'integer',
61 mediumint => 'integer',
d529894e 62 tinyint => 'smallint',
c8c17a58 63 char => 'character',
da8e499e 64 varchar => 'character varying',
d529894e 65 longtext => 'text',
66 mediumtext => 'text',
d529894e 67 tinytext => 'text',
68 tinyblob => 'bytea',
69 blob => 'bytea',
70 mediumblob => 'bytea',
71 longblob => 'bytea',
da8e499e 72 enum => 'character varying',
73 set => 'character varying',
d529894e 74 datetime => 'timestamp',
d529894e 75 year => 'date',
76
77 #
78 # Oracle types
79 #
96844cae 80 number => 'integer',
da8e499e 81 varchar2 => 'character varying',
96844cae 82 long => 'text',
ada2826e 83 clob => 'text',
96844cae 84
85 #
86 # Sybase types
87 #
96844cae 88 comment => 'text',
ebad0597 89
90 #
91 # MS Access types
92 #
93 memo => 'text',
d529894e 94);
bfb5a568 95}
96844cae 96my %truncated;
97
98=pod
99
100=head1 PostgreSQL Create Table Syntax
101
102 CREATE [ [ LOCAL ] { TEMPORARY | TEMP } ] TABLE table_name (
103 { column_name data_type [ DEFAULT default_expr ] [ column_constraint [, ... ] ]
104 | table_constraint } [, ... ]
105 )
106 [ INHERITS ( parent_table [, ... ] ) ]
107 [ WITH OIDS | WITHOUT OIDS ]
108
109where column_constraint is:
110
111 [ CONSTRAINT constraint_name ]
112 { NOT NULL | NULL | UNIQUE | PRIMARY KEY |
113 CHECK (expression) |
114 REFERENCES reftable [ ( refcolumn ) ] [ MATCH FULL | MATCH PARTIAL ]
115 [ ON DELETE action ] [ ON UPDATE action ] }
116 [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
117
118and table_constraint is:
119
120 [ CONSTRAINT constraint_name ]
121 { UNIQUE ( column_name [, ... ] ) |
122 PRIMARY KEY ( column_name [, ... ] ) |
123 CHECK ( expression ) |
124 FOREIGN KEY ( column_name [, ... ] ) REFERENCES reftable [ ( refcolumn [, ... ] ) ]
125 [ MATCH FULL | MATCH PARTIAL ] [ ON DELETE action ] [ ON UPDATE action ] }
126 [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
127
da8e499e 128=head1 Create Index Syntax
129
130 CREATE [ UNIQUE ] INDEX index_name ON table
131 [ USING acc_method ] ( column [ ops_name ] [, ...] )
132 [ WHERE predicate ]
133 CREATE [ UNIQUE ] INDEX index_name ON table
134 [ USING acc_method ] ( func_name( column [, ... ]) [ ops_name ] )
135 [ WHERE predicate ]
136
96844cae 137=cut
f8f0253c 138
139sub produce {
e189562c 140 my $translator = shift;
141 local $DEBUG = $translator->debug;
142 local $WARN = $translator->show_warnings;
143 my $no_comments = $translator->no_comments;
144 my $add_drop_table = $translator->add_drop_table;
145 my $schema = $translator->schema;
146 my $pargs = $translator->producer_args;
7b4b17aa 147 my $postgres_version = parse_dbms_version(
148 $pargs->{postgres_version}, 'perl'
149 );
96844cae 150
f82112a3 151 my $generator = _generator({ quote_identifiers => $translator->quote_identifiers });
ea93df61 152
bf75adec 153 my @output;
154 push @output, header_comment unless ($no_comments);
96844cae 155
08d91aad 156 my (@table_defs, @fks);
79f55d7e 157 my %type_defs;
0c43e0a1 158 for my $table ( $schema->get_tables ) {
08d91aad 159
ea93df61 160 my ($table_def, $fks) = create_table($table, {
f82112a3 161 generator => $generator,
e189562c 162 no_comments => $no_comments,
163 postgres_version => $postgres_version,
164 add_drop_table => $add_drop_table,
79f55d7e 165 type_defs => \%type_defs,
e189562c 166 });
167
08d91aad 168 push @table_defs, $table_def;
169 push @fks, @$fks;
da8e499e 170 }
171
296c2701 172 for my $view ( $schema->get_views ) {
f82112a3 173 push @table_defs, create_view($view, {
174 postgres_version => $postgres_version,
175 add_drop_view => $add_drop_table,
176 generator => $generator,
177 no_comments => $no_comments,
178 });
296c2701 179 }
180
c96cd4a8 181 for my $trigger ( $schema->get_triggers ) {
182 push @table_defs, create_trigger( $trigger, {
183 add_drop_trigger => $add_drop_table,
c9c8f3e1 184 generator => $generator,
c96cd4a8 185 no_comments => $no_comments,
186 });
187 }
188
79f55d7e 189 push @output, map { "$_;\n\n" } values %type_defs;
bf75adec 190 push @output, map { "$_;\n\n" } @table_defs;
08d91aad 191 if ( @fks ) {
bf75adec 192 push @output, "--\n-- Foreign Key Definitions\n--\n\n" unless $no_comments;
193 push @output, map { "$_;\n\n" } @fks;
08d91aad 194 }
021dbce8 195
da8e499e 196 if ( $WARN ) {
197 if ( %truncated ) {
198 warn "Truncated " . keys( %truncated ) . " names:\n";
199 warn "\t" . join( "\n\t", sort keys %truncated ) . "\n";
200 }
f8f0253c 201 }
202
bf75adec 203 return wantarray
204 ? @output
205 : join ('', @output);
f8f0253c 206}
207
b14cf6f4 208{
209 my %global_names;
210 sub mk_name {
211 my $basename = shift || '';
212 my $type = shift || '';
213 my $scope = shift || '';
214 my $critical = shift || '';
215 my $basename_orig = $basename;
216
217 my $max_name = $type
218 ? MAX_ID_LENGTH - (length($type) + 1)
219 : MAX_ID_LENGTH;
220 $basename = substr( $basename, 0, $max_name )
221 if length( $basename ) > $max_name;
222 my $name = $type ? "${type}_$basename" : $basename;
223
224 if ( $basename ne $basename_orig and $critical ) {
225 my $show_type = $type ? "+'$type'" : "";
226 warn "Truncating '$basename_orig'$show_type to ", MAX_ID_LENGTH,
227 " character limit to make '$name'\n" if $WARN;
228 $truncated{ $basename_orig } = $name;
229 }
96844cae 230
b14cf6f4 231 $scope ||= \%global_names;
232 if ( my $prev = $scope->{ $name } ) {
233 my $name_orig = $name;
234 $name .= sprintf( "%02d", ++$prev );
235 substr($name, MAX_ID_LENGTH - 3) = "00"
236 if length( $name ) > MAX_ID_LENGTH;
96844cae 237
b14cf6f4 238 warn "The name '$name_orig' has been changed to ",
239 "'$name' to make it unique.\n" if $WARN;
96844cae 240
b14cf6f4 241 $scope->{ $name_orig }++;
242 }
96844cae 243
b14cf6f4 244 $scope->{ $name }++;
245 return $name;
246 }
96844cae 247}
248
0b4b7709 249sub is_geometry {
250 my $field = shift;
251 return 1 if $field->data_type eq 'geometry';
140a1dad 252}
253
0b4b7709 254sub is_geography {
140a1dad 255 my $field = shift;
256 return 1 if $field->data_type eq 'geography';
e83ad71c 257}
258
ea93df61 259sub create_table
bfb5a568 260{
261 my ($table, $options) = @_;
262
f82112a3 263 my $generator = _generator($options);
bfb5a568 264 my $no_comments = $options->{no_comments} || 0;
265 my $add_drop_table = $options->{add_drop_table} || 0;
5342f5c1 266 my $postgres_version = $options->{postgres_version} || 0;
79f55d7e 267 my $type_defs = $options->{type_defs} || {};
bfb5a568 268
3406fd5b 269 my $table_name = $table->name or next;
f82112a3 270 my $table_name_qt = $generator->quote($table_name);
bfb5a568 271
d31a1336 272 my ( @comments, @field_defs, @index_defs, @constraint_defs, @fks );
bfb5a568 273
f82112a3 274 push @comments, "--\n-- Table: $table_name\n--\n" unless $no_comments;
bfb5a568 275
31bed2c0 276 if ( !$no_comments and my $comments = $table->comments ) {
277 $comments =~ s/^/-- /mg;
278 push @comments, "-- Comments:\n$comments\n--\n";
bfb5a568 279 }
280
281 #
282 # Fields
283 #
bfb5a568 284 for my $field ( $table->get_fields ) {
f82112a3 285 push @field_defs, create_field($field, {
286 generator => $generator,
287 postgres_version => $postgres_version,
288 type_defs => $type_defs,
289 constraint_defs => \@constraint_defs,
290 });
bfb5a568 291 }
292
293 #
294 # Index Declarations
295 #
bfb5a568 296 for my $index ( $table->get_indices ) {
f82112a3 297 my ($idef, $constraints) = create_index($index, {
298 generator => $generator,
299 });
7ed7402c 300 $idef and push @index_defs, $idef;
bfb5a568 301 push @constraint_defs, @$constraints;
302 }
303
304 #
305 # Table constraints
306 #
bfb5a568 307 for my $c ( $table->get_constraints ) {
f82112a3 308 my ($cdefs, $fks) = create_constraint($c, {
309 generator => $generator,
310 });
bfb5a568 311 push @constraint_defs, @$cdefs;
312 push @fks, @$fks;
313 }
314
3e98f7d9 315
da936d63 316 my $create_statement = join("\n", @comments);
5342f5c1 317 if ($add_drop_table) {
7b4b17aa 318 if ($postgres_version >= 8.002) {
f82112a3 319 $create_statement .= "DROP TABLE IF EXISTS $table_name_qt CASCADE;\n";
5342f5c1 320 } else {
f82112a3 321 $create_statement .= "DROP TABLE $table_name_qt CASCADE;\n";
5342f5c1 322 }
323 }
da936d63 324 my $temporary = $table->extra->{temporary} ? "TEMPORARY " : "";
f82112a3 325 $create_statement .= "CREATE ${temporary}TABLE $table_name_qt (\n" .
bfb5a568 326 join( ",\n", map { " $_" } @field_defs, @constraint_defs ).
3406fd5b 327 "\n)"
bfb5a568 328 ;
3406fd5b 329 $create_statement .= @index_defs ? ';' : q{};
330 $create_statement .= ( $create_statement =~ /;$/ ? "\n" : q{} )
331 . join(";\n", @index_defs);
bfb5a568 332
0b4b7709 333 #
334 # Geometry
335 #
54b8ff8c 336 if (my @geometry_columns = grep { is_geometry($_) } $table->get_fields) {
e83ad71c 337 $create_statement .= ";";
54b8ff8c 338 $create_statement .= join("\n", '', map{ drop_geometry_column($_) } @geometry_columns) if $options->{add_drop_table};
339 $create_statement .= join("\n", '', map{ add_geometry_column($_) } @geometry_columns);
0b4b7709 340 }
e83ad71c 341
08d91aad 342 return $create_statement, \@fks;
bfb5a568 343}
344
296c2701 345sub create_view {
346 my ($view, $options) = @_;
f82112a3 347 my $generator = _generator($options);
0e758018 348 my $postgres_version = $options->{postgres_version} || 0;
a25ac5d2 349 my $add_drop_view = $options->{add_drop_view};
296c2701 350
351 my $view_name = $view->name;
352 debug("PKG: Looking at view '${view_name}'\n");
353
354 my $create = '';
2230ed2a 355 $create .= "--\n-- View: " . $generator->quote($view_name) . "\n--\n"
296c2701 356 unless $options->{no_comments};
0e758018 357 if ($add_drop_view) {
358 if ($postgres_version >= 8.002) {
2230ed2a 359 $create .= "DROP VIEW IF EXISTS " . $generator->quote($view_name) . ";\n";
0e758018 360 } else {
2230ed2a 361 $create .= "DROP VIEW " . $generator->quote($view_name) . ";\n";
0e758018 362 }
363 }
296c2701 364 $create .= 'CREATE';
296c2701 365
366 my $extra = $view->extra;
367 $create .= " TEMPORARY" if exists($extra->{temporary}) && $extra->{temporary};
2230ed2a 368 $create .= " VIEW " . $generator->quote($view_name);
296c2701 369
370 if ( my @fields = $view->fields ) {
2230ed2a 371 my $field_list = join ', ', map { $generator->quote($_) } @fields;
296c2701 372 $create .= " ( ${field_list} )";
373 }
374
375 if ( my $sql = $view->sql ) {
f59b2c0e 376 $create .= " AS\n ${sql}\n";
296c2701 377 }
378
379 if ( $extra->{check_option} ) {
380 $create .= ' WITH ' . uc $extra->{check_option} . ' CHECK OPTION';
381 }
382
296c2701 383 return $create;
384}
385
ea93df61 386{
bfb5a568 387
388 my %field_name_scope;
389
390 sub create_field
391 {
392 my ($field, $options) = @_;
393
f82112a3 394 my $generator = _generator($options);
bfb5a568 395 my $table_name = $field->table->name;
396 my $constraint_defs = $options->{constraint_defs} || [];
5342f5c1 397 my $postgres_version = $options->{postgres_version} || 0;
79f55d7e 398 my $type_defs = $options->{type_defs} || {};
bfb5a568 399
400 $field_name_scope{$table_name} ||= {};
912e67a1 401 my $field_name = $field->name;
31bed2c0 402 my $field_comments = '';
403 if (my $comments = $field->comments) {
404 $comments =~ s/(?<!\A)^/ -- /mg;
405 $field_comments = "-- $comments\n ";
406 }
bfb5a568 407
2230ed2a 408 my $field_def = $field_comments . $generator->quote($field_name);
bfb5a568 409
410 #
411 # Datatype
412 #
bfb5a568 413 my $data_type = lc $field->data_type;
414 my %extra = $field->extra;
415 my $list = $extra{'list'} || [];
1868ddbe 416 my $commalist = join( ', ', map { __PACKAGE__->_quote_string($_) } @$list );
bfb5a568 417
d31a1336 418 if ($postgres_version >= 8.003 && $data_type eq 'enum') {
79f55d7e 419 my $type_name = $extra{'custom_type_name'} || $field->table->name . '_' . $field->name . '_type';
5342f5c1 420 $field_def .= ' '. $type_name;
d25db732 421 my $new_type_def = "DROP TYPE IF EXISTS $type_name CASCADE;\n" .
79f55d7e 422 "CREATE TYPE $type_name AS ENUM ($commalist)";
423 if (! exists $type_defs->{$type_name} ) {
424 $type_defs->{$type_name} = $new_type_def;
425 } elsif ( $type_defs->{$type_name} ne $new_type_def ) {
426 die "Attempted to redefine type name '$type_name' as a different type.\n";
427 }
5342f5c1 428 } else {
429 $field_def .= ' '. convert_datatype($field);
430 }
bfb5a568 431
432 #
ea93df61 433 # Default value
bfb5a568 434 #
1868ddbe 435 __PACKAGE__->_apply_default_value(
06baeb21 436 $field,
437 \$field_def,
438 [
439 'NULL' => \'NULL',
440 'now()' => 'now()',
441 'CURRENT_TIMESTAMP' => 'CURRENT_TIMESTAMP',
442 ],
443 );
bfb5a568 444
445 #
446 # Not null constraint
447 #
448 $field_def .= ' NOT NULL' unless $field->is_nullable;
449
0b4b7709 450 #
451 # Geometry constraints
452 #
453 if (is_geometry($field)) {
454 foreach ( create_geometry_constraints($field) ) {
455 my ($cdefs, $fks) = create_constraint($_, {
456 generator => $generator,
457 });
458 push @$constraint_defs, @$cdefs;
459 push @$fks, @$fks;
460 }
e83ad71c 461 }
ea93df61 462
bfb5a568 463 return $field_def;
464 }
465}
466
0b4b7709 467sub create_geometry_constraints {
468 my $field = shift;
469
470 my @constraints;
471 push @constraints, SQL::Translator::Schema::Constraint->new(
472 name => "enforce_dims_".$field->name,
473 expression => "(ST_NDims($field) = ".$field->extra->{dimensions}.")",
474 table => $field->table,
475 type => CHECK_C,
476 );
477
478 push @constraints, SQL::Translator::Schema::Constraint->new(
479 name => "enforce_srid_".$field->name,
480 expression => "(ST_SRID($field) = ".$field->extra->{srid}.")",
481 table => $field->table,
482 type => CHECK_C,
483 );
484 push @constraints, SQL::Translator::Schema::Constraint->new(
485 name => "enforce_geotype_".$field->name,
486 expression => "(GeometryType($field) = '".$field->extra->{geometry_type}."'::text OR $field IS NULL)",
487 table => $field->table,
488 type => CHECK_C,
489 );
490
491 return @constraints;
e83ad71c 492}
493
892573f2 494{
b14cf6f4 495 my %index_name;
496 sub create_index
497 {
498 my ($index, $options) = @_;
bfb5a568 499
b14cf6f4 500 my $generator = _generator($options);
501 my $table_name = $index->table->name;
502
503 my ($index_def, @constraint_defs);
504
505 my $name
506 = $index->name
507 || join('_', $table_name, 'idx', ++$index_name{ $table_name });
508
509 my $type = $index->type || NORMAL;
510 my @fields = $index->fields;
511 return unless @fields;
512
513 my $index_using;
514 my $index_where;
515 for my $opt ( $index->options ) {
516 if ( ref $opt eq 'HASH' ) {
517 foreach my $key (keys %$opt) {
518 my $value = $opt->{$key};
519 next unless defined $value;
520 if ( uc($key) eq 'USING' ) {
521 $index_using = "USING $value";
522 }
523 elsif ( uc($key) eq 'WHERE' ) {
524 $index_where = "WHERE $value";
525 }
526 }
527 }
5b36314d 528 }
5b36314d 529
b14cf6f4 530 my $def_start = 'CONSTRAINT ' . $generator->quote($name) . ' ';
531 my $field_names = '(' . join(", ", (map { $_ =~ /\(.*\)/ ? $_ : ( $generator->quote($_) ) } @fields)) . ')';
532 if ( $type eq PRIMARY_KEY ) {
533 push @constraint_defs, "${def_start}PRIMARY KEY ".$field_names;
534 }
535 elsif ( $type eq UNIQUE ) {
536 push @constraint_defs, "${def_start}UNIQUE " .$field_names;
537 }
538 elsif ( $type eq NORMAL ) {
539 $index_def =
540 'CREATE INDEX ' . $generator->quote($name) . ' on ' . $generator->quote($table_name) . ' ' .
541 join ' ', grep { defined } $index_using, $field_names, $index_where;
542 }
543 else {
544 warn "Unknown index type ($type) on table $table_name.\n"
545 if $WARN;
546 }
bfb5a568 547
b14cf6f4 548 return $index_def, \@constraint_defs;
549 }
892573f2 550}
bfb5a568 551
892573f2 552sub create_constraint
553{
554 my ($c, $options) = @_;
bfb5a568 555
f82112a3 556 my $generator = _generator($options);
892573f2 557 my $table_name = $c->table->name;
558 my (@constraint_defs, @fks);
bfb5a568 559
892573f2 560 my $name = $c->name || '';
bfb5a568 561
5f31ed66 562 my @fields = grep { defined } $c->fields;
892573f2 563
5f31ed66 564 my @rfields = grep { defined } $c->reference_fields;
892573f2 565
566 next if !@fields && $c->type ne CHECK_C;
2230ed2a 567 my $def_start = $name ? 'CONSTRAINT ' . $generator->quote($name) . ' ' : '';
568 my $field_names = '(' . join(", ", (map { $_ =~ /\(.*\)/ ? $_ : ( $generator->quote($_) ) } @fields)) . ')';
892573f2 569 if ( $c->type eq PRIMARY_KEY ) {
5f31ed66 570 push @constraint_defs, "${def_start}PRIMARY KEY ".$field_names;
892573f2 571 }
572 elsif ( $c->type eq UNIQUE ) {
5f31ed66 573 push @constraint_defs, "${def_start}UNIQUE " .$field_names;
892573f2 574 }
575 elsif ( $c->type eq CHECK_C ) {
576 my $expression = $c->expression;
577 push @constraint_defs, "${def_start}CHECK ($expression)";
578 }
579 elsif ( $c->type eq FOREIGN_KEY ) {
2230ed2a 580 my $def .= "ALTER TABLE " . $generator->quote($table_name) . " ADD ${def_start}FOREIGN KEY $field_names"
581 . "\n REFERENCES " . $generator->quote($c->reference_table);
bfb5a568 582
892573f2 583 if ( @rfields ) {
2230ed2a 584 $def .= ' (' . join( ', ', map { $generator->quote($_) } @rfields ) . ')';
892573f2 585 }
bfb5a568 586
892573f2 587 if ( $c->match_type ) {
ea93df61 588 $def .= ' MATCH ' .
892573f2 589 ( $c->match_type =~ /full/i ) ? 'FULL' : 'PARTIAL';
590 }
5342f5c1 591
892573f2 592 if ( $c->on_delete ) {
5863ad87 593 $def .= ' ON DELETE '. $c->on_delete;
892573f2 594 }
bfb5a568 595
892573f2 596 if ( $c->on_update ) {
5863ad87 597 $def .= ' ON UPDATE '. $c->on_update;
892573f2 598 }
124b192c 599
892573f2 600 if ( $c->deferrable ) {
601 $def .= ' DEFERRABLE';
124b192c 602 }
603
892573f2 604 push @fks, "$def";
124b192c 605 }
bfb5a568 606
892573f2 607 return \@constraint_defs, \@fks;
608}
609
c96cd4a8 610sub create_trigger {
611 my ($trigger,$options) = @_;
c9c8f3e1 612 my $generator = _generator($options);
c96cd4a8 613
614 my @statements;
615
c9c8f3e1 616 push @statements, sprintf( 'DROP TRIGGER IF EXISTS %s', $generator->quote($trigger->name) )
c96cd4a8 617 if $options->{add_drop_trigger};
618
619 my $scope = $trigger->scope || '';
620 $scope = " FOR EACH $scope" if $scope;
621
622 push @statements, sprintf(
623 'CREATE TRIGGER %s %s %s ON %s%s %s',
c9c8f3e1 624 $generator->quote($trigger->name),
c96cd4a8 625 $trigger->perform_action_when,
626 join( ' OR ', @{ $trigger->database_events } ),
c9c8f3e1 627 $generator->quote($trigger->on_table),
c96cd4a8 628 $scope,
629 $trigger->action,
630 );
631
632 return @statements;
633}
634
bfb5a568 635sub convert_datatype
636{
637 my ($field) = @_;
638
639 my @size = $field->size;
640 my $data_type = lc $field->data_type;
aacb3187 641 my $array = $data_type =~ s/\[\]$//;
bfb5a568 642
643 if ( $data_type eq 'enum' ) {
644# my $len = 0;
645# $len = ($len < length($_)) ? length($_) : $len for (@$list);
646# my $chk_name = mk_name( $table_name.'_'.$field_name, 'chk' );
ea93df61 647# push @$constraint_defs,
2230ed2a 648# 'CONSTRAINT "$chk_name" CHECK (' . $generator->quote(field_name) .
bfb5a568 649# qq[IN ($commalist))];
650 $data_type = 'character varying';
651 }
652 elsif ( $data_type eq 'set' ) {
653 $data_type = 'character varying';
654 }
655 elsif ( $field->is_auto_increment ) {
656 if ( defined $size[0] && $size[0] > 11 ) {
657 $data_type = 'bigserial';
658 }
659 else {
660 $data_type = 'serial';
661 }
662 undef @size;
663 }
664 else {
ada2826e 665 $data_type = defined $translate{ lc $data_type } ?
666 $translate{ lc $data_type } :
bfb5a568 667 $data_type;
668 }
669
ad258776 670 if ( $data_type =~ /^time/i || $data_type =~ /^interval/i ) {
bfb5a568 671 if ( defined $size[0] && $size[0] > 6 ) {
672 $size[0] = 6;
673 }
674 }
675
676 if ( $data_type eq 'integer' ) {
677 if ( defined $size[0] && $size[0] > 0) {
678 if ( $size[0] > 10 ) {
679 $data_type = 'bigint';
680 }
681 elsif ( $size[0] < 5 ) {
682 $data_type = 'smallint';
683 }
684 else {
685 $data_type = 'integer';
686 }
687 }
688 else {
689 $data_type = 'integer';
690 }
691 }
52bc2e13 692
693 my $type_with_size = join('|',
e189562c 694 'bit', 'varbit', 'character', 'bit varying', 'character varying',
90089d63 695 'time', 'timestamp', 'interval', 'numeric', 'float'
52bc2e13 696 );
697
698 if ( $data_type !~ /$type_with_size/ ) {
ea93df61 699 @size = ();
e56dabb7 700 }
bfb5a568 701
ad258776 702 if (defined $size[0] && $size[0] > 0 && $data_type =~ /^time/i ) {
703 $data_type =~ s/^(time.*?)( with.*)?$/$1($size[0])/;
704 $data_type .= $2 if(defined $2);
705 } elsif ( defined $size[0] && $size[0] > 0 ) {
e189562c 706 $data_type .= '(' . join( ',', @size ) . ')';
08d91aad 707 }
aacb3187 708 if($array)
709 {
710 $data_type .= '[]';
711 }
bfb5a568 712
140a1dad 713 #
714 # Geography
715 #
716 if($data_type eq 'geography'){
aa068030 717 $data_type .= '('.$field->extra->{geography_type}.','. $field->extra->{srid} .')'
140a1dad 718 }
719
bfb5a568 720 return $data_type;
721}
722
723
724sub alter_field
725{
f7410082 726 my ($from_field, $to_field, $options) = @_;
bfb5a568 727
ea93df61 728 die "Can't alter field in another table"
bfb5a568 729 if($from_field->table->name ne $to_field->table->name);
730
f7410082 731 my $generator = _generator($options);
bfb5a568 732 my @out;
ea93df61 733
e83ad71c 734 # drop geometry column and constraints
54b8ff8c 735 push @out,
736 drop_geometry_column($from_field),
737 drop_geometry_constraints($from_field),
738 if is_geometry($from_field);
c50d1a0a 739
740 # it's necessary to start with rename column cause this would affect
741 # all of the following statements which would be broken if do the
742 # rename later
743 # BUT: drop geometry is done before the rename, cause it work's on the
744 # $from_field directly
745 push @out, sprintf('ALTER TABLE %s RENAME COLUMN %s TO %s',
f7410082 746 map($generator->quote($_),
747 $to_field->table->name,
748 $from_field->name,
749 $to_field->name,
750 ),
751 )
752 if($from_field->name ne $to_field->name);
c50d1a0a 753
3406fd5b 754 push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s SET NOT NULL',
f7410082 755 map($generator->quote($_),
756 $to_field->table->name,
757 $to_field->name
758 ),
759 )
760 if(!$to_field->is_nullable and $from_field->is_nullable);
bfb5a568 761
90726ffd 762 push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s DROP NOT NULL',
f7410082 763 map($generator->quote($_),
764 $to_field->table->name,
765 $to_field->name
766 ),
767 )
768 if (!$from_field->is_nullable and $to_field->is_nullable);
90726ffd 769
770
bfb5a568 771 my $from_dt = convert_datatype($from_field);
772 my $to_dt = convert_datatype($to_field);
3406fd5b 773 push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s TYPE %s',
f7410082 774 map($generator->quote($_),
775 $to_field->table->name,
776 $to_field->name
777 ),
778 $to_dt,
779 )
780 if($to_dt ne $from_dt);
bfb5a568 781
3406fd5b 782 my $old_default = $from_field->default_value;
783 my $new_default = $to_field->default_value;
90726ffd 784 my $default_value = $to_field->default_value;
ea93df61 785
90726ffd 786 # fixes bug where output like this was created:
787 # ALTER TABLE users ALTER COLUMN column SET DEFAULT ThisIsUnescaped;
788 if(ref $default_value eq "SCALAR" ) {
789 $default_value = $$default_value;
790 } elsif( defined $default_value && $to_dt =~ /^(character|text)/xsmi ) {
1868ddbe 791 $default_value = __PACKAGE__->_quote_string($default_value);
90726ffd 792 }
ea93df61 793
3406fd5b 794 push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s SET DEFAULT %s',
f7410082 795 map($generator->quote($_),
796 $to_field->table->name,
797 $to_field->name,
798 ),
799 $default_value,
800 )
3406fd5b 801 if ( defined $new_default &&
802 (!defined $old_default || $old_default ne $new_default) );
bfb5a568 803
ea93df61 804 # fixes bug where removing the DEFAULT statement of a column
805 # would result in no change
806
807 push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s DROP DEFAULT',
f7410082 808 map($generator->quote($_),
809 $to_field->table->name,
810 $to_field->name,
811 ),
812 )
90726ffd 813 if ( !defined $new_default && defined $old_default );
ea93df61 814
10d7ce8b 815 # add geometry column and constraints
54b8ff8c 816 push @out,
817 add_geometry_column($to_field),
818 add_geometry_constraints($to_field)
819 if is_geometry($to_field);
ea93df61 820
c50d1a0a 821 return wantarray ? @out : join(";\n", @out);
bfb5a568 822}
823
3406fd5b 824sub rename_field { alter_field(@_) }
825
bfb5a568 826sub add_field
827{
f7410082 828 my ($new_field,$options) = @_;
bfb5a568 829
3406fd5b 830 my $out = sprintf('ALTER TABLE %s ADD COLUMN %s',
f7410082 831 _generator($options)->quote($new_field->table->name),
832 create_field($new_field, $options));
54b8ff8c 833 $out .= "\n".add_geometry_column($new_field)
834 . "\n".add_geometry_constraints($new_field)
835 if is_geometry($new_field);
bfb5a568 836 return $out;
837
838}
839
840sub drop_field
841{
c50d1a0a 842 my ($old_field, $options) = @_;
843
f82112a3 844 my $generator = _generator($options);
bfb5a568 845
3406fd5b 846 my $out = sprintf('ALTER TABLE %s DROP COLUMN %s',
2230ed2a 847 $generator->quote($old_field->table->name),
848 $generator->quote($old_field->name));
54b8ff8c 849 $out .= "\n".drop_geometry_column($old_field)
850 if is_geometry($old_field);
ea93df61 851 return $out;
bfb5a568 852}
853
0b4b7709 854sub add_geometry_column {
54b8ff8c 855 my ($field, $options) = @_;
0b4b7709 856
54b8ff8c 857 return sprintf(
0b4b7709 858 "INSERT INTO geometry_columns VALUES ('%s','%s','%s','%s','%s','%s','%s')",
859 '',
860 $field->table->schema->name,
861 $options->{table} ? $options->{table} : $field->table->name,
862 $field->name,
863 $field->extra->{dimensions},
864 $field->extra->{srid},
865 $field->extra->{geometry_type},
866 );
e83ad71c 867}
868
0b4b7709 869sub drop_geometry_column {
870 my $field = shift;
ea93df61 871
54b8ff8c 872 return sprintf(
0b4b7709 873 "DELETE FROM geometry_columns WHERE f_table_schema = '%s' AND f_table_name = '%s' AND f_geometry_column = '%s'",
874 $field->table->schema->name,
875 $field->table->name,
876 $field->name,
877 );
e83ad71c 878}
879
0b4b7709 880sub add_geometry_constraints {
54b8ff8c 881 my ($field, $options) = @_;
ea93df61 882
54b8ff8c 883 return join("\n", map { alter_create_constraint($_) }
884 create_geometry_constraints($field));
e83ad71c 885}
886
0b4b7709 887sub drop_geometry_constraints {
54b8ff8c 888 my ($field, $options) = @_;
ea93df61 889
54b8ff8c 890 return join("\n", map { alter_drop_constraint($_) }
891 create_geometry_constraints($field));
ea93df61 892
e83ad71c 893}
894
3406fd5b 895sub alter_table {
896 my ($to_table, $options) = @_;
f82112a3 897 my $generator = _generator($options);
3406fd5b 898 my $out = sprintf('ALTER TABLE %s %s',
2230ed2a 899 $generator->quote($to_table->name),
3406fd5b 900 $options->{alter_table_action});
e83ad71c 901 $out .= "\n".$options->{geometry_changes} if $options->{geometry_changes};
3406fd5b 902 return $out;
903}
904
905sub rename_table {
906 my ($old_table, $new_table, $options) = @_;
f82112a3 907 my $generator = _generator($options);
2230ed2a 908 $options->{alter_table_action} = "RENAME TO " . $generator->quote($new_table);
e83ad71c 909
54b8ff8c 910 my @geometry_changes = map {
911 drop_geometry_column($_),
912 add_geometry_column($_, { table => $new_table }),
913 } grep { is_geometry($_) } $old_table->get_fields;
ea93df61 914
54b8ff8c 915 $options->{geometry_changes} = join ("\n",@geometry_changes) if @geometry_changes;
ea93df61 916
3406fd5b 917 return alter_table($old_table, $options);
918}
919
920sub alter_create_index {
921 my ($index, $options) = @_;
f82112a3 922 my $generator = _generator($options);
3406fd5b 923 my ($idef, $constraints) = create_index($index, {
f82112a3 924 generator => $generator,
3406fd5b 925 });
926 return $index->type eq NORMAL ? $idef
927 : sprintf('ALTER TABLE %s ADD %s',
2230ed2a 928 $generator->quote($index->table->name),
3406fd5b 929 join(q{}, @$constraints)
930 );
931}
932
933sub alter_drop_index {
934 my ($index, $options) = @_;
f7410082 935 return 'DROP INDEX '. _generator($options)->quote($index->name);
3406fd5b 936}
937
938sub alter_drop_constraint {
939 my ($c, $options) = @_;
f82112a3 940 my $generator = _generator($options);
c50d1a0a 941
bc9b1c11 942 # attention: Postgres has a very special naming structure for naming
943 # foreign keys and primary keys. It names them using the name of the
944 # table as prefix and fkey or pkey as suffix, concatenated by an underscore
945 my $c_name;
946 if( $c->name ) {
f7410082 947 # Already has a name, just use it
948 $c_name = $c->name;
bc9b1c11 949 } elsif ( $c->type eq FOREIGN_KEY ) {
950 # Doesn't have a name, and is foreign key, append '_fkey'
f7410082 951 $c_name = $c->table->name . '_' . ($c->fields)[0] . '_fkey';
bc9b1c11 952 } elsif ( $c->type eq PRIMARY_KEY ) {
953 # Doesn't have a name, and is primary key, append '_pkey'
f7410082 954 $c_name = $c->table->name . '_pkey';
bc9b1c11 955 }
956
c50d1a0a 957 return sprintf(
958 'ALTER TABLE %s DROP CONSTRAINT %s',
f7410082 959 map { $generator->quote($_) } $c->table->name, $c_name,
c50d1a0a 960 );
3406fd5b 961}
962
963sub alter_create_constraint {
964 my ($index, $options) = @_;
f82112a3 965 my $generator = _generator($options);
90726ffd 966 my ($defs, $fks) = create_constraint(@_);
ea93df61 967
90726ffd 968 # return if there are no constraint definitions so we don't run
969 # into output like this:
970 # ALTER TABLE users ADD ;
ea93df61 971
90726ffd 972 return unless(@{$defs} || @{$fks});
973 return $index->type eq FOREIGN_KEY ? join(q{}, @{$fks})
2230ed2a 974 : join( ' ', 'ALTER TABLE', $generator->quote($index->table->name),
90726ffd 975 'ADD', join(q{}, @{$defs}, @{$fks})
3406fd5b 976 );
977}
978
979sub drop_table {
980 my ($table, $options) = @_;
f82112a3 981 my $generator = _generator($options);
2230ed2a 982 my $out = "DROP TABLE " . $generator->quote($table) . " CASCADE";
ea93df61 983
e83ad71c 984 my @geometry_drops = map { drop_geometry_column($_); } grep { is_geometry($_) } $table->get_fields;
985
54b8ff8c 986 $out .= join("\n", '', @geometry_drops) if @geometry_drops;
e83ad71c 987 return $out;
3406fd5b 988}
989
0c610cc8 990sub batch_alter_table {
991 my ( $table, $diff_hash, $options ) = @_;
0c610cc8 992
993 # as long as we're not renaming the table we don't need to be here
994 if ( @{$diff_hash->{rename_table}} == 0 ) {
86609eaa 995 return batch_alter_table_statements($diff_hash, $options);
0c610cc8 996 }
997
998 # first we need to perform drops which are on old table
86609eaa 999 my @sql = batch_alter_table_statements($diff_hash, $options, qw(
1000 alter_drop_constraint
0c610cc8 1001 alter_drop_index
86609eaa 1002 drop_field
1003 ));
0c610cc8 1004
1005 # next comes the rename_table
1006 my $old_table = $diff_hash->{rename_table}[0][0];
1007 push @sql, rename_table( $old_table, $table, $options );
1008
1009 # for alter_field (and so also rename_field) we need to make sure old
1010 # field has table name set to new table otherwise calling alter_field dies
1011 $diff_hash->{alter_field} =
1012 [map { $_->[0]->table($table) && $_ } @{$diff_hash->{alter_field}}];
1013 $diff_hash->{rename_field} =
1014 [map { $_->[0]->table($table) && $_ } @{$diff_hash->{rename_field}}];
1015
1016 # now add everything else
86609eaa 1017 push @sql, batch_alter_table_statements($diff_hash, $options, qw(
1018 add_field
0c610cc8 1019 alter_field
1020 rename_field
1021 alter_create_index
1022 alter_create_constraint
86609eaa 1023 alter_table
1024 ));
0c610cc8 1025
1026 return @sql;
1027}
1028
f8f0253c 10291;
f8f0253c 1030
96844cae 1031# -------------------------------------------------------------------
1032# Life is full of misery, loneliness, and suffering --
1033# and it's all over much too soon.
1034# Woody Allen
1035# -------------------------------------------------------------------
f8f0253c 1036
96844cae 1037=pod
f8f0253c 1038
20770e44 1039=head1 SEE ALSO
1040
1041SQL::Translator, SQL::Translator::Producer::Oracle.
1042
f8f0253c 1043=head1 AUTHOR
1044
f997b9ab 1045Ken Youens-Clark E<lt>kclark@cpan.orgE<gt>.
f8f0253c 1046
1047=cut