diff --git a/.gitignore b/.gitignore index 915cedcc..4782f03c 100644 --- a/.gitignore +++ b/.gitignore @@ -20,3 +20,4 @@ share/PrecompiledParsers/Parse/RecDescent/DDL/SQLT/*.pm *~ .#* *# +t/00* diff --git a/lib/SQL/Translator/Producer/NuoDB.pm b/lib/SQL/Translator/Producer/NuoDB.pm new file mode 100644 index 00000000..54e27618 --- /dev/null +++ b/lib/SQL/Translator/Producer/NuoDB.pm @@ -0,0 +1,339 @@ +package SQL::Translator::Producer::NuoDB; +# Started with lib/SQL/Translator/Producer/DB2.pm since it created a vastly correct DDL without modification +=head1 NAME + +SQL::Translator::Producer::NuoDB - NuoDB SQL producer + +=head1 SYNOPSIS + + use SQL::Translator; + + my $t = SQL::Translator->new( parser => '...', producer => 'NuoDB' ); + print $translator->translate( $file ); + +=head1 DESCRIPTION + +Creates an SQL DDL suitable for NuoDB. + +=cut + +use warnings; +use strict; +use warnings; +our ( $DEBUG, $WARN ); +our $VERSION = '1.59'; +$DEBUG = 0 unless defined $DEBUG; + +use SQL::Translator::Schema::Constants; +use SQL::Translator::Utils qw(header_comment); + +my %dt_translate; +BEGIN { + %dt_translate = ( + int => 'INTEGER', + varchar => 'STRING', + text => 'STRING', + interval => 'INTEGER', + bytea => 'BINARY', + inet => 'STRING', +); +} + +my %nuodb_reserved = map { $_ => 1} qw/ +ALL AS BETWEEN BITS +BOTH BREAK BY CALL +CASCADE CASE CATCH COLLATE +COLUMN CONSTRAINT CONTAINING CONTINUE +CREATE CURRENT CURRENT_DATE CURRENT_TIME +CURRENT_TIMESTAMP DEFAULT DELETE DESCRIBE +DISTINCT ELSE END END_FOR +END_FUNCTION END_IF END_PROCEDURE END_TRIGGER +END_TRY END_WHILE ENUM ESCAPE +EXECUTE EXISTS FALSE FETCH +FOR FOREIGN FOR_UPDATE FROM +FULL GENERATED GROUP HAVING +IDENTITY IF IN INNER +INOUT INSERT INTO IS +JOIN KEY LEADING LEFT +LIKE LIMIT LOGICAL_AND LOGICAL_NOT +LOGICAL_OR MAX MAXVALUE MIN +NATIONAL NATURAL NCHAR NCLOB +NEXT NEXT_VALUE NOT_BETWEEN NOT_CONTAINING +NOT_IN NOT_LIKE NOT_STARTING NTEXT +NULL NUMERIC NVARCHAR OCTETS +OFF OFFSET ON ONLY +ORDER OUT PRIMARY REAL +RECORD_BATCHING REFERENCES REGEXP RESTART +RESTRICT RETURN RIGHT ROLLBACK +ROWS SELECT SET SHOW +SMALLDATETIME SMALLINT STARTING STRING_TYPE +THEN THROW TINYBLOB TINYINT +TO TRAILING TRUE TRY +UNION UNIQUE UNKNOWN UPDATE +USING VAR VER WHEN +WHERE WHILE WITH +ABS ACOS ASIN ATAN2 +ATAN BIT_LENGTH CAST CEILING +CHARACTER_LENGTH COALESCE CONCAT CONVERT_TZ +COS COT CURRENT_USER DATE +DATE_ADD DATE_SUB DAYOFWEEK DAY +DEGREES EXTRACT FLOOR GREATEST +HOUR IFNULL LEAST LOCATE +LOWER LTRIM MINUTE MOD +MONTH MSLEEP NOW NULLIF +OCTET_LENGTH OPTIONAL_FIELD PI POSITION +POWER RADIANS RAND REPLACE +ROUND RTRIM SECOND SIN +SQRT SUBSTRING_INDEX SUBSTR TAN +TRIM UPPER USER YEAR +STRING SCHEMA PART LOCK +PATH GET +/; + +sub produce +{ + my ($translator) = @_; + $DEBUG = $translator->debug; + $WARN = $translator->show_warnings; + my $no_comments = $translator->no_comments; + my $add_drop_table = $translator->add_drop_table; + my $schema = $translator->schema; + my $output = ''; + my $indent = ' '; + + $output .= header_comment unless($no_comments); + my (@table_defs, @fks, @index_defs); + foreach my $table ($schema->get_tables) + { + push @table_defs, 'DROP TABLE ' . $table->name . ";" if $add_drop_table; + my ($table_def, $fks) = create_table($table, { + no_comments => $no_comments}); + push @table_defs, $table_def; + push @fks, @$fks; + + foreach my $index ($table->get_indices) + { + push @index_defs, create_index($index); + } + + } + my (@view_defs); + foreach my $view ( $schema->get_views ) + { + push @view_defs, create_view($view); + } + my (@trigger_defs); + foreach my $trigger ( $schema->get_triggers ) + { + push @trigger_defs, create_trigger($trigger); + } + + return wantarray ? (@table_defs, @fks, @index_defs, @view_defs, @trigger_defs) : + $output . join("\n\n", @table_defs, @fks, @index_defs, @view_defs, @trigger_defs) . "\n\n"; +} + +{ my %objnames; + + sub check_name + { + my ($name, $type, $length) = @_; + + my $newname = $name; + if(length($name) > $length) ## Maximum table name length is 18 + { + warn "Table name $name is longer than $length characters, truncated" if $WARN; + } + + if($nuodb_reserved{uc($newname)}) + { + warn "$newname is a reserved word in NuoDB!" if $WARN; + $newname = '"'.$newname.'"'; + } + + return $newname; + } +} + +sub create_table +{ + my ($table, $options) = @_; + + my $table_name = check_name($table->name, 'tables', 128); + + my (@field_defs, @comments); + push @comments, "--\n-- Table: $table_name\n--" unless $options->{no_comments}; + foreach my $field ($table->get_fields) + { + push @field_defs, create_field($field); + } + my (@con_defs, @fks); + foreach my $con ($table->get_constraints) + { + my ($cdefs, $fks) = create_constraint($con); + push @con_defs, @$cdefs; + push @fks, @$fks; + } + + my $tablespace = $table->extra()->{'TABLESPACE'} || ''; + my $table_def = "CREATE TABLE $table_name (\n"; + $table_def .= join (",\n", map { " $_" } @field_defs, @con_defs); + $table_def .= "\n)"; + $table_def .= $tablespace ? "IN $tablespace;" : ';'; + + return $table_def, \@fks; +} + +sub create_field +{ + my ($field) = @_; + + my $field_name = check_name($field->name, 'fields', 30); + + my $data_type = uc($dt_translate{lc($field->data_type)} || $field->data_type); + my $size = $field->size(); + + # NuoDB does not support WITHOUT TIME ZONE types + $data_type =~ s/ WITHOUT TIME ZONE//i; + + my $field_def = "$field_name $data_type"; + $field_def .= $field->is_auto_increment ? + ' GENERATED BY DEFAULT AS IDENTITY' : ''; + $field_def .= $data_type =~ /(CHAR|CLOB|NUMERIC|DECIMAL)/i ? "(${size})" : ''; + $field_def .= !$field->is_nullable ? ' NOT NULL':''; + $field_def .= !defined $field->default_value ? '' : + $field->default_value =~ /current( |_)timestamp/i || + $field->default_value =~ /\Qnow()\E/i ? + ' DEFAULT NOW()' : defined $field->default_value ? + (" DEFAULT " . ($data_type =~ /(INT|DOUBLE)/i ? + $field->default_value : "'" . $field->default_value . "'") + ) : ''; + + return $field_def; +} + +sub create_index +{ + my ($index) = @_; + + my @fields; + # check each field name + for ($index->fields) { + push @fields, check_name($_, 'fields', 30); + } + + my $out = sprintf('CREATE %sINDEX %s ON %s (%s);', + $index->type() =~ /^UNIQUE$/i ? 'UNIQUE ' : '', + $index->name, + $index->table->name, + join(', ', @fields)); + + return $out; +} + +sub create_constraint +{ + my ($constraint) = @_; + + my (@con_defs, @fks); + + my $ctype = $constraint->type =~ /^PRIMARY(_|\s)KEY$/i ? 'PRIMARY KEY' : + $constraint->type =~ /^UNIQUE$/i ? 'UNIQUE' : + $constraint->type =~ /^CHECK_C$/i ? 'CHECK' : + $constraint->type =~ /^FOREIGN(_|\s)KEY$/i ? 'FOREIGN KEY' : ''; + + my $expr = $constraint->type =~ /^CHECK_C$/i ? $constraint->expression : + ''; + my $ref = $constraint->type =~ /^FOREIGN(_|\s)KEY$/i ? ('REFERENCES ' . $constraint->reference_table . '(' . join(', ', $constraint->reference_fields) . ')') : ''; + my $update = $constraint->on_update ? $constraint->on_update : ''; + my $delete = $constraint->on_delete ? $constraint->on_delete : ''; + + my $out = join(' ', grep { $_ } + $ctype, + $constraint->name && $constraint->type ne FOREIGN_KEY ? ('KEY ' . $constraint->name) : '', + '(' . join (', ', check_name($constraint->fields, 'fields', 30)) . ')', + $expr ? $expr : $ref, + $update, + $delete); + + if ($constraint->type eq FOREIGN_KEY) { + my $table_name = $constraint->table->name; + + $out = join(' ', + 'ALTER TABLE', + $table_name, + $constraint->name ? ('ADD CONSTRAINT ' . $constraint->name) : 'ADD', + ($out . ';'), + ); + + push @fks, $out; + } + else { + push @con_defs, $out; + } + + return \@con_defs, \@fks; + +} + +sub create_view +{ + my ($view) = @_; + + my $out = sprintf("CREATE VIEW %s AS\n%s;", + $view->name, + $view->sql); + + return $out; +} + +sub create_trigger +{ + my ($trigger) = @_; + + my $db_events = join ', ', $trigger->database_events; + my $out = sprintf("DROP TRIGGER IF EXISTS %s;\nSET DELIMITER @\nCREATE TRIGGER %s FOR %s %s %s AS\n %s\nEND_TRIGGER@\nSET DELIMITER ;", + $trigger->name, + $trigger->name, + $trigger->table->name, + uc($trigger->perform_action_when) || 'AFTER', + uc($db_events) || 'UPDATE', + $trigger->action ); + + return $out; + +} + +sub alter_field +{ + my ($from_field, $to_field) = @_; + + my $data_type = uc($dt_translate{lc($to_field->data_type)} || $to_field->data_type); + + my $size = $to_field->size(); + $data_type .= $data_type =~ /CHAR/i ? "(${size})" : ''; + + my $out = sprintf('ALTER TABLE %s ALTER %s SET DATATYPE %s', + $to_field->table->name, + $to_field->name, + $data_type); + +} + +sub add_field +{ + my ($new_field) = @_; + + my $out = sprintf('ALTER TABLE %s ADD COLUMN %s', + $new_field->table->name, + create_field($new_field)); + + return $out; +} + +sub drop_field +{ + my ($field) = @_; + + return ''; +} +1; diff --git a/t/65xml-to-nuodb-types.t b/t/65xml-to-nuodb-types.t new file mode 100644 index 00000000..f8f1798d --- /dev/null +++ b/t/65xml-to-nuodb-types.t @@ -0,0 +1,282 @@ +#!/usr/bin/perl +# vim: set ft=perl: +# Started with 56-sqlite-producer.t +use strict; +use Test::More; +use Test::SQL::Translator qw(maybe_plan); +use SQL::Translator::Schema; +use SQL::Translator::Schema::View; +use SQL::Translator::Schema::Table; +use SQL::Translator::Schema::Constants; +use SQL::Translator::Producer::NuoDB; + +{ + my $table = SQL::Translator::Schema::Table->new( + name => 'foo_table', + ); + $table->add_field( + name => 'id', + data_type => 'int', + default_value => 1, + ); + my $expected = "CREATE TABLE foo_table (\n id INTEGER DEFAULT 1\n);"; + my @result = SQL::Translator::Producer::NuoDB::create_table($table); + is_deeply(@result[0], $expected, 'simple table'); +} + +# varchar +{ + my $table = SQL::Translator::Schema::Table->new( + name => 'foo_table', + ); + $table->add_field( + name => 'f', + data_type => 'varchar', + ); + my $expected = "CREATE TABLE foo_table (\n f STRING\n);"; + my @result = SQL::Translator::Producer::NuoDB::create_table($table); + is_deeply(@result[0], $expected, 'varchar to string'); +} + +# text +{ + my $table = SQL::Translator::Schema::Table->new( + name => 'foo_table', + ); + $table->add_field( + name => 'f', + data_type => 'text', + ); + my $expected = "CREATE TABLE foo_table (\n f STRING\n);"; + my @result = SQL::Translator::Producer::NuoDB::create_table($table); + is_deeply(@result[0], $expected, 'text to string'); +} + +# interval +{ + my $table = SQL::Translator::Schema::Table->new( + name => 'foo_table', + ); + $table->add_field( + name => 'i', + data_type => 'interval', + ); + my $expected = "CREATE TABLE foo_table (\n i INTEGER\n);"; + my @result = SQL::Translator::Producer::NuoDB::create_table($table); + is_deeply(@result[0], $expected, 'interval to integer'); +} + +# bytea +{ + my $table = SQL::Translator::Schema::Table->new( + name => 'foo_table', + ); + $table->add_field( + name => 'b', + data_type => 'bytea', + ); + my $expected = "CREATE TABLE foo_table (\n b BINARY\n);"; + my @result = SQL::Translator::Producer::NuoDB::create_table($table); + is_deeply(@result[0], $expected, 'bytea to binary'); +} + +# inet +{ + my $table = SQL::Translator::Schema::Table->new( + name => 'foo_table', + ); + $table->add_field( + name => 'ip', + data_type => 'inet', + ); + my $expected = "CREATE TABLE foo_table (\n ip STRING\n);"; + my @result = SQL::Translator::Producer::NuoDB::create_table($table); + is_deeply(@result[0], $expected, 'inet to string'); +} + + +# default NOW() +{ + my $table = SQL::Translator::Schema::Table->new( + name => 'foo_table', + ); + $table->add_field( + name => 'c', + data_type => 'timestamp', + is_nullable => 0, + default_value => 'NOW()', + ); + my $expected = "CREATE TABLE foo_table (\n c TIMESTAMP NOT NULL DEFAULT NOW()\n);"; + my @result = SQL::Translator::Producer::NuoDB::create_table($table); + is_deeply(@result[0], $expected, 'NOW() stays NOW()'); +} + +# without time zone +{ + my $table = SQL::Translator::Schema::Table->new( + name => 'foo_table', + ); + $table->add_field( + name => 'c', + data_type => 'timestamp WITHOUT TIME ZONE', + is_nullable => 1, + ); + my $expected = "CREATE TABLE foo_table (\n c TIMESTAMP\n);"; + my @result = SQL::Translator::Producer::NuoDB::create_table($table); + is_deeply(@result[0], $expected, 'Ignore WITHOUT TIME ZONE'); +} + + +# reserved word field +{ + my $table = SQL::Translator::Schema::Table->new( + name => 'foo_table', + ); + $table->add_field( + name => 'set', + data_type => 'integer', + ); + $table->add_field( + name => 'string', + data_type => 'integer', + ); + $table->add_field( + name => 'schema', + data_type => 'integer', + ); + $table->add_field( + name => 'part', + data_type => 'integer', + ); + $table->add_field( + name => 'lock', + data_type => 'integer', + ); + $table->add_field( + name => 'path', + data_type => 'integer', + ); + $table->add_field( + name => 'get', + data_type => 'integer', + ); + my $expected = "CREATE TABLE foo_table (\n \"set\" INTEGER,\n \"string\" INTEGER,\n \"schema\" INTEGER,\n \"part\" INTEGER,\n \"lock\" INTEGER,\n \"path\" INTEGER,\n \"get\" INTEGER\n);"; + my @result = SQL::Translator::Producer::NuoDB::create_table($table); + is_deeply(@result[0], $expected, 'reserved word field'); +} + +# reserved word field used in constraint +{ + my $table = SQL::Translator::Schema::Table->new( + name => 'foo_table', + ); + + my $fk_constraint = SQL::Translator::Schema::Constraint->new( + table => $table, + name => 'foo_table_string', + type => FOREIGN_KEY, + fields => 'string', + reference_table => 'area', + reference_fields => 'id', + ); + + my $expected = "ALTER TABLE foo_table ADD CONSTRAINT foo_table_string FOREIGN KEY (\"string\") REFERENCES area(id);"; + my ($result, $result_fk) = SQL::Translator::Producer::NuoDB::create_constraint($fk_constraint); + is($result_fk->[0], $expected, 'reserved word field in constraint'); +} + +# reserved word field used in index +{ + my $table = SQL::Translator::Schema::Table->new( + name => 'foo_table', + fields => [qw(string,set)], + ); + + my $index = $table->add_index(name => 'myindex', fields => ['string,set']); + my ($def) = SQL::Translator::Producer::NuoDB::create_index($index); + is($def, 'CREATE INDEX myindex ON foo_table ("string", "set");', 'reserved word field index'); +} + +# primary key +{ + my $table = SQL::Translator::Schema::Table->new( + name => 'foo_table', + ); + $table->add_field( + name => 'code', + data_type => 'integer', + is_nullable => 0, + is_primary_key => 1 + ); + $table->add_constraint( + fields => 'code', + type => PRIMARY_KEY, + ); + my $expected = "CREATE TABLE foo_table (\n code INTEGER NOT NULL,\n PRIMARY KEY (code)\n);"; + my @result = SQL::Translator::Producer::NuoDB::create_table($table); + is_deeply(@result[0], $expected, 'simple table'); +} + +# constraint name +{ + my $table = SQL::Translator::Schema::Table->new( + name => 'foo_table', + ); + + my $fk_constraint = SQL::Translator::Schema::Constraint->new( + table => $table, + name => 'foo_table_code', + type => FOREIGN_KEY, + fields => 'code', + reference_table => 'area', + reference_fields => 'id', + ); + + my $expected = "ALTER TABLE foo_table ADD CONSTRAINT foo_table_code FOREIGN KEY (code) REFERENCES area(id);"; + my ($result, $result_fk) = SQL::Translator::Producer::NuoDB::create_constraint($fk_constraint); + is($result_fk->[0], $expected, 'named foreign constraint'); +} + +# int identity +{ + my $table = SQL::Translator::Schema::Table->new( + name => 'foo_table', + ); + $table->add_field( + name => 'id', + data_type => 'integer', + is_auto_increment => 1, + is_nullable => 0, + is_primary_key => 1 + ); + $table->add_constraint( + fields => 'id', + type => PRIMARY_KEY, + ); + my $expected = "CREATE TABLE foo_table (\n id INTEGER GENERATED BY DEFAULT AS IDENTITY NOT NULL,\n PRIMARY KEY (id)\n);"; + my @result = SQL::Translator::Producer::NuoDB::create_table($table); + is_deeply(@result[0], $expected, 'int identity'); +} + +# bigint identity +{ + my $table = SQL::Translator::Schema::Table->new( + name => 'foo_table', + ); + $table->add_field( + name => 'id', + data_type => 'bigint', + is_auto_increment => 1, + is_nullable => 0, + is_primary_key => 1 + ); + $table->add_constraint( + fields => 'id', + type => PRIMARY_KEY, + ); + my $expected = "CREATE TABLE foo_table (\n id BIGINT GENERATED BY DEFAULT AS IDENTITY NOT NULL,\n PRIMARY KEY (id)\n);"; + my @result = SQL::Translator::Producer::NuoDB::create_table($table); + is_deeply(@result[0], $expected, 'bitint identity'); +} + +done_testing; diff --git a/t/65xml-to-nuodb.t b/t/65xml-to-nuodb.t new file mode 100644 index 00000000..3b2381fd --- /dev/null +++ b/t/65xml-to-nuodb.t @@ -0,0 +1,90 @@ +#!/usr/bin/perl +#Started with t/64xml-to-mysql.t +use strict; + +use FindBin qw/$Bin/; +use Test::More; +use Test::SQL::Translator; +use Test::Exception; +use Test::Differences; +#use Data::Dumper; +use SQL::Translator; +use SQL::Translator::Schema::Constants; + + +BEGIN { + maybe_plan(2, 'SQL::Translator::Parser::XML::SQLFairy', + 'SQL::Translator::Producer::NuoDB'); +} + +my $xmlfile = "$Bin/data/xml/schema.xml"; + +my $sqlt; +$sqlt = SQL::Translator->new( + no_comments => 1, + show_warnings => 0, + add_drop_table => 1, + producer_args => { + nuodb_version => 0, + }, +); + +die "Can't find test schema $xmlfile" unless -e $xmlfile; + +my @want = ( + q[DROP TABLE Basic;], + q[CREATE TABLE Basic ( + id INTEGER GENERATED BY DEFAULT AS IDENTITY NOT NULL, + title STRING NOT NULL DEFAULT 'hello', + description STRING DEFAULT '', + email STRING, + explicitnulldef STRING, + explicitemptystring STRING DEFAULT '', + emptytagdef STRING DEFAULT '', + another_id INTEGER DEFAULT 2, + timest TIMESTAMP, + PRIMARY KEY (id), + UNIQUE KEY emailuniqueindex (email), + UNIQUE KEY very_long_index_name_on_title_field_which_should_be_truncated_for_various_rdbms (title) +);], + + q[DROP TABLE Another;], + q[CREATE TABLE Another ( + id INTEGER GENERATED BY DEFAULT AS IDENTITY NOT NULL, + num NUMERIC(10,2), + PRIMARY KEY (id) +);], + q[ALTER TABLE Basic ADD FOREIGN KEY (another_id) REFERENCES Another(id);], + q[CREATE INDEX titleindex ON Basic (title);], + q[CREATE VIEW email_list AS +SELECT email FROM Basic WHERE (email IS NOT NULL);], + q[DROP TRIGGER IF EXISTS foo_trigger; +SET DELIMITER @ +CREATE TRIGGER foo_trigger FOR Basic AFTER INSERT AS + update modified=timestamp(); +END_TRIGGER@ +SET DELIMITER ;], + + q[DROP TRIGGER IF EXISTS bar_trigger; +SET DELIMITER @ +CREATE TRIGGER bar_trigger FOR Basic BEFORE INSERT, UPDATE AS + update modified2=timestamp(); +END_TRIGGER@ +SET DELIMITER ;] +); + +my $sql = $sqlt->translate( + from => 'XML-SQLFairy', + to => 'NuoDB', + filename => $xmlfile, +) or die $sqlt->error; + +eq_or_diff($sql, join("", map { "$_\n\n" } @want)); + +my @sql = $sqlt->translate( + from => 'XML-SQLFairy', + to => 'NuoDB', + filename => $xmlfile, +) or die $sqlt->error; + +is_deeply(\@sql, \@want);