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