Skip to content
/ server Public
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
85 changes: 85 additions & 0 deletions mysql-test/suite/innodb/r/foreign_key_errors.result
Original file line number Diff line number Diff line change
@@ -0,0 +1,85 @@
#
# MDEV-32688: Test innodb_foreign_key_errors status variable
#
# Setup
CREATE TABLE parent (id INT PRIMARY KEY) ENGINE=InnoDB;
CREATE TABLE child (
id INT PRIMARY KEY,
parent_id INT,
FOREIGN KEY (parent_id) REFERENCES parent(id)
) ENGINE=InnoDB;
INSERT INTO parent VALUES (1), (2), (3);
INSERT INTO child VALUES (1, 1), (2, 2);
# Counter starts at 0
SHOW GLOBAL STATUS LIKE 'innodb_foreign_key_errors';
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

to ensure that it indeed starts at 0, please make sure to either explicitly reset it (as mtr sometimes uses a running server instance that matches the start parameters for the current tests) or make sure that the test is always run on a freshly started server.

I'd do the former: saves one needless restart and lots of mtr run time.

This is why some of the build bot hosts are failing on your test btw.

Variable_name Value
Innodb_foreign_key_errors 0
# Child-side violations (INSERT, UPDATE, REPLACE, INSERT...SELECT)
INSERT INTO child VALUES (10, 999);
ERROR 23000: Cannot add or update a child row: a foreign key constraint fails (`test`.`child`, CONSTRAINT `1` FOREIGN KEY (`parent_id`) REFERENCES `parent` (`id`))
UPDATE child SET parent_id = 888 WHERE id = 1;
ERROR 23000: Cannot add or update a child row: a foreign key constraint fails (`test`.`child`, CONSTRAINT `1` FOREIGN KEY (`parent_id`) REFERENCES `parent` (`id`))
REPLACE INTO child VALUES (30, 777);
ERROR 23000: Cannot add or update a child row: a foreign key constraint fails (`test`.`child`, CONSTRAINT `1` FOREIGN KEY (`parent_id`) REFERENCES `parent` (`id`))
INSERT INTO child (id, parent_id) SELECT 40, 555;
ERROR 23000: Cannot add or update a child row: a foreign key constraint fails (`test`.`child`, CONSTRAINT `1` FOREIGN KEY (`parent_id`) REFERENCES `parent` (`id`))
# Parent-side violations (DELETE, UPDATE)
DELETE FROM parent WHERE id = 1;
ERROR 23000: Cannot delete or update a parent row: a foreign key constraint fails (`test`.`child`, CONSTRAINT `1` FOREIGN KEY (`parent_id`) REFERENCES `parent` (`id`))
UPDATE parent SET id = 100 WHERE id = 1;
ERROR 23000: Cannot delete or update a parent row: a foreign key constraint fails (`test`.`child`, CONSTRAINT `1` FOREIGN KEY (`parent_id`) REFERENCES `parent` (`id`))
# Counter after 6 violations
SHOW GLOBAL STATUS LIKE 'innodb_foreign_key_errors';
Variable_name Value
Innodb_foreign_key_errors 6
# Successful operations should NOT increment
INSERT INTO child VALUES (50, 3);
UPDATE child SET parent_id = 1 WHERE id = 50;
DELETE FROM child WHERE id = 50;
INSERT INTO child VALUES (60, NULL);
DELETE FROM child WHERE id = 60;
# Counter unchanged after successful operations
SHOW GLOBAL STATUS LIKE 'innodb_foreign_key_errors';
Variable_name Value
Innodb_foreign_key_errors 6
# FOREIGN_KEY_CHECKS=0 should NOT increment
SET FOREIGN_KEY_CHECKS = 0;
INSERT INTO child VALUES (70, 999);
SET FOREIGN_KEY_CHECKS = 1;
DELETE FROM child WHERE id = 70;
# Counter unchanged with FK checks disabled
SHOW GLOBAL STATUS LIKE 'innodb_foreign_key_errors';
Variable_name Value
Innodb_foreign_key_errors 6
# CASCADE chain failure
CREATE TABLE grandparent (id INT PRIMARY KEY) ENGINE=InnoDB;
CREATE TABLE parent_cascade (
id INT PRIMARY KEY,
gp_id INT,
FOREIGN KEY (gp_id) REFERENCES grandparent(id) ON DELETE RESTRICT
) ENGINE=InnoDB;
CREATE TABLE child_cascade (
id INT PRIMARY KEY,
parent_id INT,
FOREIGN KEY (parent_id) REFERENCES parent_cascade(id) ON DELETE CASCADE
) ENGINE=InnoDB;
INSERT INTO grandparent VALUES (1);
INSERT INTO parent_cascade VALUES (1, 1);
INSERT INTO child_cascade VALUES (1, 1);
DELETE FROM grandparent WHERE id = 1;
ERROR 23000: Cannot delete or update a parent row: a foreign key constraint fails (`test`.`parent_cascade`, CONSTRAINT `1` FOREIGN KEY (`gp_id`) REFERENCES `grandparent` (`id`))
# Counter after CASCADE chain failure
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

