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