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