say what the value needs to be please. makes it easier to read and check.

SHOW GLOBAL STATUS LIKE 'innodb_foreign_key_errors';
Variable_name Value
Innodb_foreign_key_errors 7
DROP TABLE child_cascade;
DROP TABLE parent_cascade;
DROP TABLE grandparent;
# Counter resets after restart
# restart
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

test reset too: FLUSH status.

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Also, please, fix the commit message: do not mention the license in it. And remove the "similar to ..." part: it's not relevant.

SHOW GLOBAL STATUS LIKE 'innodb_foreign_key_errors';
Variable_name Value
Innodb_foreign_key_errors 0
# Cleanup
DROP TABLE child;
DROP TABLE parent;
1 change: 1 addition & 0 deletions mysql-test/suite/innodb/r/innodb_status_variables.result
Original file line number Diff line number Diff line change
Expand Up @@ -56,6 +56,7 @@ INNODB_DATA_WRITTEN
INNODB_DBLWR_PAGES_WRITTEN
INNODB_DBLWR_WRITES
INNODB_DEADLOCKS
INNODB_FOREIGN_KEY_ERRORS
INNODB_HISTORY_LIST_LENGTH
INNODB_LOG_WAITS
INNODB_LOG_WRITE_REQUESTS
Expand Down
97 changes: 97 additions & 0 deletions mysql-test/suite/innodb/t/foreign_key_errors.test
Original file line number Diff line number Diff line change
@@ -0,0 +1,97 @@
--source include/have_innodb.inc

--echo #
--echo # MDEV-32688: Test innodb_foreign_key_errors status variable
--echo #

--echo # Setup
CREATE TABLE parent (id INT PRIMARY KEY) ENGINE=InnoDB;
CREATE TABLE child (
id INT PRIMARY KEY,
parent_id INT,
FOREIGN KEY (parent_id) REFERENCES parent(id)
) ENGINE=InnoDB;

INSERT INTO parent VALUES (1), (2), (3);
INSERT INTO child VALUES (1, 1), (2, 2);

--echo # Counter starts at 0
SHOW GLOBAL STATUS LIKE 'innodb_foreign_key_errors';

--echo # Child-side violations (INSERT, UPDATE, REPLACE, INSERT...SELECT)
--error ER_NO_REFERENCED_ROW_2
INSERT INTO child VALUES (10, 999);

--error ER_NO_REFERENCED_ROW_2
UPDATE child SET parent_id = 888 WHERE id = 1;

--error ER_NO_REFERENCED_ROW_2
REPLACE INTO child VALUES (30, 777);

--error ER_NO_REFERENCED_ROW_2
INSERT INTO child (id, parent_id) SELECT 40, 555;

--echo # Parent-side violations (DELETE, UPDATE)
--error ER_ROW_IS_REFERENCED_2
DELETE FROM parent WHERE id = 1;

--error ER_ROW_IS_REFERENCED_2
UPDATE parent SET id = 100 WHERE id = 1;

--echo # Counter after 6 violations
SHOW GLOBAL STATUS LIKE 'innodb_foreign_key_errors';

--echo # Successful operations should NOT increment
INSERT INTO child VALUES (50, 3);
UPDATE child SET parent_id = 1 WHERE id = 50;
DELETE FROM child WHERE id = 50;
INSERT INTO child VALUES (60, NULL);
DELETE FROM child WHERE id = 60;

--echo # Counter unchanged after successful operations
SHOW GLOBAL STATUS LIKE 'innodb_foreign_key_errors';

--echo # FOREIGN_KEY_CHECKS=0 should NOT increment
SET FOREIGN_KEY_CHECKS = 0;
INSERT INTO child VALUES (70, 999);
SET FOREIGN_KEY_CHECKS = 1;
DELETE FROM child WHERE id = 70;

--echo # Counter unchanged with FK checks disabled
SHOW GLOBAL STATUS LIKE 'innodb_foreign_key_errors';

