patch from abraxxa (Alexander Hartmaier) to truncate unique constraint names that...
[dbsrgits/SQL-Translator.git] / lib / SQL / Translator / Producer / Oracle.pm
CommitLineData
16dc9970 1package SQL::Translator::Producer::Oracle;
2
077ebf34 3# -------------------------------------------------------------------
478f608d 4# Copyright (C) 2002-2009 SQLFairy Authors
16dc9970 5#
077ebf34 6# This program is free software; you can redistribute it and/or
7# modify it under the terms of the GNU General Public License as
8# published by the Free Software Foundation; version 2.
9#
10# This program is distributed in the hope that it will be useful, but
11# WITHOUT ANY WARRANTY; without even the implied warranty of
12# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
13# General Public License for more details.
14#
15# You should have received a copy of the GNU General Public License
16# along with this program; if not, write to the Free Software
17# Foundation, Inc., 59 Temple Place, Suite 330, Boston, MA
18# 02111-1307 USA
19# -------------------------------------------------------------------
20
ba096dc4 21=head1 NAME
22
23SQL::Translator::Producer::Oracle - Oracle SQL producer
24
25=head1 SYNOPSIS
26
27 use SQL::Translator;
28
29 my $t = SQL::Translator->new( parser => '...', producer => 'Oracle' );
30 print $translator->translate( $file );
31
32=head1 DESCRIPTION
33
34Creates an SQL DDL suitable for Oracle.
35
662258cd 36=head1 producer_args
37
38=over
39
40=item delay_constraints
41
42This option remove the primary key and other key constraints from the
43CREATE TABLE statement and adds ALTER TABLEs at the end with it.
44
38b019a3 45=item quote_field_names
46
47Controls whether quotes are being used around column names in generated DDL.
48
49=item quote_table_names
50
51Controls whether quotes are being used around table, sequence and trigger names in
52generated DDL.
53
662258cd 54=back
55
2c5e6626 56=head1 NOTES
57
58=head2 Autoincremental primary keys
59
60This producer uses sequences and triggers to autoincrement primary key
61columns, if necessary. SQLPlus and DBI expect a slightly different syntax
62of CREATE TRIGGER statement. You might have noticed that this
63producer returns a scalar containing all statements concatenated by
64newlines or an array of single statements depending on the context
65(scalar, array) it has been called in.
66
67SQLPlus expects following trigger syntax:
68
69 CREATE OR REPLACE TRIGGER ai_person_id
70 BEFORE INSERT ON person
71 FOR EACH ROW WHEN (
72 new.id IS NULL OR new.id = 0
73 )
74 BEGIN
75 SELECT sq_person_id.nextval
76 INTO :new.id
77 FROM dual;
78 END;
79 /
80
81Whereas if you want to create the same trigger using L<DBI/do>, you need
82to omit the last slash:
83
84 my $dbh = DBI->connect('dbi:Oracle:mysid', 'scott', 'tiger');
85 $dbh->do("
86 CREATE OR REPLACE TRIGGER ai_person_id
87 BEFORE INSERT ON person
88 FOR EACH ROW WHEN (
89 new.id IS NULL OR new.id = 0
90 )
91 BEGIN
92 SELECT sq_person_id.nextval
93 INTO :new.id
94 FROM dual;
95 END;
96 ");
97
98If you call this producer in array context, we expect you want to process
99the returned array of statements using L<DBI> like
100L<DBIx::Class::Schema/deploy> does.
101
102To get this working we removed the slash in those statements in version
1030.09002 of L<SQL::Translator> when called in array context. In scalar
104context the slash will be still there to ensure compatibility with SQLPlus.
105
ba096dc4 106=cut
107
16dc9970 108use strict;
da06ac74 109use vars qw[ $VERSION $DEBUG $WARN ];
11ad2df9 110$VERSION = '1.59';
d529894e 111$DEBUG = 0 unless defined $DEBUG;
16dc9970 112
57f77285 113use SQL::Translator::Schema::Constants;
5ee19df8 114use SQL::Translator::Utils qw(header_comment);
115
16dc9970 116my %translate = (
d529894e 117 #
118 # MySQL types
119 #
16dc9970 120 bigint => 'number',
07720cf1 121 double => 'float',
16dc9970 122 decimal => 'number',
3c8c1129 123 float => 'float',
16dc9970 124 int => 'number',
25966689 125 integer => 'number',
16dc9970 126 mediumint => 'number',
127 smallint => 'number',
128 tinyint => 'number',
16dc9970 129 char => 'char',
16dc9970 130 varchar => 'varchar2',
1f58ba76 131 tinyblob => 'blob',
132 blob => 'blob',
133 mediumblob => 'blob',
134 longblob => 'blob',
9fc9bfb1 135 tinytext => 'varchar2',
d570aec7 136 text => 'clob',
1f58ba76 137 longtext => 'clob',
138 mediumtext => 'clob',
16dc9970 139 enum => 'varchar2',
140 set => 'varchar2',
16dc9970 141 date => 'date',
142 datetime => 'date',
143 time => 'date',
144 timestamp => 'date',
145 year => 'date',
d529894e 146
147 #
148 # PostgreSQL types
149 #
57f77285 150 numeric => 'number',
151 'double precision' => 'number',
152 serial => 'number',
153 bigserial => 'number',
154 money => 'number',
155 character => 'char',
156 'character varying' => 'varchar2',
157 bytea => 'BLOB',
158 interval => 'number',
159 boolean => 'number',
160 point => 'number',
161 line => 'number',
162 lseg => 'number',
163 box => 'number',
164 path => 'number',
165 polygon => 'number',
166 circle => 'number',
167 cidr => 'number',
168 inet => 'varchar2',
169 macaddr => 'varchar2',
170 bit => 'number',
171 'bit varying' => 'number',
ab8802d7 172
173 #
174 # Oracle types
175 #
176 number => 'number',
177 varchar2 => 'varchar2',
178 long => 'clob',
d529894e 179);
180
181#
e3aac687 182# Oracle 8/9 max size of data types from:
183# http://www.ss64.com/orasyntax/datatypes.html
184#
185my %max_size = (
186 char => 2000,
3c8c1129 187 float => 126,
e3aac687 188 nchar => 2000,
189 nvarchar2 => 4000,
190 number => [ 38, 127 ],
191 raw => 2000,
192 varchar => 4000, # only synonym for varchar2
193 varchar2 => 4000,
194);
195
96844cae 196my $max_id_length = 30;
197my %used_identifiers = ();
d529894e 198my %global_names;
d529894e 199my %truncated;
16dc9970 200
38b019a3 201# Quote used to escape table, field, sequence and trigger names
202my $quote_char = '"';
38b019a3 203
96844cae 204# -------------------------------------------------------------------
077ebf34 205sub produce {
a1d94525 206 my $translator = shift;
207 $DEBUG = $translator->debug;
e56dabb7 208 $WARN = $translator->show_warnings || 0;
a1d94525 209 my $no_comments = $translator->no_comments;
210 my $add_drop_table = $translator->add_drop_table;
211 my $schema = $translator->schema;
15861005 212 my $oracle_version = $translator->producer_args->{oracle_version} || 0;
65ffb46c 213 my $delay_constraints = $translator->producer_args->{delay_constraints};
214 my ($output, $create, @table_defs, @fk_defs, @trigger_defs, @index_defs, @constraint_defs);
44fcd0b5 215
e56dabb7 216 $create .= header_comment unless ($no_comments);
7769504d 217 my $qt = 1 if $translator->quote_table_names;
218 my $qf = 1 if $translator->quote_field_names;
077ebf34 219
d529894e 220 if ( $translator->parser_type =~ /mysql/i ) {
e56dabb7 221 $create .=
ba3cb849 222 "-- We assume that default NLS_DATE_FORMAT has been changed\n".
223 "-- but we set it here anyway to be self-consistent.\n"
224 unless $no_comments;
225
e56dabb7 226 $create .=
d529894e 227 "ALTER SESSION SET NLS_DATE_FORMAT = 'YYYY-MM-DD HH24:MI:SS';\n\n";
228 }
16dc9970 229
57f77285 230 for my $table ( $schema->get_tables ) {
535e5c95 231 my ( $table_def, $fk_def, $trigger_def, $index_def, $constraint_def ) = create_table(
e56dabb7 232 $table,
233 {
535e5c95 234 add_drop_table => $add_drop_table,
235 show_warnings => $WARN,
236 no_comments => $no_comments,
237 delay_constraints => $delay_constraints,
7769504d 238 quote_table_names => $qt,
239 quote_field_names => $qf,
e56dabb7 240 }
241 );
242 push @table_defs, @$table_def;
243 push @fk_defs, @$fk_def;
244 push @trigger_defs, @$trigger_def;
041e659f 245 push @index_defs, @$index_def;
65ffb46c 246 push @constraint_defs, @$constraint_def;
e56dabb7 247 }
248
249 my (@view_defs);
250 foreach my $view ( $schema->get_views ) {
64ac5763 251 my ( $view_def ) = create_view(
252 $view,
253 {
254 add_drop_view => $add_drop_table,
7769504d 255 quote_table_names => $qt,
64ac5763 256 }
257 );
258 push @view_defs, @$view_def;
e56dabb7 259 }
260
f92d79aa 261 if (wantarray) {
262 return defined $create ? $create : (), @table_defs, @view_defs, @fk_defs, @trigger_defs, @index_defs, @constraint_defs;
263 }
264 else {
38b019a3 265 $create .= join (";\n\n", @table_defs, @view_defs, @fk_defs, @index_defs, @constraint_defs);
7769504d 266 $create .= ";\n\n";
64ac5763 267 # If wantarray is not set we have to add "/" in this statement
268 # DBI->do() needs them omitted
f92d79aa 269 # triggers may NOT end with a semicolon
64ac5763 270 $create .= join "/\n\n", @trigger_defs;
271 # for last trigger
272 $create .= "/\n\n";
f92d79aa 273 return $create;
274 }
e56dabb7 275}
276
277sub create_table {
278 my ($table, $options) = @_;
7769504d 279 my $qt = $options->{quote_table_names};
280 my $qf = $options->{quote_field_names};
e56dabb7 281 my $table_name = $table->name;
7769504d 282 my $table_name_q = quote($table_name,$qt);
64ac5763 283
e56dabb7 284 my $item = '';
285 my $drop;
286 my (@create, @field_defs, @constraint_defs, @fk_defs, @trigger_defs);
16dc9970 287
38b019a3 288 push @create, "--\n-- Table: $table_name\n--" unless $options->{no_comments};
289 push @create, qq[DROP TABLE $table_name_q CASCADE CONSTRAINTS] if $options->{add_drop_table};
a7f999aa 290
f6195129 291 my ( %field_name_scope, @field_comments );
57f77285 292 for my $field ( $table->get_fields ) {
017ac5a7 293 my ($field_create, $field_defs, $trigger_defs, $field_comments) =
294 create_field($field, $options, \%field_name_scope);
295 push @create, @$field_create if ref $field_create;
296 push @field_defs, @$field_defs if ref $field_defs;
297 push @trigger_defs, @$trigger_defs if ref $trigger_defs;
298 push @field_comments, @$field_comments if ref $field_comments;
57f77285 299 }
300
301 #
02c2af3b 302 # Table options
303 #
304 my @table_options;
305 for my $opt ( $table->options ) {
306 if ( ref $opt eq 'HASH' ) {
307 my ( $key, $value ) = each %$opt;
308 if ( ref $value eq 'ARRAY' ) {
309 push @table_options, "$key\n(\n". join ("\n",
310 map { " $_->[0]\t$_->[1]" }
311 map { [ each %$_ ] }
312 @$value
313 )."\n)";
314 }
315 elsif ( !defined $value ) {
316 push @table_options, $key;
317 }
318 else {
319 push @table_options, "$key $value";
320 }
321 }
322 }
323
324 #
57f77285 325 # Table constraints
326 #
57f77285 327 for my $c ( $table->get_constraints ) {
328 my $name = $c->name || '';
38b019a3 329 my @fields = map { quote($_,$qf) } $c->fields;
330 my @rfields = quote($c->reference_fields,$qf);
4dfb0380 331 next if !@fields && $c->type ne CHECK_C;
57f77285 332
333 if ( $c->type eq PRIMARY_KEY ) {
d4977f1c 334 # create a name if delay_constraints
335 $name ||= mk_name( $table_name, 'pk' )
336 if $options->{delay_constraints};
7769504d 337 $name = quote($name,$qf);
54e61f1f 338 push @constraint_defs, ($name ? "CONSTRAINT $name " : '') .
7769504d 339 'PRIMARY KEY (' . join( ', ', @fields ) . ')';
57f77285 340 }
341 elsif ( $c->type eq UNIQUE ) {
7769504d 342 # Don't create UNIQUE constraints identical to the primary key
343 if ( my $pk = $table->primary_key ) {
344 my $u_fields = join(":", @fields);
345 my $pk_fields = join(":", $pk->fields);
346 next if $u_fields eq $pk_fields;
347 }
348
349 if ($name) {
350 # Force prepend of table_name as ORACLE doesn't allow duplicate
351 # CONSTRAINT names even for different tables (ORA-02264)
3b9249fb 352 $name = mk_name( "${table_name}_$name", 'u' ) unless $name =~ /^$table_name/;
7769504d 353 }
354 else {
38b019a3 355 $name = mk_name( $table_name, 'u' );
7769504d 356 }
357
358 $name = quote($name, $qf);
6d4ce9b6 359
b0c196d4 360 for my $f ( $c->fields ) {
361 my $field_def = $table->get_field( $f ) or next;
15861005 362 my $dtype = $translate{ ref $field_def->data_type eq "ARRAY" ? $field_def->data_type->[0] : $field_def->data_type} or next;
b0c196d4 363 if ( $WARN && $dtype =~ /clob/i ) {
364 warn "Oracle will not allow UNIQUE constraints on " .
365 "CLOB field '" . $field_def->table->name . '.' .
366 $field_def->name . ".'\n"
367 }
368 }
6d4ce9b6 369
57f77285 370 push @constraint_defs, "CONSTRAINT $name UNIQUE " .
371 '(' . join( ', ', @fields ) . ')';
372 }
4dfb0380 373 elsif ( $c->type eq CHECK_C ) {
54e61f1f 374 $name ||= mk_name( $name || $table_name, 'ck' );
7769504d 375 $name = quote($name, $qf);
4dfb0380 376 my $expression = $c->expression || '';
377 push @constraint_defs, "CONSTRAINT $name CHECK ($expression)";
378 }
57f77285 379 elsif ( $c->type eq FOREIGN_KEY ) {
541d6e24 380 $name = mk_name( join('_', $table_name, $c->fields). '_fk' );
7769504d 381 $name = quote($name, $qf);
cd617ba8 382 my $def = "CONSTRAINT $name FOREIGN KEY ";
383
384 if ( @fields ) {
1c899510 385 $def .= '(' . join( ', ', @fields ) . ')';
cd617ba8 386 }
387
38b019a3 388 my $ref_table = quote($c->reference_table,$qt);
1c899510 389
390 $def .= " REFERENCES $ref_table";
57f77285 391
392 if ( @rfields ) {
393 $def .= ' (' . join( ', ', @rfields ) . ')';
394 }
395
396 if ( $c->match_type ) {
397 $def .= ' MATCH ' .
398 ( $c->match_type =~ /full/i ) ? 'FULL' : 'PARTIAL';
399 }
400
401 if ( $c->on_delete ) {
402 $def .= ' ON DELETE '.join( ' ', $c->on_delete );
403 }
404
541d6e24 405 # disabled by plu 2007-12-29 - doesn't exist for oracle
406 #if ( $c->on_update ) {
407 # $def .= ' ON UPDATE '.join( ' ', $c->on_update );
408 #}
57f77285 409
38b019a3 410 push @fk_defs, sprintf("ALTER TABLE %s ADD %s", $table_name_q, $def);
57f77285 411 }
16dc9970 412 }
413
414 #
415 # Index Declarations
416 #
57f77285 417 my @index_defs = ();
57f77285 418 for my $index ( $table->get_indices ) {
419 my $index_name = $index->name || '';
420 my $index_type = $index->type || NORMAL;
38b019a3 421 my @fields = map { quote($_, $qf) } $index->fields;
44fcd0b5 422 next unless @fields;
16dc9970 423
bdd8e79a 424 my @index_options;
425 for my $opt ( $index->options ) {
426 if ( ref $opt eq 'HASH' ) {
427 my ( $key, $value ) = each %$opt;
428 if ( ref $value eq 'ARRAY' ) {
429 push @table_options, "$key\n(\n". join ("\n",
430 map { " $_->[0]\t$_->[1]" }
431 map { [ each %$_ ] }
432 @$value
433 )."\n)";
434 }
435 elsif ( !defined $value ) {
436 push @index_options, $key;
437 }
438 else {
439 push @index_options, "$key $value";
440 }
441 }
442 }
443 my $index_options = @index_options
444 ? "\n".join("\n", @index_options) : '';
445
57f77285 446 if ( $index_type eq PRIMARY_KEY ) {
6d4ce9b6 447 $index_name = $index_name ? mk_name( $index_name )
448 : mk_name( $table_name, 'pk' );
7769504d 449 $index_name = quote($index_name, $qf);
57f77285 450 push @field_defs, 'CONSTRAINT '.$index_name.' PRIMARY KEY '.
16dc9970 451 '(' . join( ', ', @fields ) . ')';
452 }
57f77285 453 elsif ( $index_type eq NORMAL ) {
6d4ce9b6 454 $index_name = $index_name ? mk_name( $index_name )
455 : mk_name( $table_name, $index_name || 'i' );
7769504d 456 $index_name = quote($index_name, $qf);
57f77285 457 push @index_defs,
1ced2a25 458 "CREATE INDEX $index_name on $table_name_q (".
da8e499e 459 join( ', ', @fields ).
4dec2e49 460 ")$index_options";
16dc9970 461 }
041e659f 462 elsif ( $index_type eq UNIQUE ) {
463 $index_name = $index_name ? mk_name( $index_name )
464 : mk_name( $table_name, $index_name || 'i' );
7769504d 465 $index_name = quote($index_name, $qf);
041e659f 466 push @index_defs,
1ced2a25 467 "CREATE UNIQUE INDEX $index_name on $table_name_q (".
041e659f 468 join( ', ', @fields ).
4dec2e49 469 ")$index_options";
041e659f 470 }
16dc9970 471 else {
96844cae 472 warn "Unknown index type ($index_type) on table $table_name.\n"
473 if $WARN;
16dc9970 474 }
475 }
476
9fc9bfb1 477 if ( my @table_comments = $table->comments ) {
478 for my $comment ( @table_comments ) {
479 next unless $comment;
b89d5635 480 $comment =~ s/'/''/g;
38b019a3 481 push @field_comments, "COMMENT ON TABLE $table_name_q is\n '".
4dec2e49 482 $comment . "'" unless $options->{no_comments}
9fc9bfb1 483 ;
484 }
485 }
486
02c2af3b 487 my $table_options = @table_options
488 ? "\n".join("\n", @table_options) : '';
38b019a3 489 push @create, "CREATE TABLE $table_name_q (\n" .
65ffb46c 490 join( ",\n", map { " $_" } @field_defs,
491 ($options->{delay_constraints} ? () : @constraint_defs) ) .
4dec2e49 492 "\n)$table_options";
65ffb46c 493
38b019a3 494 @constraint_defs = map { "ALTER TABLE $table_name_q ADD $_" }
65ffb46c 495 @constraint_defs;
16dc9970 496
96844cae 497 if ( $WARN ) {
498 if ( %truncated ) {
499 warn "Truncated " . keys( %truncated ) . " names:\n";
500 warn "\t" . join( "\n\t", sort keys %truncated ) . "\n";
501 }
96844cae 502 }
503
65ffb46c 504 return \@create, \@fk_defs, \@trigger_defs, \@index_defs, ($options->{delay_constraints} ? \@constraint_defs : []);
e56dabb7 505}
506
017ac5a7 507sub alter_field {
508 my ($from_field, $to_field, $options) = @_;
509
7769504d 510 my $qt = $options->{quote_table_names};
017ac5a7 511 my ($field_create, $field_defs, $trigger_defs, $field_comments) =
512 create_field($to_field, $options, {});
513
d888d445 514 # Fix ORA-01442
515 if ($to_field->is_nullable && !$from_field->is_nullable) {
516 die 'Cannot remove NOT NULL from table field';
517 } elsif (!$from_field->is_nullable && !$to_field->is_nullable) {
518 @$field_defs = map { s/ NOT NULL//; $_} @$field_defs;
519 }
520
1ced2a25 521 my $table_name = quote($to_field->table->name,$qt);
017ac5a7 522
38b019a3 523 return 'ALTER TABLE '.$table_name.' MODIFY ( '.join('', @$field_defs).' )';
017ac5a7 524}
525
fe9f1470 526sub add_field {
527 my ($new_field, $options) = @_;
528
7769504d 529 my $qt = $options->{quote_table_names};
fe9f1470 530 my ($field_create, $field_defs, $trigger_defs, $field_comments) =
531 create_field($new_field, $options, {});
532
1ced2a25 533 my $table_name = quote($new_field->table->name,$qt);
fe9f1470 534
535 my $out = sprintf('ALTER TABLE %s ADD ( %s )',
38b019a3 536 $table_name,
fe9f1470 537 join('', @$field_defs));
538 return $out;
539}
540
017ac5a7 541sub create_field {
542 my ($field, $options, $field_name_scope) = @_;
7769504d 543 my $qf = $options->{quote_field_names};
544 my $qt = $options->{quote_table_names};
017ac5a7 545
546 my (@create, @field_defs, @trigger_defs, @field_comments);
547
548 my $table_name = $field->table->name;
38b019a3 549 my $table_name_q = quote($table_name, $qt);
017ac5a7 550
551 #
552 # Field name
553 #
554 my $field_name = mk_name(
555 $field->name, '', $field_name_scope, 1
556 );
7769504d 557 my $field_name_q = quote($field_name, $qf);
38b019a3 558 my $field_def = quote($field_name, $qf);
559 $field->name( $field_name );
017ac5a7 560
561 #
562 # Datatype
563 #
564 my $check;
565 my $data_type = lc $field->data_type;
566 my @size = $field->size;
567 my %extra = $field->extra;
568 my $list = $extra{'list'} || [];
569 # \todo deal with embedded quotes
570 my $commalist = join( ', ', map { qq['$_'] } @$list );
571
572 if ( $data_type eq 'enum' ) {
38b019a3 573 $check = "CHECK ($field_name_q IN ($commalist))";
017ac5a7 574 $data_type = 'varchar2';
575 }
576 elsif ( $data_type eq 'set' ) {
577 # XXX add a CHECK constraint maybe
578 # (trickier and slower, than enum :)
579 $data_type = 'varchar2';
580 }
581 else {
7769504d 582 if (defined $translate{ $data_type }) {
583 if (ref $translate{ $data_type } eq "ARRAY") {
584 ($data_type,$size[0]) = @{$translate{ $data_type }};
585 } else {
586 $data_type = $translate{ $data_type };
587 }
588 }
15861005 589 $data_type ||= 'varchar2';
017ac5a7 590 }
7769504d 591
e3aac687 592 # ensure size is not bigger than max size oracle allows for data type
593 if ( defined $max_size{$data_type} ) {
594 for ( my $i = 0 ; $i < scalar @size ; $i++ ) {
595 my $max =
596 ref( $max_size{$data_type} ) eq 'ARRAY'
597 ? $max_size{$data_type}->[$i]
598 : $max_size{$data_type};
599 $size[$i] = $max if $size[$i] > $max;
600 }
601 }
017ac5a7 602
603 #
604 # Fixes ORA-02329: column of datatype LOB cannot be
605 # unique or a primary key
606 #
607 if ( $data_type eq 'clob' && $field->is_primary_key ) {
608 $data_type = 'varchar2';
609 $size[0] = 4000;
610 warn "CLOB cannot be a primary key, changing to VARCHAR2\n"
611 if $WARN;
612 }
613
614 if ( $data_type eq 'clob' && $field->is_unique ) {
615 $data_type = 'varchar2';
616 $size[0] = 4000;
617 warn "CLOB cannot be a unique key, changing to VARCHAR2\n"
618 if $WARN;
619 }
620
621 #
622 # Fixes ORA-00907: missing right parenthesis
623 #
624 if ( $data_type =~ /(date|clob)/i ) {
625 undef @size;
626 }
627
e19efc15 628 #
629 # Fixes ORA-00906: missing right parenthesis
630 # if size is 0 or undefined
631 #
632 for (qw/varchar2/) {
633 if ( $data_type =~ /^($_)$/i ) {
634 $size[0] ||= $max_size{$_};
635 }
636 }
637
017ac5a7 638 $field_def .= " $data_type";
639 if ( defined $size[0] && $size[0] > 0 ) {
9190556b 640 $field_def .= '(' . join( ',', @size ) . ')';
017ac5a7 641 }
642
643 #
644 # Default value
645 #
646 my $default = $field->default_value;
647 if ( defined $default ) {
648 #
649 # Wherein we try to catch a string being used as
650 # a default value for a numerical field. If "true/false,"
651 # then sub "1/0," otherwise just test the truthity of the
652 # argument and use that (naive?).
653 #
bc8e2aa1 654 if (ref $default and defined $$default) {
655 $default = $$default;
656 } elsif (ref $default) {
657 $default = 'NULL';
658 } elsif (
017ac5a7 659 $data_type =~ /^number$/i &&
660 $default !~ /^-?\d+$/ &&
661 $default !~ m/null/i
662 ) {
663 if ( $default =~ /^true$/i ) {
664 $default = "'1'";
665 } elsif ( $default =~ /^false$/i ) {
666 $default = "'0'";
667 } else {
668 $default = $default ? "'1'" : "'0'";
669 }
670 } elsif (
671 $data_type =~ /date/ && (
672 $default eq 'current_timestamp'
673 ||
674 $default eq 'now()'
675 )
676 ) {
677 $default = 'SYSDATE';
678 } else {
679 $default = $default =~ m/null/i ? 'NULL' : "'$default'"
680 }
681
682 $field_def .= " DEFAULT $default",
683 }
684
685 #
686 # Not null constraint
687 #
688 unless ( $field->is_nullable ) {
689 $field_def .= ' NOT NULL';
690 }
691
692 $field_def .= " $check" if $check;
693
694 #
695 # Auto_increment
696 #
697 if ( $field->is_auto_increment ) {
38b019a3 698 my $base_name = $table_name . "_". $field_name;
699 my $seq_name = quote(mk_name( $base_name, 'sq' ),$qt);
700 my $trigger_name = quote(mk_name( $base_name, 'ai' ),$qt);
017ac5a7 701
4dec2e49 702 push @create, qq[DROP SEQUENCE $seq_name] if $options->{add_drop_table};
703 push @create, "CREATE SEQUENCE $seq_name";
535e5c95 704 my $trigger =
017ac5a7 705 "CREATE OR REPLACE TRIGGER $trigger_name\n" .
38b019a3 706 "BEFORE INSERT ON $table_name_q\n" .
017ac5a7 707 "FOR EACH ROW WHEN (\n" .
38b019a3 708 " new.$field_name_q IS NULL".
709 " OR new.$field_name_q = 0\n".
017ac5a7 710 ")\n".
711 "BEGIN\n" .
712 " SELECT $seq_name.nextval\n" .
38b019a3 713 " INTO :new." . $field_name_q."\n" .
017ac5a7 714 " FROM dual;\n" .
535e5c95 715 "END;\n";
7769504d 716
535e5c95 717 push @trigger_defs, $trigger;
017ac5a7 718 }
719
720 if ( lc $field->data_type eq 'timestamp' ) {
38b019a3 721 my $base_name = $table_name . "_". $field_name;
722 my $trig_name = quote(mk_name( $base_name, 'ts' ), $qt);
535e5c95 723 my $trigger =
017ac5a7 724 "CREATE OR REPLACE TRIGGER $trig_name\n".
38b019a3 725 "BEFORE INSERT OR UPDATE ON $table_name_q\n".
726 "FOR EACH ROW WHEN (new.$field_name_q IS NULL)\n".
017ac5a7 727 "BEGIN \n".
38b019a3 728 " SELECT sysdate INTO :new.$field_name_q FROM dual;\n".
535e5c95 729 "END;\n";
730
535e5c95 731 push @trigger_defs, $trigger;
017ac5a7 732 }
733
734 push @field_defs, $field_def;
735
736 if ( my $comment = $field->comments ) {
737 $comment =~ s/'/''/g;
738 push @field_comments,
1ced2a25 739 "COMMENT ON COLUMN $table_name_q.$field_name_q is\n '" .
017ac5a7 740 $comment . "';" unless $options->{no_comments};
741 }
742
743 return \@create, \@field_defs, \@trigger_defs, \@field_comments;
744
745}
746
747
e56dabb7 748sub create_view {
64ac5763 749 my ($view, $options) = @_;
7769504d 750 my $qt = $options->{quote_table_names};
38b019a3 751 my $view_name = quote($view->name,$qt);
64ac5763 752
753 my @create;
754 push @create, qq[DROP VIEW $view_name]
755 if $options->{add_drop_view};
e56dabb7 756
64ac5763 757 push @create, sprintf("CREATE VIEW %s AS\n%s",
758 $view_name,
e56dabb7 759 $view->sql);
760
64ac5763 761 return \@create;
16dc9970 762}
763
d529894e 764# -------------------------------------------------------------------
765sub mk_name {
57f77285 766 my $basename = shift || '';
767 my $type = shift || '';
1c899510 768 $type = '' if $type =~ /^\d/;
57f77285 769 my $scope = shift || '';
770 my $critical = shift || '';
d529894e 771 my $basename_orig = $basename;
f5087552 772 my $max_name = $type
773 ? $max_id_length - (length($type) + 1)
774 : $max_id_length;
96844cae 775 $basename = substr( $basename, 0, $max_name )
776 if length( $basename ) > $max_name;
d529894e 777 my $name = $type ? "${type}_$basename" : $basename;
778
779 if ( $basename ne $basename_orig and $critical ) {
780 my $show_type = $type ? "+'$type'" : "";
781 warn "Truncating '$basename_orig'$show_type to $max_id_length ",
96844cae 782 "character limit to make '$name'\n" if $WARN;
783 $truncated{ $basename_orig } = $name;
d529894e 784 }
785
786 $scope ||= \%global_names;
96844cae 787 if ( my $prev = $scope->{ $name } ) {
788 my $name_orig = $name;
b89d5635 789 substr($name, $max_id_length - 2) = ""
790 if length( $name ) >= $max_id_length - 1;
791 $name .= sprintf( "%02d", $prev++ );
96844cae 792
793 warn "The name '$name_orig' has been changed to ",
794 "'$name' to make it unique.\n" if $WARN;
795
796 $scope->{ $name_orig }++;
797 }
798
799 $scope->{ $name }++;
d529894e 800 return $name;
801}
802
38b019a3 8031;
d529894e 804
38b019a3 805# -------------------------------------------------------------------
806sub quote {
807 my ($name, $q) = @_;
7769504d 808 $q && $name ? "$quote_char$name$quote_char" : $name;
d529894e 809}
810
16dc9970 811
d529894e 812# -------------------------------------------------------------------
16dc9970 813# All bad art is the result of good intentions.
814# Oscar Wilde
d529894e 815# -------------------------------------------------------------------
16dc9970 816
ba096dc4 817=pod
16dc9970 818
d529894e 819=head1 CREDITS
820
ba096dc4 821Mad props to Tim Bunce for much of the logic stolen from his "mysql2ora"
822script.
16dc9970 823
42ef836a 824=head1 AUTHORS
16dc9970 825
42ef836a 826Ken Youens-Clark E<lt>kclark@cpan.orgE<gt>,
38b019a3 827Alexander Hartmaier E<lt>abraxxa@cpan.orgE<gt>,
828Fabien Wernli E<lt>faxmodem@cpan.orgE<gt>.
16dc9970 829
830=head1 SEE ALSO
831
ba096dc4 832SQL::Translator, DDL::Oracle, mysql2ora.
16dc9970 833
834=cut