Commit 49edf2d4 authored by Debarun Banerjee's avatar Debarun Banerjee Committed by Marko Mäkelä

BUG#25126722 FOREIGN KEY CONSTRAINT NAME IS NULL IN INFORMATION_SCHEMA AFTER RESTART

Problem :
---------
Information_Schema.referential_constraints (UNIQUE_CONSTRAINT_NAME)
shows NULL for a foreign key constraint after restarting the server.
If any dml or query (select/insert/update/delete) is done on
referenced table, then the constraint name is correctly shown.

Solution :
----------
UNIQUE_CONSTRAINT_NAME column is the key name of the referenced table.
In innodb, FK reference is stored as a list of columns in referenced
table in INNODB_SYS_FOREIGN and INNODB_SYS_FOREIGN_COLS. The referenced
column must have at least one index/key with the referenced column as
prefix but the key name itself is not included in FK metadata. For this
reason, the UNIQUE_CONSTRAINT_NAME is only filled up when the
referenced table is actually loaded in innodb dictionary cache.

The information_schema view calls handler::get_foreign_key_list() on
foreign key table to read the FK metadata. The UNIQUE_CONSTRAINT_NAME
information shows NULL based on whether the referenced table is
already loaded or not.

One way to fix this issue is to load the referenced table while reading
the FK metadata information, if needed.
Reviewed-by: default avatarSunny Bains <sunny.bains@oracle.com>

