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