From b4874ba12b3d4ee6558215af2f2626dcf4cf73b0 Mon Sep 17 00:00:00 2001 From: Dave Lambley Date: Thu, 12 Dec 2019 10:55:25 +0000 Subject: [PATCH 1/2] Assert current behaviour with clashing index names --- t/38-mysql-producer.t | 46 +++++++++++++++++++++++++++++++++++++++++++ 1 file changed, 46 insertions(+) diff --git a/t/38-mysql-producer.t b/t/38-mysql-producer.t index b3c3bf88c..6fe62d780 100644 --- a/t/38-mysql-producer.t +++ b/t/38-mysql-producer.t @@ -194,6 +194,41 @@ schema: type: FOREIGN_KEY fields: foo2 name: fk_thing + + thing4: + name: thing4 + extra: + order: 4 + fields: + id: + name: id + data_type: int + is_primary_key: 0 + order: 1 + is_foreign_key: 1 + foo: + name: foo + data_type: int + order: 2 + is_not_null: 1 + foo2: + name: foo2 + data_type: int + order: 3 + is_not_null: 1 + constraints: + - type: UNIQUE + fields: + - foo + - foo2 + name: foo + - type: PRIMARY_KEY + fields: + - id + - reference_table: thing + type: FOREIGN_KEY + fields: foo + name: foo EOSCHEMA my @stmts = ( @@ -240,6 +275,17 @@ my @stmts = ( CONSTRAINT `fk_thing_3` FOREIGN KEY (`foo2`) REFERENCES `some`.`thing2` (`id`, `foo`) ) ENGINE=InnoDB", +"DROP TABLE IF EXISTS `thing4`", +"CREATE TABLE `thing4` ( + `id` integer NOT NULL, + `foo` integer NULL, + `foo2` integer NULL, + INDEX (`foo`), + UNIQUE `foo` (`foo`, `foo2`), + PRIMARY KEY (`id`), + CONSTRAINT `foo` FOREIGN KEY (`foo`) REFERENCES `thing` (`id`) +) ENGINE=InnoDB", + "SET foreign_key_checks=1", ); From 5a278bb871d521c2ab7368cf93ca68bca74d40aa Mon Sep 17 00:00:00 2001 From: Dave Lambley Date: Thu, 12 Dec 2019 11:30:21 +0000 Subject: [PATCH 2/2] Avoid index name clashing with UNIQUE KEY When we create a foreign key constraint for MySQL we also create an index, if there is not already an index beginning with the field in question. UNIQUEness constaint are implemented by indices, and so we should also skip adding an index if one already exists. To avoid changing existing fully-working schemas, this change only skips index creation if one with the same name already exists. This case currently fails with a duplicate key error in MySQL, eg., ERROR 1061 (42000): Duplicate key name 'foo' --- lib/SQL/Translator/Producer/MySQL.pm | 10 ++++++++++ t/38-mysql-producer.t | 1 - 2 files changed, 10 insertions(+), 1 deletion(-) diff --git a/lib/SQL/Translator/Producer/MySQL.pm b/lib/SQL/Translator/Producer/MySQL.pm index 5106dfb3e..f4518c766 100644 --- a/lib/SQL/Translator/Producer/MySQL.pm +++ b/lib/SQL/Translator/Producer/MySQL.pm @@ -460,6 +460,16 @@ sub create_table # my @constraint_defs; my @constraints = $table->get_constraints; + + # Mark fields which are first in a UNIQUE constraint as indexed if the + # constraint name is the same as the field. This is to prevent a duplicate + # index being created to support foreign keys. + for my $c ( @constraints ) { + if ($c->type eq UNIQUE && $c->name eq ($c->fields())[0]) { + $indexed_fields{ ($c->fields())[0] } = 1; + } + } + for my $c ( @constraints ) { my $constr = create_constraint($c, $options); push @constraint_defs, $constr if($constr); diff --git a/t/38-mysql-producer.t b/t/38-mysql-producer.t index 6fe62d780..ef35b7719 100644 --- a/t/38-mysql-producer.t +++ b/t/38-mysql-producer.t @@ -280,7 +280,6 @@ my @stmts = ( `id` integer NOT NULL, `foo` integer NULL, `foo2` integer NULL, - INDEX (`foo`), UNIQUE `foo` (`foo`, `foo2`), PRIMARY KEY (`id`), CONSTRAINT `foo` FOREIGN KEY (`foo`) REFERENCES `thing` (`id`)