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