From: Jess Robinson Date: Tue, 29 Jan 2008 13:41:23 +0000 (+0000) Subject: Update oracle producer, patch from plu. X-Git-Tag: v0.11008~347 X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=commitdiff_plain;h=e56dabb75c0079e5790cbcd893aa124b540d60cc;p=dbsrgits%2FSQL-Translator.git Update oracle producer, patch from plu. Update postgres producer, patch from wreis --- diff --git a/META.yml b/META.yml index 48dcb35..06f6236 100644 --- a/META.yml +++ b/META.yml @@ -236,7 +236,7 @@ provides: Test::SQL::Translator: file: lib/Test/SQL/Translator.pm version: 1.08 -generated_by: Module::Build version 0.2808 +generated_by: Module::Build version 0.28 meta-spec: url: http://module-build.sourceforge.net/META-spec-v1.2.html version: 1.2 diff --git a/lib/SQL/Translator/Producer/Oracle.pm b/lib/SQL/Translator/Producer/Oracle.pm index 45c379d..8986ef3 100644 --- a/lib/SQL/Translator/Producer/Oracle.pm +++ b/lib/SQL/Translator/Producer/Oracle.pm @@ -150,35 +150,58 @@ my %truncated; sub produce { my $translator = shift; $DEBUG = $translator->debug; - $WARN = $translator->show_warnings; + $WARN = $translator->show_warnings || 0; my $no_comments = $translator->no_comments; my $add_drop_table = $translator->add_drop_table; my $schema = $translator->schema; - my $output; + my ($output, $create, @table_defs, @fk_defs, @trigger_defs); - $output .= header_comment unless ($no_comments); + $create .= header_comment unless ($no_comments); if ( $translator->parser_type =~ /mysql/i ) { - $output .= + $create .= "-- We assume that default NLS_DATE_FORMAT has been changed\n". "-- but we set it here anyway to be self-consistent.\n" unless $no_comments; - $output .= + $create .= "ALTER SESSION SET NLS_DATE_FORMAT = 'YYYY-MM-DD HH24:MI:SS';\n\n"; } - # - # Print create for each table - # for my $table ( $schema->get_tables ) { - my $table_name = $table->name or next; - $table_name = mk_name( $table_name, '', undef, 1 ); - my $table_name_ur = unreserve($table_name) or next; + my ( $table_def, $fk_def, $trigger_def ) = create_table( + $table, + { + add_drop_table => $add_drop_table, + show_warnings => $WARN, + no_comments => $no_comments, + } + ); + push @table_defs, @$table_def; + push @fk_defs, @$fk_def; + push @trigger_defs, @$trigger_def; + } + + my (@view_defs); + foreach my $view ( $schema->get_views ) { + push @view_defs, create_view($view); + } + + return wantarray ? (defined $create ? $create : (), @table_defs, @view_defs, @fk_defs, @trigger_defs) : $create . join ("\n\n", @table_defs, @view_defs, @fk_defs, @trigger_defs); +} + +sub create_table { + my ($table, $options) = @_; + my $table_name = $table->name; + + my $item = ''; + my $drop; + my (@create, @field_defs, @constraint_defs, @fk_defs, @trigger_defs); - my ( @comments, @field_defs, @trigger_defs, @constraint_defs ); + push @create, "--\n-- Table: $table_name\n--" unless $options->{no_comments}; + push @create, qq[DROP TABLE $table_name CASCADE CONSTRAINTS;] if $options->{add_drop_table}; - push @comments, "--\n-- Table: $table_name_ur\n--" unless $no_comments; + my $table_name_ur = unreserve($table_name) or next; my ( %field_name_scope, @field_comments ); for my $field ( $table->get_fields ) { @@ -237,8 +260,6 @@ sub produce { if $WARN; } - - # # Fixes ORA-00907: missing right parenthesis # @@ -310,8 +331,9 @@ sub produce { my $seq_name = mk_name( $base_name, 'sq' ); my $trigger_name = mk_name( $base_name, 'ai' ); + push @create, qq[DROP SEQUENCE $seq_name;] if $options->{add_drop_table}; + push @create, "CREATE SEQUENCE $seq_name;"; push @trigger_defs, - "CREATE SEQUENCE $seq_name;\n" . "CREATE OR REPLACE TRIGGER $trigger_name\n" . "BEFORE INSERT ON $table_name_ur\n" . "FOR EACH ROW WHEN (\n" . @@ -344,7 +366,7 @@ sub produce { $comment =~ s/'/''/g; push @field_comments, "COMMENT ON COLUMN $table_name_ur.$field_name_ur is\n '" . - $comment . "';" unless $no_comments; + $comment . "';" unless $options->{no_comments}; } } @@ -415,7 +437,7 @@ sub produce { push @constraint_defs, "CONSTRAINT $name CHECK ($expression)"; } elsif ( $c->type eq FOREIGN_KEY ) { - $name ||= mk_name( join('_', $table_name, $c->fields), 'fk' ); + $name = mk_name( join('_', $table_name, $c->fields). '_fk' ); my $def = "CONSTRAINT $name FOREIGN KEY "; if ( @fields ) { @@ -439,11 +461,12 @@ sub produce { $def .= ' ON DELETE '.join( ' ', $c->on_delete ); } - if ( $c->on_update ) { - $def .= ' ON UPDATE '.join( ' ', $c->on_update ); - } + # disabled by plu 2007-12-29 - doesn't exist for oracle + #if ( $c->on_update ) { + # $def .= ' ON UPDATE '.join( ' ', $c->on_update ); + #} - push @constraint_defs, $def; + push @fk_defs, sprintf("ALTER TABLE %s ADD %s;", $table, $def); } } @@ -478,35 +501,21 @@ sub produce { } } - my $create_statement; - $create_statement = "DROP TABLE $table_name_ur;\n" if $add_drop_table; - if ( my @table_comments = $table->comments ) { for my $comment ( @table_comments ) { next unless $comment; $comment =~ s/'/''/g; push @field_comments, "COMMENT ON TABLE $table_name_ur is\n '". - $comment . "';" unless $no_comments + $comment . "';" unless $options->{no_comments} ; } } my $table_options = @table_options ? "\n".join("\n", @table_options) : ''; - $create_statement .= "CREATE TABLE $table_name_ur (\n" . + push @create, "CREATE TABLE $table_name_ur (\n" . join( ",\n", map { " $_" } @field_defs, @constraint_defs ) . - "\n)$table_options;" - ; - - $output .= join( "\n\n", - @comments, - $create_statement, - @trigger_defs, - @index_defs, - @field_comments, - '' - ); - } + "\n)$table_options;"; if ( $WARN ) { if ( %truncated ) { @@ -521,7 +530,17 @@ sub produce { } } - return $output; + return \@create, \@fk_defs, \@trigger_defs; +} + +sub create_view { + my ($view) = @_; + + my $out = sprintf("CREATE VIEW %s AS\n%s;", + $view->name, + $view->sql); + + return $out; } # ------------------------------------------------------------------- diff --git a/lib/SQL/Translator/Producer/PostgreSQL.pm b/lib/SQL/Translator/Producer/PostgreSQL.pm index d4415ab..9647357 100644 --- a/lib/SQL/Translator/Producer/PostgreSQL.pm +++ b/lib/SQL/Translator/Producer/PostgreSQL.pm @@ -77,7 +77,7 @@ BEGIN { set => 'character varying', date => 'date', datetime => 'timestamp', - time => 'date', + time => 'time', timestamp => 'timestamp', year => 'date', @@ -631,12 +631,15 @@ sub convert_datatype $data_type = 'integer'; } } + my @type_without_size = qw/bigint boolean box bytea cidr circle date inet + integer smallint text line lseg macaddr money + path point polygon real/; + foreach (@type_without_size) { + if ( $data_type =~ qr/$_/ ) { + undef @size; last; + } + } - # - # PG doesn't need a size for integers or text - # - undef @size if $data_type =~ m/(integer|smallint|bigint|text)/; - if ( defined $size[0] && $size[0] > 0 ) { $data_type .= '(' . join( ',', @size ) . ')'; } diff --git a/t/47postgres-producer.t b/t/47postgres-producer.t index c96b5e2..9c0590d 100644 --- a/t/47postgres-producer.t +++ b/t/47postgres-producer.t @@ -14,7 +14,7 @@ use FindBin qw/$Bin/; #============================================================================= BEGIN { - maybe_plan(4, + maybe_plan(6, 'SQL::Translator::Producer::PostgreSQL', 'Test::Differences', ) @@ -64,4 +64,29 @@ is($add_field, 'ALTER TABLE mytable ADD COLUMN field3 character varying(10);', ' my $drop_field = SQL::Translator::Producer::PostgreSQL::drop_field($field2); is($drop_field, 'ALTER TABLE mytable DROP COLUMN myfield;', 'Drop field works'); +my $field3 = SQL::Translator::Schema::Field->new( name => 'time_field', + table => $table, + data_type => 'TIME', + default_value => undef, + is_auto_increment => 0, + is_nullable => 0, + is_foreign_key => 0, + is_unique => 0 ); + +my $field3_sql = SQL::Translator::Producer::PostgreSQL::create_field($field3); + +is($field3_sql, 'time_field time NOT NULL', 'Create time field works'); + +my $field4 = SQL::Translator::Schema::Field->new( name => 'bytea_field', + table => $table, + data_type => 'bytea', + size => '16777215', + default_value => undef, + is_auto_increment => 0, + is_nullable => 0, + is_foreign_key => 0, + is_unique => 0 ); + +my $field4_sql = SQL::Translator::Producer::PostgreSQL::create_field($field4); +is($field4_sql, 'bytea_field bytea NOT NULL', 'Create bytea field works'); diff --git a/t/51-xml-to-oracle.t b/t/51-xml-to-oracle.t new file mode 100644 index 0000000..f44bd0d --- /dev/null +++ b/t/51-xml-to-oracle.t @@ -0,0 +1,330 @@ +#!/usr/bin/perl +use strict; + +use FindBin qw/$Bin/; +use Test::More; +use Test::SQL::Translator; +use Test::Exception; +use Data::Dumper; +use SQL::Translator; +use SQL::Translator::Schema::Constants; + +BEGIN { + maybe_plan(2, 'SQL::Translator::Parser::XML::SQLFairy', + 'SQL::Translator::Producer::Oracle'); +} + +my $xmlfile = "$Bin/data/xml/schema.xml"; + +my $sqlt; +$sqlt = SQL::Translator->new( + no_comments => 1, + show_warnings => 1, + add_drop_table => 1, +); + +die "Can't find test schema $xmlfile" unless -e $xmlfile; + +my @sql = $sqlt->translate( + from => 'XML-SQLFairy', + to => 'Oracle', + filename => $xmlfile, +) or die $sqlt->error; + +my $sql_string = $sqlt->translate( + from => 'XML-SQLFairy', + to => 'Oracle', + filename => $xmlfile, +) or die $sqlt->error; + +my $want = [ +'DROP TABLE Basic CASCADE CONSTRAINTS;', + 'DROP SEQUENCE sq_Basic_id01;', + 'CREATE SEQUENCE sq_Basic_id01;', + 'CREATE TABLE Basic ( + id number(10) NOT NULL, + title varchar2(100) DEFAULT \'hello\' NOT NULL, + description clob DEFAULT \'\', + email varchar2(255), + explicitnulldef varchar2, + explicitemptystring varchar2 DEFAULT \'\', + emptytagdef varchar2 DEFAULT \'\', + another_id number(10) DEFAULT \'2\', + timest date, + PRIMARY KEY (id), + CONSTRAINT emailuniqueindex UNIQUE (email) +);', + 'DROP TABLE Another CASCADE CONSTRAINTS;', + 'DROP SEQUENCE sq_Another_id01;', + 'CREATE SEQUENCE sq_Another_id01;', + 'CREATE TABLE Another ( + id number(10) NOT NULL, + PRIMARY KEY (id) +);', + 'CREATE VIEW email_list AS +SELECT email FROM Basic WHERE email IS NOT NULL;', + 'ALTER TABLE Basic ADD CONSTRAINT Basic_another_id_fk01 FOREIGN KEY (another_id) REFERENCES Another (id);', + 'CREATE OR REPLACE TRIGGER ai_Basic_id01 +BEFORE INSERT ON Basic +FOR EACH ROW WHEN ( + new.id IS NULL OR new.id = 0 +) +BEGIN + SELECT sq_Basic_id01.nextval + INTO :new.id + FROM dual; +END; +/', + 'CREATE OR REPLACE TRIGGER ts_Basic_timest01 +BEFORE INSERT OR UPDATE ON Basic +FOR EACH ROW WHEN (new.timest IS NULL) +BEGIN + SELECT sysdate INTO :new.timest FROM dual; +END; +/', + 'CREATE OR REPLACE TRIGGER ai_Another_id01 +BEFORE INSERT ON Another +FOR EACH ROW WHEN ( + new.id IS NULL OR new.id = 0 +) +BEGIN + SELECT sq_Another_id01.nextval + INTO :new.id + FROM dual; +END; +/']; + +is_deeply(\@sql, $want, 'Got correct Oracle statements in list context'); + +is($sql_string, q|DROP TABLE Basic CASCADE CONSTRAINTS; + +DROP SEQUENCE sq_Basic_id02; + +CREATE SEQUENCE sq_Basic_id02; + +CREATE TABLE Basic ( + id number(10) NOT NULL, + title varchar2(100) DEFAULT 'hello' NOT NULL, + description clob DEFAULT '', + email varchar2(255), + explicitnulldef varchar2, + explicitemptystring varchar2 DEFAULT '', + emptytagdef varchar2 DEFAULT '', + another_id number(10) DEFAULT '2', + timest date, + PRIMARY KEY (id), + CONSTRAINT emailuniqueindex UNIQUE (email) +); + +DROP TABLE Another CASCADE CONSTRAINTS; + +DROP SEQUENCE sq_Another_id02; + +CREATE SEQUENCE sq_Another_id02; + +CREATE TABLE Another ( + id number(10) NOT NULL, + PRIMARY KEY (id) +); + +CREATE VIEW email_list AS +SELECT email FROM Basic WHERE email IS NOT NULL; + +ALTER TABLE Basic ADD CONSTRAINT Basic_another_id_fk02 FOREIGN KEY (another_id) REFERENCES Another (id); + +CREATE OR REPLACE TRIGGER ai_Basic_id02 +BEFORE INSERT ON Basic +FOR EACH ROW WHEN ( + new.id IS NULL OR new.id = 0 +) +BEGIN + SELECT sq_Basic_id02.nextval + INTO :new.id + FROM dual; +END; +/ + +CREATE OR REPLACE TRIGGER ts_Basic_timest02 +BEFORE INSERT OR UPDATE ON Basic +FOR EACH ROW WHEN (new.timest IS NULL) +BEGIN + SELECT sysdate INTO :new.timest FROM dual; +END; +/ + +CREATE OR REPLACE TRIGGER ai_Another_id02 +BEFORE INSERT ON Another +FOR EACH ROW WHEN ( + new.id IS NULL OR new.id = 0 +) +BEGIN + SELECT sq_Another_id02.nextval + INTO :new.id + FROM dual; +END; +/|); +#!/usr/bin/perl +use strict; + +use FindBin qw/$Bin/; +use Test::More; +use Test::SQL::Translator; +use Test::Exception; +use Data::Dumper; +use SQL::Translator; +use SQL::Translator::Schema::Constants; + +BEGIN { + maybe_plan(2, 'SQL::Translator::Parser::XML::SQLFairy', + 'SQL::Translator::Producer::Oracle'); +} + +my $xmlfile = "$Bin/data/xml/schema.xml"; + +my $sqlt; +$sqlt = SQL::Translator->new( + no_comments => 1, + show_warnings => 1, + add_drop_table => 1, +); + +die "Can't find test schema $xmlfile" unless -e $xmlfile; + +my @sql = $sqlt->translate( + from => 'XML-SQLFairy', + to => 'Oracle', + filename => $xmlfile, +) or die $sqlt->error; + +my $sql_string = $sqlt->translate( + from => 'XML-SQLFairy', + to => 'Oracle', + filename => $xmlfile, +) or die $sqlt->error; + +my $want = [ +'DROP TABLE Basic CASCADE CONSTRAINTS;', + 'DROP SEQUENCE sq_Basic_id01;', + 'CREATE SEQUENCE sq_Basic_id01;', + 'CREATE TABLE Basic ( + id number(10) NOT NULL, + title varchar2(100) DEFAULT \'hello\' NOT NULL, + description clob DEFAULT \'\', + email varchar2(255), + explicitnulldef varchar2, + explicitemptystring varchar2 DEFAULT \'\', + emptytagdef varchar2 DEFAULT \'\', + another_id number(10) DEFAULT \'2\', + timest date, + PRIMARY KEY (id), + CONSTRAINT emailuniqueindex UNIQUE (email) +);', + 'DROP TABLE Another CASCADE CONSTRAINTS;', + 'DROP SEQUENCE sq_Another_id01;', + 'CREATE SEQUENCE sq_Another_id01;', + 'CREATE TABLE Another ( + id number(10) NOT NULL, + PRIMARY KEY (id) +);', + 'CREATE VIEW email_list AS +SELECT email FROM Basic WHERE email IS NOT NULL;', + 'ALTER TABLE Basic ADD CONSTRAINT Basic_another_id_fk01 FOREIGN KEY (another_id) REFERENCES Another (id);', + 'CREATE OR REPLACE TRIGGER ai_Basic_id01 +BEFORE INSERT ON Basic +FOR EACH ROW WHEN ( + new.id IS NULL OR new.id = 0 +) +BEGIN + SELECT sq_Basic_id01.nextval + INTO :new.id + FROM dual; +END; +/', + 'CREATE OR REPLACE TRIGGER ts_Basic_timest01 +BEFORE INSERT OR UPDATE ON Basic +FOR EACH ROW WHEN (new.timest IS NULL) +BEGIN + SELECT sysdate INTO :new.timest FROM dual; +END; +/', + 'CREATE OR REPLACE TRIGGER ai_Another_id01 +BEFORE INSERT ON Another +FOR EACH ROW WHEN ( + new.id IS NULL OR new.id = 0 +) +BEGIN + SELECT sq_Another_id01.nextval + INTO :new.id + FROM dual; +END; +/']; + +is_deeply(\@sql, $want, 'Got correct Oracle statements in list context'); + +is($sql_string, q|DROP TABLE Basic CASCADE CONSTRAINTS; + +DROP SEQUENCE sq_Basic_id02; + +CREATE SEQUENCE sq_Basic_id02; + +CREATE TABLE Basic ( + id number(10) NOT NULL, + title varchar2(100) DEFAULT 'hello' NOT NULL, + description clob DEFAULT '', + email varchar2(255), + explicitnulldef varchar2, + explicitemptystring varchar2 DEFAULT '', + emptytagdef varchar2 DEFAULT '', + another_id number(10) DEFAULT '2', + timest date, + PRIMARY KEY (id), + CONSTRAINT emailuniqueindex UNIQUE (email) +); + +DROP TABLE Another CASCADE CONSTRAINTS; + +DROP SEQUENCE sq_Another_id02; + +CREATE SEQUENCE sq_Another_id02; + +CREATE TABLE Another ( + id number(10) NOT NULL, + PRIMARY KEY (id) +); + +CREATE VIEW email_list AS +SELECT email FROM Basic WHERE email IS NOT NULL; + +ALTER TABLE Basic ADD CONSTRAINT Basic_another_id_fk02 FOREIGN KEY (another_id) REFERENCES Another (id); + +CREATE OR REPLACE TRIGGER ai_Basic_id02 +BEFORE INSERT ON Basic +FOR EACH ROW WHEN ( + new.id IS NULL OR new.id = 0 +) +BEGIN + SELECT sq_Basic_id02.nextval + INTO :new.id + FROM dual; +END; +/ + +CREATE OR REPLACE TRIGGER ts_Basic_timest02 +BEFORE INSERT OR UPDATE ON Basic +FOR EACH ROW WHEN (new.timest IS NULL) +BEGIN + SELECT sysdate INTO :new.timest FROM dual; +END; +/ + +CREATE OR REPLACE TRIGGER ai_Another_id02 +BEFORE INSERT ON Another +FOR EACH ROW WHEN ( + new.id IS NULL OR new.id = 0 +) +BEGIN + SELECT sq_Another_id02.nextval + INTO :new.id + FROM dual; +END; +/|);