--echo # CASCADE chain failure
CREATE TABLE grandparent (id INT PRIMARY KEY) ENGINE=InnoDB;
CREATE TABLE parent_cascade (
id INT PRIMARY KEY,
gp_id INT,
FOREIGN KEY (gp_id) REFERENCES grandparent(id) ON DELETE RESTRICT
) ENGINE=InnoDB;
CREATE TABLE child_cascade (
id INT PRIMARY KEY,
parent_id INT,
FOREIGN KEY (parent_id) REFERENCES parent_cascade(id) ON DELETE CASCADE
) ENGINE=InnoDB;

INSERT INTO grandparent VALUES (1);
INSERT INTO parent_cascade VALUES (1, 1);
INSERT INTO child_cascade VALUES (1, 1);

--error ER_ROW_IS_REFERENCED_2
DELETE FROM grandparent WHERE id = 1;

--echo # Counter after CASCADE chain failure
SHOW GLOBAL STATUS LIKE 'innodb_foreign_key_errors';

DROP TABLE child_cascade;
DROP TABLE parent_cascade;
DROP TABLE grandparent;

--echo # Counter resets after restart
--source include/restart_mysqld.inc

SHOW GLOBAL STATUS LIKE 'innodb_foreign_key_errors';

--echo # Cleanup
DROP TABLE child;
DROP TABLE parent;
2 changes: 2 additions & 0 deletions storage/innobase/dict/dict0dict.cc
Original file line number Diff line number Diff line change
Expand Up @@ -172,6 +172,8 @@ and unique key errors. Only created if !srv_read_only_mode */
FILE* dict_foreign_err_file = NULL;
/* mutex protecting the foreign and unique error buffers */
mysql_mutex_t dict_foreign_err_mutex;
/** Number of foreign key constraint violations */
ulint dict_foreign_key_errors = 0;

/********************************************************************//**
Checks if the database name in two table names is the same.
Expand Down
2 changes: 2 additions & 0 deletions storage/innobase/handler/ha_innodb.cc
Original file line number Diff line number Diff line change
Expand Up @@ -73,6 +73,7 @@ this program; if not, write to the Free Software Foundation, Inc.,
#include "buf0flu.h"
#include "buf0lru.h"
#include "dict0boot.h"
#include "dict0dict.h"
#include "dict0load.h"
#include "dict0crea.h"
#include "dict0stats.h"
Expand Down Expand Up @@ -993,6 +994,7 @@ static SHOW_VAR innodb_status_variables[]= {
{"dblwr_pages_written", &export_vars.innodb_dblwr_pages_written,SHOW_SIZE_T},
{"dblwr_writes", &export_vars.innodb_dblwr_writes, SHOW_SIZE_T},
{"deadlocks", &lock_sys.deadlocks, SHOW_SIZE_T},
{"foreign_key_errors", &dict_foreign_key_errors, SHOW_SIZE_T},
{"history_list_length", &export_vars.innodb_history_list_length,SHOW_SIZE_T},
{"log_waits", &log_sys.waits, SHOW_SIZE_T},
{"log_write_requests", &log_sys.write_to_buf, SHOW_SIZE_T},
Expand Down
2 changes: 2 additions & 0 deletions storage/innobase/include/dict0dict.h
Original file line number Diff line number Diff line change
Expand Up @@ -1276,6 +1276,8 @@ constraint */
and unique key errors */
extern FILE* dict_foreign_err_file;
extern mysql_mutex_t dict_foreign_err_mutex;
/** Number of foreign key constraint violations */
extern ulint dict_foreign_key_errors;

/** InnoDB data dictionary cache */
class dict_sys_t
Expand Down
4 changes: 4 additions & 0 deletions storage/innobase/row/row0ins.cc
Original file line number Diff line number Diff line change
Expand Up @@ -760,6 +760,8 @@ row_ins_foreign_report_err(

row_ins_foreign_trx_print(trx);

dict_foreign_key_errors++;

fputs("Foreign key constraint fails for table ", ef);
ut_print_name(ef, trx, foreign->foreign_table_name);
fputs(":\n", ef);
Expand Down Expand Up @@ -816,6 +818,8 @@ row_ins_foreign_report_add_err(

row_ins_foreign_trx_print(trx);

dict_foreign_key_errors++;

fputs("Foreign key constraint fails for table ", ef);
ut_print_name(ef, trx, foreign->foreign_table_name);
fputs(":\n", ef);
Expand Down