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