1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214
|
--source include/force_myisam_default.inc
--source include/have_myisam.inc
# Use MyISAM for this table since we are only interested in checking syntax.
--error ER_WRONG_FK_DEF
create table t1 (
a int not null references t2,
b int not null references t2 (c),
primary key (a,b),
foreign key (a) references t3 match full,
foreign key (a) references t3 match partial,
foreign key (a,b) references t3 (c,d) on delete no action
on update no action,
foreign key (a,b) references t3 (c,d) on update cascade,
foreign key (a,b) references t3 (c,d) on delete set default,
foreign key (a,b) references t3 (c,d) on update set null) engine=myisam;
# Remove the problematic FKs and try again.
create table t1 (
a int not null,
b int not null references t2 (c),
primary key (a,b),
foreign key (a,b) references t3 (c,d) on delete no action
on update no action,
foreign key (a,b) references t3 (c,d) on update cascade,
foreign key (a,b) references t3 (c,d) on delete set default,
foreign key (a,b) references t3 (c,d) on update set null) engine=myisam;
create index a on t1 (a);
create unique index b on t1 (a,b);
drop table t1;
--echo #
--echo # 5) Check how parent table in different storage engine is handled.
--echo #
--echo # We handle it in the same way as if table was missing to be compatible
--echo # with pre-8.0 versions.
--echo #
--echo # 5.a) Attempt to create table with a foreign key or to add foreign key
--echo # to already xisting table which reference parent in different SE
--echo # should fail in FOREIGN_KEY_CHECKS=1 mode.
CREATE TABLE bad_parent (pk INT PRIMARY KEY) ENGINE=MyISAM;
--error ER_FK_CANNOT_OPEN_PARENT
CREATE TABLE child (fk INT, FOREIGN KEY (fk) REFERENCES bad_parent(pk)) ENGINE=InnoDB;
CREATE TABLE child (fk INT) ENGINE=InnoDB;
--error ER_FK_CANNOT_OPEN_PARENT
ALTER TABLE child ADD FOREIGN KEY (fk) REFERENCES bad_parent(pk);
--echo #
--echo # 5.b) However, in FOREIGN_KEY_CHECKS=0 mode this is allowed.
--echo # Referenced table is considered missing and existing table
--echo # in a wrong SE is not considered as real parent.
SET FOREIGN_KEY_CHECKS = 0;
ALTER TABLE child ADD FOREIGN KEY (fk) REFERENCES bad_parent(pk);
DROP TABLE child;
CREATE TABLE child (fk INT, FOREIGN KEY (fk) REFERENCES bad_parent(pk));
SET FOREIGN_KEY_CHECKS = 1;
--echo # Bad parent can be dropped just fine even in FOREIGN_KEY_CHECKS=1 mode.
DROP TABLE bad_parent;
DROP TABLE child;
--echo #
--echo # 5.c) Attempt to change SE for table participating in foreign key
--echo # should lead to error.
CREATE TABLE parent (pk INT PRIMARY KEY) ENGINE=InnoDB;
CREATE TABLE child (fk INT, FOREIGN KEY (fk) REFERENCES parent(pk)) ENGINE=InnoDB;
--error ER_FK_CANNOT_CHANGE_ENGINE
ALTER TABLE child ENGINE=MyISAM;
--error ER_FK_CANNOT_CHANGE_ENGINE
ALTER TABLE parent ENGINE=MyISAM;
DROP TABLES child, parent;
--echo #
--echo # 5.d) It is possible to add "parent" in wrong SE to orphan foreign key.
--echo # However, it won't be considered as real parent.
SET FOREIGN_KEY_CHECKS = 0;
CREATE TABLE child (fk INT, FOREIGN KEY (fk) REFERENCES bad_parent(pk));
SET FOREIGN_KEY_CHECKS = 1;
CREATE TABLE bad_parent (pk INT PRIMARY KEY) ENGINE=MyISAM;
--echo # It is possible to break bad parent even in FOREIGN_KEY_CHECKS=1 mode.
ALTER TABLE bad_parent DROP COLUMN pk, ADD COLUMN i INT;
DROP TABLE bad_parent;
DROP TABLE child;
--echo #
--echo # 7) Test that we check that referencing and referenced column types are
--echo # compatible. Such check should be performed for newly created foreign
--echo # keys and when we change types of columns in existing foreign keys.
--echo #
--echo #
--echo # 7.d) It should be impossible to create foreign keys with incompatible
--echo # column types by adding parent to previously orphan foreign key.
SET FOREIGN_KEY_CHECKS=0;
CREATE TABLE child (fk CHAR(10), FOREIGN KEY (fk) REFERENCES parent(pk)) ENGINE=InnoDB;
--error ER_FK_INCOMPATIBLE_COLUMNS
CREATE TABLE parent (pk INT PRIMARY KEY) ENGINE=InnoDB;
CREATE TABLE parent0 (pk INT PRIMARY KEY) ENGINE=InnoDB;
--error ER_FK_INCOMPATIBLE_COLUMNS
ALTER TABLE parent0 RENAME TO parent;
--error ER_FK_INCOMPATIBLE_COLUMNS
ALTER TABLE parent0 RENAME TO parent, ADD COLUMN j INT;
--error ER_FK_INCOMPATIBLE_COLUMNS
RENAME TABLE parent0 TO parent;
--disable_testcase Bug#28608460
CREATE TABLE parent (pk INT PRIMARY KEY) ENGINE=MyISAM;
ALTER TABLE parent ENGINE=InnoDB;
--enable_testcase
DROP TABLES child, parent0;
SET FOREIGN_KEY_CHECKS=1;
--echo #
--echo # Tests for bug#28608460 "POSSIBLE TO ADD INCONSISTENT PARENT TO ORPHAN
--echo # FOREIGN KEY IF SE CHANGED".
--echo #
--echo #
--echo # Check that consistency checks are performed when we add parent
--echo # table to previously orphan foreign key by changing table storage
--echo # engine.
SET FOREIGN_KEY_CHECKS=0;
CREATE TABLE child (fk INT, FOREIGN KEY(fk) REFERENCES parent (pk)) ENGINE=InnoDB;
CREATE TABLE parent (pk INT) ENGINE=MyISAM;
--error ER_FK_NO_INDEX_PARENT
ALTER TABLE parent ENGINE=InnoDB;
DROP TABLE parent;
CREATE TABLE parent (a INT) ENGINE=MyISAM;
--error ER_FK_NO_COLUMN_PARENT
ALTER TABLE parent ENGINE=InnoDB;
DROP TABLE parent;
CREATE TABLE parent (pk BIGINT PRIMARY KEY) ENGINE=MyISAM;
--error ER_FK_INCOMPATIBLE_COLUMNS
ALTER TABLE parent ENGINE=InnoDB;
DROP TABLE parent;
--echo #
--echo # This should work for ALTER TABLE that combines change of SE
--echo # with renaming of table.
CREATE TABLE parent0 (pk INT) ENGINE=MyISAM;
--error ER_FK_NO_INDEX_PARENT
ALTER TABLE parent0 ENGINE=InnoDB, RENAME TO parent;
DROP TABLE parent0;
--echo #
--echo # ALTER TABLE which combines change of SE and renaming of the
--echo # table is executed as if we separately did change of SE and
--echo # renamed table after that. I.e. consistency checks are also
--echo # performed for orphan foreign keys which are associated with
--echo # old table name.
CREATE TABLE parent (pk INT) ENGINE=MyISAM;
--error ER_FK_NO_INDEX_PARENT
ALTER TABLE parent ENGINE=InnoDB, RENAME TO parent0;
DROP TABLE parent;
--echo #
--echo # Check that unique constraint name is correctly updated when parent
--echo # table is added to orphan foreign key by changing table SE.
CREATE TABLE parent (pk INT, UNIQUE u(pk)) ENGINE=MyISAM;
SELECT referenced_table_name, unique_constraint_name FROM
information_schema.referential_constraints WHERE table_name = 'child';
ALTER TABLE parent ENGINE=InnoDB;
SELECT referenced_table_name, unique_constraint_name FROM
information_schema.referential_constraints WHERE table_name = 'child';
DROP TABLE parent;
--echo #
--echo # Since ALTER TABLE which combines change of SE and renaming of the
--echo # table is executed as if we separately did change of SE and
--echo # renamed table after that, the referenced table name should
--echo # be updated too.
CREATE TABLE parent (pk INT PRIMARY KEY) ENGINE=MyISAM;
SELECT referenced_table_name, unique_constraint_name FROM
information_schema.referential_constraints WHERE table_name = 'child';
ALTER TABLE parent ENGINE=InnoDB, RENAME TO parent0;
SELECT referenced_table_name, unique_constraint_name FROM
information_schema.referential_constraints WHERE table_name = 'child';
RENAME TABLE parent0 TO parent;
DROP TABLES parent;
--echo #
--echo # Check that under LOCK TABLES, when adding parent for previously orphan
--echo # foreign key by SE change, we check locks on child tables.
CREATE TABLE parent (pk INT PRIMARY KEY) ENGINE=MyISAM;
LOCK TABLES parent WRITE;
--error ER_TABLE_NOT_LOCKED
ALTER TABLE parent ENGINE=InnoDB;
UNLOCK TABLES;
LOCK TABLES child READ, parent WRITE;
--error ER_TABLE_NOT_LOCKED_FOR_WRITE
ALTER TABLE parent ENGINE=InnoDB;
UNLOCK TABLES;
LOCK TABLES child WRITE, parent WRITE;
ALTER TABLE parent ENGINE=InnoDB;
UNLOCK TABLES;
DROP TABLES child, parent;
SET FOREIGN_KEY_CHECKS=1;
--echo #
--echo # Additional coverage for bug#30267236 "REPLACE DICT_FOREIGN_PARSE...
--echo # WITH SQL-LAYER CHECK."
--echo #
--echo # Special case. We silently ignore requests to drop foreign keys
--echo # on tables in storage engines which don't support foreign keys.
--echo # This is symmetrical with the fact that we silently ignore requests
--echo # to create foreign keys on such tables.
CREATE TABLE parent (pk INT PRIMARY KEY);
CREATE TABLE child (fk1 INT, b INT, CONSTRAINT c FOREIGN KEY (fk1) REFERENCES parent (pk));
CREATE TABLE myisam_table (fk INT) ENGINE=MyISAM;
ALTER TABLE myisam_table DROP FOREIGN KEY no_such_fk;
ALTER TABLE myisam_table DROP FOREIGN KEY c;
DROP TABLES myisam_table, child, parent;
|