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