Fix missing semicolons between PostGIS statements
[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) {
6440741a 337 $create_statement .= join(";\n", '', map{ drop_geometry_column($_) } @geometry_columns) if $options->{add_drop_table};
338 $create_statement .= join(";\n", '', map{ add_geometry_column($_) } @geometry_columns);
0b4b7709 339 }
e83ad71c 340
08d91aad 341 return $create_statement, \@fks;
bfb5a568 342}
343
296c2701 344sub create_view {
345 my ($view, $options) = @_;
f82112a3 346 my $generator = _generator($options);
0e758018 347 my $postgres_version = $options->{postgres_version} || 0;
a25ac5d2 348 my $add_drop_view = $options->{add_drop_view};
296c2701 349
350 my $view_name = $view->name;
351 debug("PKG: Looking at view '${view_name}'\n");
352
353 my $create = '';
2230ed2a 354 $create .= "--\n-- View: " . $generator->quote($view_name) . "\n--\n"
296c2701 355 unless $options->{no_comments};
0e758018 356 if ($add_drop_view) {
357 if ($postgres_version >= 8.002) {
2230ed2a 358 $create .= "DROP VIEW IF EXISTS " . $generator->quote($view_name) . ";\n";
0e758018 359 } else {
2230ed2a 360 $create .= "DROP VIEW " . $generator->quote($view_name) . ";\n";
0e758018 361 }
362 }
296c2701 363 $create .= 'CREATE';
296c2701 364
365 my $extra = $view->extra;
366 $create .= " TEMPORARY" if exists($extra->{temporary}) && $extra->{temporary};
2230ed2a 367 $create .= " VIEW " . $generator->quote($view_name);
296c2701 368
369 if ( my @fields = $view->fields ) {
2230ed2a 370 my $field_list = join ', ', map { $generator->quote($_) } @fields;
296c2701 371 $create .= " ( ${field_list} )";
372 }
373
374 if ( my $sql = $view->sql ) {
f59b2c0e 375 $create .= " AS\n ${sql}\n";
296c2701 376 }
377
378 if ( $extra->{check_option} ) {
379 $create .= ' WITH ' . uc $extra->{check_option} . ' CHECK OPTION';
380 }
381
296c2701 382 return $create;
383}
384
ea93df61 385{
bfb5a568 386
387 my %field_name_scope;
388
389 sub create_field
390 {
391 my ($field, $options) = @_;
392
f82112a3 393 my $generator = _generator($options);
bfb5a568 394 my $table_name = $field->table->name;
395 my $constraint_defs = $options->{constraint_defs} || [];
5342f5c1 396 my $postgres_version = $options->{postgres_version} || 0;
79f55d7e 397 my $type_defs = $options->{type_defs} || {};
bfb5a568 398
399 $field_name_scope{$table_name} ||= {};
912e67a1 400 my $field_name = $field->name;
31bed2c0 401 my $field_comments = '';
402 if (my $comments = $field->comments) {
403 $comments =~ s/(?<!\A)^/ -- /mg;
404 $field_comments = "-- $comments\n ";
405 }
bfb5a568 406
2230ed2a 407 my $field_def = $field_comments . $generator->quote($field_name);
bfb5a568 408
409 #
410 # Datatype
411 #
bfb5a568 412 my $data_type = lc $field->data_type;
413 my %extra = $field->extra;
414 my $list = $extra{'list'} || [];
1868ddbe 415 my $commalist = join( ', ', map { __PACKAGE__->_quote_string($_) } @$list );
bfb5a568 416
d31a1336 417 if ($postgres_version >= 8.003 && $data_type eq 'enum') {
79f55d7e 418 my $type_name = $extra{'custom_type_name'} || $field->table->name . '_' . $field->name . '_type';
5342f5c1 419 $field_def .= ' '. $type_name;
d25db732 420 my $new_type_def = "DROP TYPE IF EXISTS $type_name CASCADE;\n" .
79f55d7e 421 "CREATE TYPE $type_name AS ENUM ($commalist)";
422 if (! exists $type_defs->{$type_name} ) {
423 $type_defs->{$type_name} = $new_type_def;
424 } elsif ( $type_defs->{$type_name} ne $new_type_def ) {
425 die "Attempted to redefine type name '$type_name' as a different type.\n";
426 }
5342f5c1 427 } else {
428 $field_def .= ' '. convert_datatype($field);
429 }
bfb5a568 430
431 #
ea93df61 432 # Default value
bfb5a568 433 #
1868ddbe 434 __PACKAGE__->_apply_default_value(
06baeb21 435 $field,
436 \$field_def,
437 [
438 'NULL' => \'NULL',
439 'now()' => 'now()',
440 'CURRENT_TIMESTAMP' => 'CURRENT_TIMESTAMP',
441 ],
442 );
bfb5a568 443
444 #
445 # Not null constraint
446 #
447 $field_def .= ' NOT NULL' unless $field->is_nullable;
448
0b4b7709 449 #
450 # Geometry constraints
451 #
452 if (is_geometry($field)) {
453 foreach ( create_geometry_constraints($field) ) {
454 my ($cdefs, $fks) = create_constraint($_, {
455 generator => $generator,
456 });
457 push @$constraint_defs, @$cdefs;
458 push @$fks, @$fks;
459 }
e83ad71c 460 }
ea93df61 461
bfb5a568 462 return $field_def;
463 }
464}
465
0b4b7709 466sub create_geometry_constraints {
467 my $field = shift;
468
469 my @constraints;
470 push @constraints, SQL::Translator::Schema::Constraint->new(
471 name => "enforce_dims_".$field->name,
472 expression => "(ST_NDims($field) = ".$field->extra->{dimensions}.")",
473 table => $field->table,
474 type => CHECK_C,
475 );
476
477 push @constraints, SQL::Translator::Schema::Constraint->new(
478 name => "enforce_srid_".$field->name,
479 expression => "(ST_SRID($field) = ".$field->extra->{srid}.")",
480 table => $field->table,
481 type => CHECK_C,
482 );
483 push @constraints, SQL::Translator::Schema::Constraint->new(
484 name => "enforce_geotype_".$field->name,
485 expression => "(GeometryType($field) = '".$field->extra->{geometry_type}."'::text OR $field IS NULL)",
486 table => $field->table,
487 type => CHECK_C,
488 );
489
490 return @constraints;
e83ad71c 491}
492
892573f2 493{
b14cf6f4 494 my %index_name;
495 sub create_index
496 {
497 my ($index, $options) = @_;
bfb5a568 498
b14cf6f4 499 my $generator = _generator($options);
500 my $table_name = $index->table->name;
501
502 my ($index_def, @constraint_defs);
503
504 my $name
505 = $index->name
506 || join('_', $table_name, 'idx', ++$index_name{ $table_name });
507
508 my $type = $index->type || NORMAL;
509 my @fields = $index->fields;
510 return unless @fields;
511
512 my $index_using;
513 my $index_where;
514 for my $opt ( $index->options ) {
515 if ( ref $opt eq 'HASH' ) {
516 foreach my $key (keys %$opt) {
517 my $value = $opt->{$key};
518 next unless defined $value;
519 if ( uc($key) eq 'USING' ) {
520 $index_using = "USING $value";
521 }
522 elsif ( uc($key) eq 'WHERE' ) {
523 $index_where = "WHERE $value";
524 }
525 }
526 }
5b36314d 527 }
5b36314d 528
b14cf6f4 529 my $def_start = 'CONSTRAINT ' . $generator->quote($name) . ' ';
530 my $field_names = '(' . join(", ", (map { $_ =~ /\(.*\)/ ? $_ : ( $generator->quote($_) ) } @fields)) . ')';
531 if ( $type eq PRIMARY_KEY ) {
532 push @constraint_defs, "${def_start}PRIMARY KEY ".$field_names;
533 }
534 elsif ( $type eq UNIQUE ) {
535 push @constraint_defs, "${def_start}UNIQUE " .$field_names;
536 }
537 elsif ( $type eq NORMAL ) {
538 $index_def =
539 'CREATE INDEX ' . $generator->quote($name) . ' on ' . $generator->quote($table_name) . ' ' .
540 join ' ', grep { defined } $index_using, $field_names, $index_where;
541 }
542 else {
543 warn "Unknown index type ($type) on table $table_name.\n"
544 if $WARN;
545 }
bfb5a568 546
b14cf6f4 547 return $index_def, \@constraint_defs;
548 }
892573f2 549}
bfb5a568 550
892573f2 551sub create_constraint
552{
553 my ($c, $options) = @_;
bfb5a568 554
f82112a3 555 my $generator = _generator($options);
892573f2 556 my $table_name = $c->table->name;
557 my (@constraint_defs, @fks);
bfb5a568 558
892573f2 559 my $name = $c->name || '';
bfb5a568 560
5f31ed66 561 my @fields = grep { defined } $c->fields;
892573f2 562
5f31ed66 563 my @rfields = grep { defined } $c->reference_fields;
892573f2 564
565 next if !@fields && $c->type ne CHECK_C;
2230ed2a 566 my $def_start = $name ? 'CONSTRAINT ' . $generator->quote($name) . ' ' : '';
567 my $field_names = '(' . join(", ", (map { $_ =~ /\(.*\)/ ? $_ : ( $generator->quote($_) ) } @fields)) . ')';
892573f2 568 if ( $c->type eq PRIMARY_KEY ) {
5f31ed66 569 push @constraint_defs, "${def_start}PRIMARY KEY ".$field_names;
892573f2 570 }
571 elsif ( $c->type eq UNIQUE ) {
5f31ed66 572 push @constraint_defs, "${def_start}UNIQUE " .$field_names;
892573f2 573 }
574 elsif ( $c->type eq CHECK_C ) {
575 my $expression = $c->expression;
576 push @constraint_defs, "${def_start}CHECK ($expression)";
577 }
578 elsif ( $c->type eq FOREIGN_KEY ) {
2230ed2a 579 my $def .= "ALTER TABLE " . $generator->quote($table_name) . " ADD ${def_start}FOREIGN KEY $field_names"
580 . "\n REFERENCES " . $generator->quote($c->reference_table);
bfb5a568 581
892573f2 582 if ( @rfields ) {
2230ed2a 583 $def .= ' (' . join( ', ', map { $generator->quote($_) } @rfields ) . ')';
892573f2 584 }
bfb5a568 585
892573f2 586 if ( $c->match_type ) {
ea93df61 587 $def .= ' MATCH ' .
892573f2 588 ( $c->match_type =~ /full/i ) ? 'FULL' : 'PARTIAL';
589 }
5342f5c1 590
892573f2 591 if ( $c->on_delete ) {
5863ad87 592 $def .= ' ON DELETE '. $c->on_delete;
892573f2 593 }
bfb5a568 594
892573f2 595 if ( $c->on_update ) {
5863ad87 596 $def .= ' ON UPDATE '. $c->on_update;
892573f2 597 }
124b192c 598
892573f2 599 if ( $c->deferrable ) {
600 $def .= ' DEFERRABLE';
124b192c 601 }
602
892573f2 603 push @fks, "$def";
124b192c 604 }
bfb5a568 605
892573f2 606 return \@constraint_defs, \@fks;
607}
608
c96cd4a8 609sub create_trigger {
610 my ($trigger,$options) = @_;
c9c8f3e1 611 my $generator = _generator($options);
c96cd4a8 612
613 my @statements;
614
c9c8f3e1 615 push @statements, sprintf( 'DROP TRIGGER IF EXISTS %s', $generator->quote($trigger->name) )
c96cd4a8 616 if $options->{add_drop_trigger};
617
618 my $scope = $trigger->scope || '';
619 $scope = " FOR EACH $scope" if $scope;
620
621 push @statements, sprintf(
622 'CREATE TRIGGER %s %s %s ON %s%s %s',
c9c8f3e1 623 $generator->quote($trigger->name),
c96cd4a8 624 $trigger->perform_action_when,
625 join( ' OR ', @{ $trigger->database_events } ),
c9c8f3e1 626 $generator->quote($trigger->on_table),
c96cd4a8 627 $scope,
628 $trigger->action,
629 );
630
631 return @statements;
632}
633
bfb5a568 634sub convert_datatype
635{
636 my ($field) = @_;
637
638 my @size = $field->size;
639 my $data_type = lc $field->data_type;
aacb3187 640 my $array = $data_type =~ s/\[\]$//;
bfb5a568 641
642 if ( $data_type eq 'enum' ) {
643# my $len = 0;
644# $len = ($len < length($_)) ? length($_) : $len for (@$list);
645# my $chk_name = mk_name( $table_name.'_'.$field_name, 'chk' );
ea93df61 646# push @$constraint_defs,
2230ed2a 647# 'CONSTRAINT "$chk_name" CHECK (' . $generator->quote(field_name) .
bfb5a568 648# qq[IN ($commalist))];
649 $data_type = 'character varying';
650 }
651 elsif ( $data_type eq 'set' ) {
652 $data_type = 'character varying';
653 }
654 elsif ( $field->is_auto_increment ) {
655 if ( defined $size[0] && $size[0] > 11 ) {
656 $data_type = 'bigserial';
657 }
658 else {
659 $data_type = 'serial';
660 }
661 undef @size;
662 }
663 else {
ada2826e 664 $data_type = defined $translate{ lc $data_type } ?
665 $translate{ lc $data_type } :
bfb5a568 666 $data_type;
667 }
668
ad258776 669 if ( $data_type =~ /^time/i || $data_type =~ /^interval/i ) {
bfb5a568 670 if ( defined $size[0] && $size[0] > 6 ) {
671 $size[0] = 6;
672 }
673 }
674
675 if ( $data_type eq 'integer' ) {
676 if ( defined $size[0] && $size[0] > 0) {
677 if ( $size[0] > 10 ) {
678 $data_type = 'bigint';
679 }
680 elsif ( $size[0] < 5 ) {
681 $data_type = 'smallint';
682 }
683 else {
684 $data_type = 'integer';
685 }
686 }
687 else {
688 $data_type = 'integer';
689 }
690 }
52bc2e13 691
692 my $type_with_size = join('|',
e189562c 693 'bit', 'varbit', 'character', 'bit varying', 'character varying',
90089d63 694 'time', 'timestamp', 'interval', 'numeric', 'float'
52bc2e13 695 );
696
697 if ( $data_type !~ /$type_with_size/ ) {
ea93df61 698 @size = ();
e56dabb7 699 }
bfb5a568 700
ad258776 701 if (defined $size[0] && $size[0] > 0 && $data_type =~ /^time/i ) {
702 $data_type =~ s/^(time.*?)( with.*)?$/$1($size[0])/;
703 $data_type .= $2 if(defined $2);
704 } elsif ( defined $size[0] && $size[0] > 0 ) {
e189562c 705 $data_type .= '(' . join( ',', @size ) . ')';
08d91aad 706 }
aacb3187 707 if($array)
708 {
709 $data_type .= '[]';
710 }
bfb5a568 711
140a1dad 712 #
713 # Geography
714 #
715 if($data_type eq 'geography'){
aa068030 716 $data_type .= '('.$field->extra->{geography_type}.','. $field->extra->{srid} .')'
140a1dad 717 }
718
bfb5a568 719 return $data_type;
720}
721
722
723sub alter_field
724{
f7410082 725 my ($from_field, $to_field, $options) = @_;
bfb5a568 726
ea93df61 727 die "Can't alter field in another table"
bfb5a568 728 if($from_field->table->name ne $to_field->table->name);
729
f7410082 730 my $generator = _generator($options);
bfb5a568 731 my @out;
ea93df61 732
e83ad71c 733 # drop geometry column and constraints
54b8ff8c 734 push @out,
735 drop_geometry_column($from_field),
736 drop_geometry_constraints($from_field),
737 if is_geometry($from_field);
c50d1a0a 738
739 # it's necessary to start with rename column cause this would affect
740 # all of the following statements which would be broken if do the
741 # rename later
742 # BUT: drop geometry is done before the rename, cause it work's on the
743 # $from_field directly
744 push @out, sprintf('ALTER TABLE %s RENAME COLUMN %s TO %s',
f7410082 745 map($generator->quote($_),
746 $to_field->table->name,
747 $from_field->name,
748 $to_field->name,
749 ),
750 )
751 if($from_field->name ne $to_field->name);
c50d1a0a 752
3406fd5b 753 push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s SET NOT NULL',
f7410082 754 map($generator->quote($_),
755 $to_field->table->name,
756 $to_field->name
757 ),
758 )
759 if(!$to_field->is_nullable and $from_field->is_nullable);
bfb5a568 760
90726ffd 761 push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s DROP NOT NULL',
f7410082 762 map($generator->quote($_),
763 $to_field->table->name,
764 $to_field->name
765 ),
766 )
767 if (!$from_field->is_nullable and $to_field->is_nullable);
90726ffd 768
769
bfb5a568 770 my $from_dt = convert_datatype($from_field);
771 my $to_dt = convert_datatype($to_field);
3406fd5b 772 push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s TYPE %s',
f7410082 773 map($generator->quote($_),
774 $to_field->table->name,
775 $to_field->name
776 ),
777 $to_dt,
778 )
779 if($to_dt ne $from_dt);
bfb5a568 780
3406fd5b 781 my $old_default = $from_field->default_value;
782 my $new_default = $to_field->default_value;
90726ffd 783 my $default_value = $to_field->default_value;
ea93df61 784
90726ffd 785 # fixes bug where output like this was created:
786 # ALTER TABLE users ALTER COLUMN column SET DEFAULT ThisIsUnescaped;
787 if(ref $default_value eq "SCALAR" ) {
788 $default_value = $$default_value;
789 } elsif( defined $default_value && $to_dt =~ /^(character|text)/xsmi ) {
1868ddbe 790 $default_value = __PACKAGE__->_quote_string($default_value);
90726ffd 791 }
ea93df61 792
3406fd5b 793 push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s SET DEFAULT %s',
f7410082 794 map($generator->quote($_),
795 $to_field->table->name,
796 $to_field->name,
797 ),
798 $default_value,
799 )
3406fd5b 800 if ( defined $new_default &&
801 (!defined $old_default || $old_default ne $new_default) );
bfb5a568 802
ea93df61 803 # fixes bug where removing the DEFAULT statement of a column
804 # would result in no change
805
806 push @out, sprintf('ALTER TABLE %s ALTER COLUMN %s DROP DEFAULT',
f7410082 807 map($generator->quote($_),
808 $to_field->table->name,
809 $to_field->name,
810 ),
811 )
90726ffd 812 if ( !defined $new_default && defined $old_default );
ea93df61 813
10d7ce8b 814 # add geometry column and constraints
54b8ff8c 815 push @out,
816 add_geometry_column($to_field),
817 add_geometry_constraints($to_field)
818 if is_geometry($to_field);
ea93df61 819
c50d1a0a 820 return wantarray ? @out : join(";\n", @out);
bfb5a568 821}
822
3406fd5b 823sub rename_field { alter_field(@_) }
824
bfb5a568 825sub add_field
826{
f7410082 827 my ($new_field,$options) = @_;
bfb5a568 828
3406fd5b 829 my $out = sprintf('ALTER TABLE %s ADD COLUMN %s',
f7410082 830 _generator($options)->quote($new_field->table->name),
831 create_field($new_field, $options));
6440741a 832 $out .= ";\n".add_geometry_column($new_field)
833 . ";\n".add_geometry_constraints($new_field)
54b8ff8c 834 if is_geometry($new_field);
bfb5a568 835 return $out;
836
837}
838
839sub drop_field
840{
c50d1a0a 841 my ($old_field, $options) = @_;
842
f82112a3 843 my $generator = _generator($options);
bfb5a568 844
3406fd5b 845 my $out = sprintf('ALTER TABLE %s DROP COLUMN %s',
2230ed2a 846 $generator->quote($old_field->table->name),
847 $generator->quote($old_field->name));
6440741a 848 $out .= ";\n".drop_geometry_column($old_field)
54b8ff8c 849 if is_geometry($old_field);
ea93df61 850 return $out;
bfb5a568 851}
852
0b4b7709 853sub add_geometry_column {
54b8ff8c 854 my ($field, $options) = @_;
0b4b7709 855
54b8ff8c 856 return sprintf(
0b4b7709 857 "INSERT INTO geometry_columns VALUES ('%s','%s','%s','%s','%s','%s','%s')",
858 '',
859 $field->table->schema->name,
860 $options->{table} ? $options->{table} : $field->table->name,
861 $field->name,
862 $field->extra->{dimensions},
863 $field->extra->{srid},
864 $field->extra->{geometry_type},
865 );
e83ad71c 866}
867
0b4b7709 868sub drop_geometry_column {
869 my $field = shift;
ea93df61 870
54b8ff8c 871 return sprintf(
0b4b7709 872 "DELETE FROM geometry_columns WHERE f_table_schema = '%s' AND f_table_name = '%s' AND f_geometry_column = '%s'",
873 $field->table->schema->name,
874 $field->table->name,
875 $field->name,
876 );
e83ad71c 877}
878
0b4b7709 879sub add_geometry_constraints {
54b8ff8c 880 my ($field, $options) = @_;
ea93df61 881
6440741a 882 return join(";\n", map { alter_create_constraint($_) }
54b8ff8c 883 create_geometry_constraints($field));
e83ad71c 884}
885
0b4b7709 886sub drop_geometry_constraints {
54b8ff8c 887 my ($field, $options) = @_;
ea93df61 888
6440741a 889 return join(";\n", map { alter_drop_constraint($_) }
54b8ff8c 890 create_geometry_constraints($field));
ea93df61 891
e83ad71c 892}
893
3406fd5b 894sub alter_table {
895 my ($to_table, $options) = @_;
f82112a3 896 my $generator = _generator($options);
3406fd5b 897 my $out = sprintf('ALTER TABLE %s %s',
2230ed2a 898 $generator->quote($to_table->name),
3406fd5b 899 $options->{alter_table_action});
6440741a 900 $out .= ";\n".$options->{geometry_changes} if $options->{geometry_changes};
3406fd5b 901 return $out;
902}
903
904sub rename_table {
905 my ($old_table, $new_table, $options) = @_;
f82112a3 906 my $generator = _generator($options);
2230ed2a 907 $options->{alter_table_action} = "RENAME TO " . $generator->quote($new_table);
e83ad71c 908
54b8ff8c 909 my @geometry_changes = map {
910 drop_geometry_column($_),
911 add_geometry_column($_, { table => $new_table }),
912 } grep { is_geometry($_) } $old_table->get_fields;
ea93df61 913
6440741a 914 $options->{geometry_changes} = join (";\n",@geometry_changes) if @geometry_changes;
ea93df61 915
3406fd5b 916 return alter_table($old_table, $options);
917}
918
919sub alter_create_index {
920 my ($index, $options) = @_;
f82112a3 921 my $generator = _generator($options);
3406fd5b 922 my ($idef, $constraints) = create_index($index, {
f82112a3 923 generator => $generator,
3406fd5b 924 });
925 return $index->type eq NORMAL ? $idef
926 : sprintf('ALTER TABLE %s ADD %s',
2230ed2a 927 $generator->quote($index->table->name),
3406fd5b 928 join(q{}, @$constraints)
929 );
930}
931
932sub alter_drop_index {
933 my ($index, $options) = @_;
f7410082 934 return 'DROP INDEX '. _generator($options)->quote($index->name);
3406fd5b 935}
936
937sub alter_drop_constraint {
938 my ($c, $options) = @_;
f82112a3 939 my $generator = _generator($options);
c50d1a0a 940
bc9b1c11 941 # attention: Postgres has a very special naming structure for naming
942 # foreign keys and primary keys. It names them using the name of the
943 # table as prefix and fkey or pkey as suffix, concatenated by an underscore
944 my $c_name;
945 if( $c->name ) {
f7410082 946 # Already has a name, just use it
947 $c_name = $c->name;
bc9b1c11 948 } elsif ( $c->type eq FOREIGN_KEY ) {
949 # Doesn't have a name, and is foreign key, append '_fkey'
f7410082 950 $c_name = $c->table->name . '_' . ($c->fields)[0] . '_fkey';
bc9b1c11 951 } elsif ( $c->type eq PRIMARY_KEY ) {
952 # Doesn't have a name, and is primary key, append '_pkey'
f7410082 953 $c_name = $c->table->name . '_pkey';
bc9b1c11 954 }
955
c50d1a0a 956 return sprintf(
957 'ALTER TABLE %s DROP CONSTRAINT %s',
f7410082 958 map { $generator->quote($_) } $c->table->name, $c_name,
c50d1a0a 959 );
3406fd5b 960}
961
962sub alter_create_constraint {
963 my ($index, $options) = @_;
f82112a3 964 my $generator = _generator($options);
90726ffd 965 my ($defs, $fks) = create_constraint(@_);
ea93df61 966
90726ffd 967 # return if there are no constraint definitions so we don't run
968 # into output like this:
969 # ALTER TABLE users ADD ;
ea93df61 970
90726ffd 971 return unless(@{$defs} || @{$fks});
972 return $index->type eq FOREIGN_KEY ? join(q{}, @{$fks})
2230ed2a 973 : join( ' ', 'ALTER TABLE', $generator->quote($index->table->name),
90726ffd 974 'ADD', join(q{}, @{$defs}, @{$fks})
3406fd5b 975 );
976}
977
978sub drop_table {
979 my ($table, $options) = @_;
f82112a3 980 my $generator = _generator($options);
2230ed2a 981 my $out = "DROP TABLE " . $generator->quote($table) . " CASCADE";
ea93df61 982
e83ad71c 983 my @geometry_drops = map { drop_geometry_column($_); } grep { is_geometry($_) } $table->get_fields;
984
6440741a 985 $out .= join(";\n", '', @geometry_drops) if @geometry_drops;
e83ad71c 986 return $out;
3406fd5b 987}
988
0c610cc8 989sub batch_alter_table {
990 my ( $table, $diff_hash, $options ) = @_;
0c610cc8 991
992 # as long as we're not renaming the table we don't need to be here
993 if ( @{$diff_hash->{rename_table}} == 0 ) {
86609eaa 994 return batch_alter_table_statements($diff_hash, $options);
0c610cc8 995 }
996
997 # first we need to perform drops which are on old table
86609eaa 998 my @sql = batch_alter_table_statements($diff_hash, $options, qw(
999 alter_drop_constraint
0c610cc8 1000 alter_drop_index
86609eaa 1001 drop_field
1002 ));
0c610cc8 1003
1004 # next comes the rename_table
1005 my $old_table = $diff_hash->{rename_table}[0][0];
1006 push @sql, rename_table( $old_table, $table, $options );
1007
1008 # for alter_field (and so also rename_field) we need to make sure old
1009 # field has table name set to new table otherwise calling alter_field dies
1010 $diff_hash->{alter_field} =
1011 [map { $_->[0]->table($table) && $_ } @{$diff_hash->{alter_field}}];
1012 $diff_hash->{rename_field} =
1013 [map { $_->[0]->table($table) && $_ } @{$diff_hash->{rename_field}}];
1014
1015 # now add everything else
86609eaa 1016 push @sql, batch_alter_table_statements($diff_hash, $options, qw(
1017 add_field
0c610cc8 1018 alter_field
1019 rename_field
1020 alter_create_index
1021 alter_create_constraint
86609eaa 1022 alter_table
1023 ));
0c610cc8 1024
1025 return @sql;
1026}
1027
f8f0253c 10281;
f8f0253c 1029
96844cae 1030# -------------------------------------------------------------------
1031# Life is full of misery, loneliness, and suffering --
1032# and it's all over much too soon.
1033# Woody Allen
1034# -------------------------------------------------------------------
f8f0253c 1035
96844cae 1036=pod
f8f0253c 1037
20770e44 1038=head1 SEE ALSO
1039
1040SQL::Translator, SQL::Translator::Producer::Oracle.
1041
f8f0253c 1042=head1 AUTHOR
1043
f997b9ab 1044Ken Youens-Clark E<lt>kclark@cpan.orgE<gt>.
f8f0253c 1045
1046=cut