sub batch_alter_table {
my ($table, $diff_hash, $options) = @_;
+ # InnoDB has an issue with dropping and re-adding a FK constraint under the
+ # name in a single alter statment, see: http://bugs.mysql.com/bug.php?id=13741
+ #
+ # We have to work round this.
+
+ my %fks_to_alter;
+ my %fks_to_drop = map {
+ $_->type eq FOREIGN_KEY
+ ? ( $_->name => $_ )
+ : ( )
+ } @{$diff_hash->{alter_drop_constraint} };
+
+ my %fks_to_create = map {
+ if ( $_->type eq FOREIGN_KEY) {
+ $fks_to_alter{$_->name} = $fks_to_drop{$_->name} if $fks_to_drop{$_->name};
+ ( $_->name => $_ );
+ } else { ( ) }
+ } @{$diff_hash->{alter_create_constraint} };
+
+ my $drop_stmt = '';
+ if (scalar keys %fks_to_alter) {
+ $diff_hash->{alter_drop_constraint} = [
+ grep { !$fks_to_alter{$_->name} } @{ $diff_hash->{alter_drop_constraint} }
+ ];
+
+ $drop_stmt = batch_alter_table($table, { alter_drop_constraint => [ values %fks_to_alter ] }, $options)
+ . "\n";
+
+ }
+
my @stmts = map {
if (@{ $diff_hash->{$_} || [] }) {
my $meth = __PACKAGE__->can($_) or die __PACKAGE__ . " cant $_";
- map { $meth->(ref $_ eq 'ARRAY' ? @$_ : $_) } @{ $diff_hash->{$_} }
+ map { $meth->( (ref $_ eq 'ARRAY' ? @$_ : $_), $options ) } @{ $diff_hash->{$_} }
} else { () }
} qw/rename_table
alter_drop_constraint
return unless @stmts;
# Just zero or one stmts. return now
- return "@stmts;" unless @stmts > 1;
+ return "$drop_stmt@stmts;" unless @stmts > 1;
# Now strip off the 'ALTER TABLE xyz' of all but the first one
$re = qr/^ALTER TABLE \Q$qt@{[$table->name]}$qt\E / if $renamed_from;
my $padd = " " x length($alter_table);
- return join( ",\n", $first, map { s/$re//; $padd . $_ } @stmts) . ';';
+ return $drop_stmt . join( ",\n", $first, map { s/$re//; $padd . $_ } @stmts) . ';';
}
sub drop_table {
use Test::More;
use Test::Differences;
use Test::SQL::Translator qw(maybe_plan);
+use SQL::Translator::Schema::Constants;
+use Storable 'dclone';
-plan tests => 5;
+plan tests => 6;
use_ok('SQL::Translator::Diff') or die "Cannot continue\n";
eq_or_diff($out, <<'## END OF DIFF', "Diff as expected");
-- Convert schema 'create1.yml' to 'create2.yml':
-BEGIN TRANSACTION;
+BEGIN;
SET foreign_key_checks=0;
eq_or_diff($out, <<'## END OF DIFF', "Diff as expected");
-- Convert schema 'create1.yml' to 'create2.yml':
-BEGIN TRANSACTION;
+BEGIN;
SET foreign_key_checks=0;
eq_or_diff($out, <<'## END OF DIFF', "No differences found");
-- Convert schema 'create.sql' to 'create2.yml':
-BEGIN TRANSACTION;
+BEGIN;
SET foreign_key_checks=0;
COMMIT;
## END OF DIFF
}
+
+# Test InnoDB stupidness. Have to drop constraints before re-adding them if
+# they are just alters.
+
+
+{
+ my $s1 = SQL::Translator::Schema->new;
+ my $s2 = SQL::Translator::Schema->new;
+
+ $s1->name('Schema 1');
+ $s2->name('Schema 2');
+
+ my $t1 = $s1->add_table($target_schema->get_table('employee'));
+ my $t2 = $s2->add_table(dclone($target_schema->get_table('employee')));
+
+
+ my ($c) = grep { $_->name eq 'FK5302D47D93FE702E_diff' } $t2->get_constraints;
+ $c->on_delete('CASCADE');
+
+ $t2->add_constraint(
+ name => 'new_constraint',
+ type => 'FOREIGN KEY',
+ fields => ['employee_id'],
+ reference_fields => ['fake'],
+ reference_table => 'patty',
+ );
+
+ $t2->add_field(
+ name => 'new',
+ data_type => 'int'
+ );
+
+ $out = SQL::Translator::Diff::schema_diff($s1, 'MySQL', $s2, 'MySQL' );
+
+ eq_or_diff($out, <<'## END OF DIFF', "Batch alter of constraints work for InnoDB");
+-- Convert schema 'Schema 1' to 'Schema 2':
+
+BEGIN;
+
+ALTER TABLE employee DROP FOREIGN KEY FK5302D47D93FE702E_diff;
+ALTER TABLE employee ADD COLUMN new integer,
+ ADD CONSTRAINT FK5302D47D93FE702E_diff FOREIGN KEY (employee_id) REFERENCES person (person_id) ON DELETE CASCADE,
+ ADD CONSTRAINT new_constraint FOREIGN KEY (employee_id) REFERENCES patty (fake);
+
+COMMIT;
+## END OF DIFF
+}