From: Arthur Axel 'fREW' Schmidt Date: Sat, 12 May 2012 05:12:23 +0000 (-0500) Subject: Beginning of actually tested SQL Server diff X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=commitdiff_plain;h=2402c3ea10ed2b43e32f90751bd4eef1e2108693;p=dbsrgits%2FSQL-Translator.git Beginning of actually tested SQL Server diff Much thanks goes to Michael Conrad who did the groundwork for most of this --- diff --git a/lib/SQL/Translator/Producer/SQLServer.pm b/lib/SQL/Translator/Producer/SQLServer.pm index c1181ca..2aa7b72 100644 --- a/lib/SQL/Translator/Producer/SQLServer.pm +++ b/lib/SQL/Translator/Producer/SQLServer.pm @@ -18,6 +18,146 @@ sub produce { )->schema($translator->schema) } +sub rename_table { + my ($old, $new) = @_;; + + q(sp_rename ') . $old->name . q(', ') . $new->name . q(') +} + +sub alter_drop_constraint { + my ($constraint, $options) = @_; + my $table_name_q= $constraint->table->name; + my $ct_name_q= $constraint->name; + return "ALTER TABLE $table_name_q DROP CONSTRAINT $ct_name_q;"; +} + +sub alter_drop_index { + my ($index, $options) = @_; + my $table_name_q= $index->table->name; + my $index_name_q= $index->name; + return "ALTER TABLE $table_name_q DROP $index_name_q"; +} + +sub alter_field { + my ($from_field, $to_field, $options) = @_; + + my $field_clause= build_field_clause($to_field, $options); + my $table_name_q= $to_field->table->name; + + my @sql; + if (lc($from_field->data_type) eq 'enum') { + push @sql, build_drop_enum_constraint($from_field, $options).';'; + } + + push @sql, "ALTER TABLE $table_name_q ALTER COLUMN $field_clause;"; + + if ($from_field->name ne $to_field->name) { + push @sql, rename_field(@_); + } + + if (lc($to_field->data_type) eq 'enum') { + push @sql, build_add_enum_constraint($to_field, $options).';'; + } + + return join("\n", @sql); +} + +sub rename_field { + 'lol' +} + +sub alter_create_index { + my ($index, $options) = @_; + my ($stmt, $clause)= build_index_stmt(@_); + return $stmt.';'; +} + +sub build_index_stmt { + my ($index, $options)= @_; + my $table_name_q = $index->table->name; + my $idx_name_q = $index->name; + my $field_list = join(', ', $index->fields ); + + my $stmt= "CREATE UNIQUE NONCLUSTERED INDEX $idx_name_q" . + " ON $table_name_q ($field_list)"; + return $stmt, undef; +} + +sub build_constraint_stmt { + my $c = shift; + + if ($c->type eq PRIMARY_KEY ) { + return SQL::Translator::Generator::DDL::SQLServer->new->primary_key_constraint($c) + } elsif ($c->type eq UNIQUE ) { + return SQL::Translator::Generator::DDL::SQLServer->new->unique_constraint_single($c) + } +} + +sub drop_table { 'DROP TABLE ' . $_[0]->name } + +sub alter_create_constraint { + my ($constraint, $options) = @_; + my ($stmt, $clause)= build_constraint_stmt(@_); + return $stmt.';'; +} + +sub build_enum_constraint { + my ($field, $options)= @_; + my %extra = $field->extra; + my $list = $extra{'list'} || []; + # \todo deal with embedded quotes + my $commalist = join( ', ', map { qq['$_'] } @$list ); + my $field_name_q = $field->name; + my $check_name_q = $field->table->name . '_' . $field->name . '_chk'; + return "CONSTRAINT $check_name_q CHECK ($field_name_q IN ($commalist))"; +} +sub build_drop_enum_constraint { + my ($field, $options)= @_; + my $table_name_q = $field->table->name; + my $check_name_q = $field->table->name . '_' . $field->name . '_chk'; + return "ALTER TABLE $table_name_q DROP $check_name_q"; +} + +sub build_add_enum_constraint { + my ($field, $options)= @_; + my $table_name_q = $field->table->name; + return "ALTER TABLE $table_name_q ADD ".build_enum_constraint(@_); +} + +sub build_field_clause { + SQL::Translator::Generator::DDL::SQLServer->new->field(shift) +} + +sub add_field { + my ($new_field, $options) = @_; + + my $field_clause = build_field_clause($new_field); + my $table_name_q= $new_field->table->name; + + my @sql= "ALTER TABLE $table_name_q ADD COLUMN $field_clause;"; + if (lc($new_field->data_type) eq 'enum') { + push @sql, build_add_enum_constraint($new_field, $options).';'; + } + + return join("\n", @sql); +} + +sub drop_field { + my ($old_field, $options) = @_; + + my $table_name_q= $old_field->table->name; + my $field_name_q= $old_field->name; + + my @sql; + if (lc($old_field->data_type) eq 'enum') { + push @sql, build_drop_enum_constraint($old_field, $options).';'; + } + + push @sql, "ALTER TABLE $table_name_q DROP COLUMN $field_name_q;"; + + return join("\n", @sql); +} + 1; =head1 NAME diff --git a/t/zomg.t b/t/zomg.t new file mode 100644 index 0000000..05438dc --- /dev/null +++ b/t/zomg.t @@ -0,0 +1,121 @@ +use strict; +use warnings; + +use Test::More; +use SQL::Translator; +use SQL::Translator::Diff; +use Test::Differences; + +my ($s1, $s2); + +subtest 'schema 1' => sub { + my $translator = SQL::Translator->new( + no_comments => 1, + ); + my $output = $translator->translate( + from => 'YAML', + to => 'SQLServer', + filename => 't/data/diff/pgsql/create1.yml', + ) ."\n"; + $s1 = $translator->schema; + + my $expected = <<'SQL'; +CREATE TABLE [person] ( + [person_id] int NOT NULL, + [name] varchar(20) NULL, + [age] int NULL, + [weight] numeric(11,2) NULL, + [iq] smallint NULL DEFAULT '0', + [description] text NULL, + CONSTRAINT [person_pk] PRIMARY KEY ([person_id]) +); + +CREATE UNIQUE NONCLUSTERED INDEX [UC_age_name] ON [person] (age) WHERE [age] IS NOT NULL; + +CREATE INDEX [u_name] ON [person] ([name]); + +CREATE TABLE [employee] ( + [position] varchar(50) NOT NULL, + [employee_id] int NOT NULL, + [job_title] varchar(255) NULL, + CONSTRAINT [employee_pk] PRIMARY KEY ([position], [employee_id]) +); + +CREATE TABLE [deleted] ( + [id] int NULL +); + +CREATE UNIQUE NONCLUSTERED INDEX [pk_id] ON [deleted] (id) WHERE [id] IS NOT NULL; + +CREATE TABLE [old_name] ( + [pk] int IDENTITY NOT NULL, + CONSTRAINT [old_name_pk] PRIMARY KEY ([pk]) +); +ALTER TABLE [employee] ADD CONSTRAINT [FK5302D47D93FE702E] FOREIGN KEY ([employee_id]) REFERENCES [person] ([person_id]); +ALTER TABLE [deleted] ADD CONSTRAINT [fk_fake] FOREIGN KEY ([id]) REFERENCES [fake] ([fk_id]); +SQL + + eq_or_diff($output, $expected, 'initial "DDL" converted correctly'); +}; + +subtest 'schema 2' => sub { + my $translator = SQL::Translator->new( + no_comments => 1, + ); + my $output = $translator->translate( + from => 'YAML', + to => 'SQLServer', + filename => 't/data/diff/pgsql/create2.yml', + ) ."\n"; + $s2 = $translator->schema; + + my $expected = <<'SQL'; +CREATE TABLE [person] ( + [person_id] int IDENTITY NOT NULL, + [name] varchar(20) NOT NULL, + [age] int NULL DEFAULT 18, + [weight] numeric(11,2) NULL, + [iq] int NULL DEFAULT 0, + [is_rock_star] smallint NULL DEFAULT '1', + [physical_description] text NULL, + CONSTRAINT [person_pk] PRIMARY KEY ([person_id]), + CONSTRAINT [UC_person_id] UNIQUE ([person_id]) +); + +CREATE UNIQUE NONCLUSTERED INDEX [UC_age_name] ON [person] (age, name) WHERE [age] IS NOT NULL; + +CREATE INDEX [unique_name] ON [person] ([name]); + +CREATE TABLE [employee] ( + [position] varchar(50) NOT NULL, + [employee_id] int NOT NULL, + CONSTRAINT [employee_pk] PRIMARY KEY ([position], [employee_id]) +); + +CREATE TABLE [added] ( + [id] int NULL +); + +CREATE TABLE [new_name] ( + [pk] int IDENTITY NOT NULL, + [new_field] int NULL, + CONSTRAINT [new_name_pk] PRIMARY KEY ([pk]) +); +ALTER TABLE [employee] ADD CONSTRAINT [FK5302D47D93FE702E_diff] FOREIGN KEY ([employee_id]) REFERENCES [person] ([person_id]); +SQL + + eq_or_diff($output, $expected, 'initial "DDL" converted correctly'); +}; + +subtest 'sql server diff' => sub { + my @out = SQL::Translator::Diff::schema_diff( + $s1, 'SQLServer', + $s2, 'SQLServer', + ); + + use Devel::Dwarn; + Dwarn \@out; +}; + + +done_testing;