RB: 14654
parent 07e88be5
#
# Bug #19027905 ASSERT RET.SECOND DICT_CREATE_FOREIGN_CONSTRAINTS_LOW
# DICT_CREATE_FOREIGN_CONSTR
#
create table t1 (f1 int primary key) engine=InnoDB;
create table t2 (f1 int primary key,
constraint c1 foreign key (f1) references t1(f1),
constraint c1 foreign key (f1) references t1(f1)) engine=InnoDB;
ERROR HY000: Can't create table `test`.`t2` (errno: 150 "Foreign key constraint is incorrectly formed")
create table t2 (f1 int primary key,
constraint c1 foreign key (f1) references t1(f1)) engine=innodb;
alter table t2 add constraint c1 foreign key (f1) references t1(f1);
ERROR HY000: Can't create table `test`.`#sql-temporary` (errno: 121 "Duplicate key on write or update")
set foreign_key_checks = 0;
alter table t2 add constraint c1 foreign key (f1) references t1(f1);
ERROR HY000: Duplicate FOREIGN KEY constraint name 'test/c1'
drop table t2, t1;
#
# Bug #20031243 CREATE TABLE FAILS TO CHECK IF FOREIGN KEY COLUMN
# NULL/NOT NULL MISMATCH
#
set foreign_key_checks = 1;
show variables like 'foreign_key_checks';
Variable_name Value
foreign_key_checks ON
CREATE TABLE t1
(a INT NOT NULL,
b INT NOT NULL,
INDEX idx(a)) ENGINE=InnoDB;
CREATE TABLE t2
(a INT KEY,
b INT,
INDEX ind(b),
FOREIGN KEY (b) REFERENCES t1(a) ON DELETE CASCADE ON UPDATE CASCADE)
ENGINE=InnoDB;
show create table t1;
Table Create Table
t1 CREATE TABLE `t1` (
`a` int(11) NOT NULL,
`b` int(11) NOT NULL,
KEY `idx` (`a`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1
show create table t2;
Table Create Table
t2 CREATE TABLE `t2` (
`a` int(11) NOT NULL,
`b` int(11) DEFAULT NULL,
PRIMARY KEY (`a`),
KEY `ind` (`b`),
CONSTRAINT `t2_ibfk_1` FOREIGN KEY (`b`) REFERENCES `t1` (`a`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=latin1
INSERT INTO t1 VALUES (1, 80);
INSERT INTO t1 VALUES (2, 81);
INSERT INTO t1 VALUES (3, 82);
INSERT INTO t1 VALUES (4, 83);
INSERT INTO t1 VALUES (5, 84);
INSERT INTO t2 VALUES (51, 1);
INSERT INTO t2 VALUES (52, 2);
INSERT INTO t2 VALUES (53, 3);
INSERT INTO t2 VALUES (54, 4);
INSERT INTO t2 VALUES (55, 5);
SELECT a, b FROM t1 ORDER BY a;
a b
1 80
2 81
3 82
4 83
5 84
SELECT a, b FROM t2 ORDER BY a;
a b
51 1
52 2
53 3
54 4
55 5
INSERT INTO t2 VALUES (56, 6);
ERROR 23000: Cannot add or update a child row: a foreign key constraint fails (`test`.`t2`, CONSTRAINT `t2_ibfk_1` FOREIGN KEY (`b`) REFERENCES `t1` (`a`) ON DELETE CASCADE ON UPDATE CASCADE)
ALTER TABLE t1 CHANGE a id INT;
SELECT id, b FROM t1 ORDER BY id;
id b
1 80
2 81
3 82
4 83
5 84
SELECT a, b FROM t2 ORDER BY a;
a b
51 1
52 2
53 3
54 4
55 5
# Operations on child table
INSERT INTO t2 VALUES (56, 6);
ERROR 23000: Cannot add or update a child row: a foreign key constraint fails (`test`.`t2`, CONSTRAINT `t2_ibfk_1` FOREIGN KEY (`b`) REFERENCES `t1` (`id`) ON DELETE CASCADE ON UPDATE CASCADE)
UPDATE t2 SET b = 99 WHERE a = 51;
ERROR 23000: Cannot add or update a child row: a foreign key constraint fails (`test`.`t2`, CONSTRAINT `t2_ibfk_1` FOREIGN KEY (`b`) REFERENCES `t1` (`id`) ON DELETE CASCADE ON UPDATE CASCADE)
DELETE FROM t2 WHERE a = 53;
SELECT id, b FROM t1 ORDER BY id;
id b
1 80
2 81
3 82
4 83
5 84
SELECT a, b FROM t2 ORDER BY a;
a b
51 1
52 2
54 4
55 5
# Operations on parent table
DELETE FROM t1 WHERE id = 1;
UPDATE t1 SET id = 50 WHERE id = 5;
SELECT id, b FROM t1 ORDER BY id;
id b
2 81
3 82
4 83
50 84
SELECT a, b FROM t2 ORDER BY a;
a b
52 2
54 4
55 50
DROP TABLE t2, t1;
#
# bug#25126722 FOREIGN KEY CONSTRAINT NAME IS NULL AFTER RESTART
# base bug#24818604 [GR]
#
CREATE TABLE t1 (c1 INT PRIMARY KEY) ENGINE=InnoDB;
CREATE TABLE t2 (c1 INT PRIMARY KEY, FOREIGN KEY (c1) REFERENCES t1(c1))
ENGINE=InnoDB;
INSERT INTO t1 VALUES (1);
INSERT INTO t2 VALUES (1);
SELECT unique_constraint_name FROM information_schema.referential_constraints
WHERE table_name = 't2';
unique_constraint_name
PRIMARY
SELECT unique_constraint_name FROM information_schema.referential_constraints
WHERE table_name = 't2';
unique_constraint_name
PRIMARY
SELECT * FROM t1;
c1
1
SELECT unique_constraint_name FROM information_schema.referential_constraints
WHERE table_name = 't2';
unique_constraint_name
PRIMARY
DROP TABLE t2;
DROP TABLE t1;
--source include/have_innodb.inc
--echo #
--echo # Bug #19027905 ASSERT RET.SECOND DICT_CREATE_FOREIGN_CONSTRAINTS_LOW
--echo # DICT_CREATE_FOREIGN_CONSTR
--echo #
create table t1 (f1 int primary key) engine=InnoDB;
--error ER_CANT_CREATE_TABLE
create table t2 (f1 int primary key,
constraint c1 foreign key (f1) references t1(f1),
constraint c1 foreign key (f1) references t1(f1)) engine=InnoDB;
create table t2 (f1 int primary key,
constraint c1 foreign key (f1) references t1(f1)) engine=innodb;
--replace_regex /#sql-[0-9a-f_]*/#sql-temporary/
--error ER_CANT_CREATE_TABLE
alter table t2 add constraint c1 foreign key (f1) references t1(f1);
set foreign_key_checks = 0;
--error ER_DUP_CONSTRAINT_NAME
alter table t2 add constraint c1 foreign key (f1) references t1(f1);
drop table t2, t1;
--echo #
--echo # Bug #20031243 CREATE TABLE FAILS TO CHECK IF FOREIGN KEY COLUMN
--echo # NULL/NOT NULL MISMATCH
--echo #
set foreign_key_checks = 1;
show variables like 'foreign_key_checks';
CREATE TABLE t1
(a INT NOT NULL,
b INT NOT NULL,
INDEX idx(a)) ENGINE=InnoDB;
CREATE TABLE t2
(a INT KEY,
b INT,
INDEX ind(b),
FOREIGN KEY (b) REFERENCES t1(a) ON DELETE CASCADE ON UPDATE CASCADE)
ENGINE=InnoDB;
show create table t1;
show create table t2;
INSERT INTO t1 VALUES (1, 80);
INSERT INTO t1 VALUES (2, 81);
INSERT INTO t1 VALUES (3, 82);
INSERT INTO t1 VALUES (4, 83);
INSERT INTO t1 VALUES (5, 84);
INSERT INTO t2 VALUES (51, 1);
INSERT INTO t2 VALUES (52, 2);
INSERT INTO t2 VALUES (53, 3);
INSERT INTO t2 VALUES (54, 4);
INSERT INTO t2 VALUES (55, 5);
SELECT a, b FROM t1 ORDER BY a;
SELECT a, b FROM t2 ORDER BY a;
--error ER_NO_REFERENCED_ROW_2
INSERT INTO t2 VALUES (56, 6);
ALTER TABLE t1 CHANGE a id INT;
SELECT id, b FROM t1 ORDER BY id;
SELECT a, b FROM t2 ORDER BY a;
--echo # Operations on child table
--error ER_NO_REFERENCED_ROW_2
INSERT INTO t2 VALUES (56, 6);
--error ER_NO_REFERENCED_ROW_2
UPDATE t2 SET b = 99 WHERE a = 51;
DELETE FROM t2 WHERE a = 53;
SELECT id, b FROM t1 ORDER BY id;
SELECT a, b FROM t2 ORDER BY a;
--echo # Operations on parent table
DELETE FROM t1 WHERE id = 1;
UPDATE t1 SET id = 50 WHERE id = 5;
SELECT id, b FROM t1 ORDER BY id;
SELECT a, b FROM t2 ORDER BY a;
DROP TABLE t2, t1;
--echo #
--echo # bug#25126722 FOREIGN KEY CONSTRAINT NAME IS NULL AFTER RESTART
--echo # base bug#24818604 [GR]
--echo #
CREATE TABLE t1 (c1 INT PRIMARY KEY) ENGINE=InnoDB;
CREATE TABLE t2 (c1 INT PRIMARY KEY, FOREIGN KEY (c1) REFERENCES t1(c1))
ENGINE=InnoDB;
INSERT INTO t1 VALUES (1);
INSERT INTO t2 VALUES (1);
SELECT unique_constraint_name FROM information_schema.referential_constraints
WHERE table_name = 't2';
--source include/restart_mysqld.inc
SELECT unique_constraint_name FROM information_schema.referential_constraints
WHERE table_name = 't2';
SELECT * FROM t1;
SELECT unique_constraint_name FROM information_schema.referential_constraints
WHERE table_name = 't2';
DROP TABLE t2;
DROP TABLE t1;
...@@ -15863,6 +15863,28 @@ get_foreign_key_info( ...@@ -15863,6 +15863,28 @@ get_foreign_key_info(
f_key_info.update_method = FK_OPTION_RESTRICT; f_key_info.update_method = FK_OPTION_RESTRICT;
} }
/* Load referenced table to update FK referenced key name. */
if (foreign->referenced_table == NULL) {
dict_table_t* ref_table;
ut_ad(mutex_own(&dict_sys->mutex));
ref_table = dict_table_open_on_name(
foreign->referenced_table_name_lookup,
TRUE, FALSE, DICT_ERR_IGNORE_NONE);
if (ref_table == NULL) {
ib::info() << "Foreign Key referenced table "
<< foreign->referenced_table_name
<< " not found for foreign table "
<< foreign->foreign_table_name;
} else {
dict_table_close(ref_table, TRUE, FALSE);
}
}
if (foreign->referenced_index if (foreign->referenced_index
&& foreign->referenced_index->name != NULL) { && foreign->referenced_index->name != NULL) {
referenced_key_name = thd_make_lex_string( referenced_key_name = thd_make_lex_string(
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment