Skip to content

Commit

Permalink
Bug #33053297 VIRTUAL INDEX CORRUPTED DURING CASCADE UPDATE ON CHILD
Browse files Browse the repository at this point in the history
TABLE

Problem:
Child table has FOREIGN KEY (FK) constraint with referential action
ON DELETE SET NULL (or ON UPDATE SET NULL).  And child table also
has an index over (FK column, virtual column).  When a row is
deleted from parent table, FK constraint check on child table, set
both [FK column, virtual column] value in the index to NULL.

Fix:
Instead of setting virtual column value to NULL, derives it from the
base columns.  when FK column is set to NULL in the child table,
three cases need to be taken care while setting virtual column value
in the index:
1. If all base columns are in FK then set virtual column value
to NULL.
2. If no base columns is in FK then set virtual column value to
OLD value.
3. If one or more base columns are in FK then set those base
column value to NULL and compute virtual column value again.

RB: 26751
Reviewed by : Rahul Agarkar <rahul.agarkar@oracle.com>
  • Loading branch information
sachinagarwal1111 committed Sep 1, 2021
1 parent f8ed177 commit 27130e2
Show file tree
Hide file tree
Showing 7 changed files with 360 additions and 9 deletions.
147 changes: 147 additions & 0 deletions mysql-test/suite/innodb/r/foreign_key.result
Expand Up @@ -150,3 +150,150 @@ unique_constraint_name
PRIMARY
DROP TABLE t2;
DROP TABLE t1;
#
# Bug#33053297 VIRTUAL INDEX CORRUPTED DURING CASCADE UPDATE ON CHILD TABLE
#
#Test-Case 1
CREATE TABLE `emails` (
`id` int unsigned NOT NULL AUTO_INCREMENT,
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
ROW_FORMAT=DYNAMIC;
CREATE TABLE `email_stats` (
`id` bigint unsigned NOT NULL AUTO_INCREMENT,
`email_id` int unsigned DEFAULT NULL,
`date_sent` datetime NOT NULL,
`generated_sent_date` date GENERATED ALWAYS AS
(concat(year(`date_sent`),'-',lpad(month(`date_sent`),2,'0'),
'-',lpad(dayofmonth(`date_sent`),2,'0'))) VIRTUAL,
PRIMARY KEY (`id`),
KEY `IDX_ES1` (`email_id`),
KEY `mautic_generated_sent_date_email_id`
(`generated_sent_date`,`email_id`),
CONSTRAINT `FK_EA1` FOREIGN KEY (`email_id`) REFERENCES
`emails` (`id`) ON DELETE SET NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
ROW_FORMAT=DYNAMIC;
INSERT INTO `emails` VALUES (1);
INSERT INTO `email_stats` (`id`, `email_id`, `date_sent`) VALUES
(1,1,'2020-10-22 13:32:41');
SELECT * FROM `email_stats`;
id email_id date_sent generated_sent_date
1 1 2020-10-22 13:32:41 2020-10-22
DELETE FROM `emails`;
DELETE FROM `email_stats`;
DROP TABLE `email_stats`;
DROP TABLE `emails`;
# Test-Case 2
CREATE TABLE `emails` (
`id` int unsigned NOT NULL AUTO_INCREMENT,
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
ROW_FORMAT=DYNAMIC;
CREATE TABLE `email_stats` (
`id` bigint unsigned NOT NULL AUTO_INCREMENT,
`email_id` int unsigned DEFAULT NULL,
`date_sent` datetime NOT NULL,
`generated_sent_date` date GENERATED ALWAYS AS
(concat(year(`date_sent`),'-',lpad(month(`date_sent`),2,'0'),
'-',lpad(dayofmonth(`date_sent`),2,'0'))) VIRTUAL,
PRIMARY KEY (`id`),
KEY `IDX_ES1` (`email_id`),
KEY `mautic_generated_sent_date_email_id`
(`generated_sent_date`,`email_id`),
CONSTRAINT `FK_EA1` FOREIGN KEY (`email_id`) REFERENCES
`emails` (`id`) ON DELETE SET NULL ON UPDATE SET NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
ROW_FORMAT=DYNAMIC;
INSERT INTO `emails` VALUES (1);
INSERT INTO `email_stats` (`id`, `email_id`, `date_sent`) VALUES
(1,1,'2020-10-22 13:32:41');
UPDATE `emails` SET `id` = 2 where `id` = 1;
SELECT id FROM `email_stats` WHERE `generated_sent_date` IS NULL;
id
SELECT * FROM `email_stats`;
id email_id date_sent generated_sent_date
1 NULL 2020-10-22 13:32:41 2020-10-22
UPDATE `email_stats` SET `email_id`=2
WHERE DATE(`generated_sent_date`) = '2020-10-22';
SELECT * FROM `email_stats`;
id email_id date_sent generated_sent_date
1 2 2020-10-22 13:32:41 2020-10-22
DROP TABLE `email_stats`;
DROP TABLE `emails`;
# test-case 3
CREATE TABLE `emails` (
`id` int unsigned NOT NULL AUTO_INCREMENT,
PRIMARY KEY (`id`)
) ENGINE=INNODB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
ROW_FORMAT=DYNAMIC;
CREATE TABLE `email_stats` (
`id` bigint unsigned NOT NULL AUTO_INCREMENT,
`email_id` int unsigned DEFAULT NULL,
`date_sent` datetime NOT NULL,
`generated_sent_email` varchar(20) GENERATED ALWAYS AS
(CONCAT(YEAR(`date_sent`),'-', COALESCE(`email_id`, ' '))) VIRTUAL,
PRIMARY KEY (`id`),
KEY `idx_es1` (`email_id`),
KEY `mautic_generated_sent_date_email`
(`generated_sent_email`,`email_id`),
CONSTRAINT `fk_ea1` FOREIGN KEY (`email_id`) REFERENCES
`emails` (`id`) ON DELETE SET NULL
) ENGINE=INNODB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
ROW_FORMAT=DYNAMIC;
INSERT INTO `emails` VALUES (1);
INSERT INTO `email_stats` (`id`, `email_id`, `date_sent`) VALUES
(1,1,'2020-10-22 13:32:41');
SELECT * FROM `email_stats`;
id email_id date_sent generated_sent_email
1 1 2020-10-22 13:32:41 2020-1
SELECT `date_sent` FROM `email_stats` WHERE `generated_sent_email` = '2020-1';
date_sent
2020-10-22 13:32:41
DELETE FROM `emails`;
SELECT * FROM `email_stats`;
id email_id date_sent generated_sent_email
1 NULL 2020-10-22 13:32:41 2020-
SELECT `date_sent` FROM `email_stats` WHERE `generated_sent_email` = '2020-';
date_sent
2020-10-22 13:32:41
DROP TABLE `email_stats`;
DROP TABLE `emails`;
# test-case 4
CREATE TABLE `emails` (
`id` int unsigned NOT NULL AUTO_INCREMENT,
PRIMARY KEY (`id`)
) ENGINE=INNODB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
ROW_FORMAT=DYNAMIC;
CREATE TABLE `email_stats` (
`id` bigint unsigned NOT NULL AUTO_INCREMENT,
`email_id` int unsigned DEFAULT NULL,
`date_sent` datetime NOT NULL,
`generated_sent_email` varchar(20) GENERATED ALWAYS AS
(CONCAT(YEAR(`date_sent`),'-', COALESCE(`email_id`, ' '))) VIRTUAL,
PRIMARY KEY (`id`),
KEY `idx_es1` (`email_id`),
KEY `mautic_generated_sent_date_email`
(`generated_sent_email`,`email_id`),
CONSTRAINT `fk_ea1` FOREIGN KEY (`email_id`) REFERENCES
`emails` (`id`) ON UPDATE SET NULL
) ENGINE=INNODB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
ROW_FORMAT=DYNAMIC;
INSERT INTO `emails` VALUES (1);
INSERT INTO `email_stats` (`id`, `email_id`, `date_sent`) VALUES
(1,1,'2020-10-22 13:32:41');
SELECT * FROM `email_stats`;
id email_id date_sent generated_sent_email
1 1 2020-10-22 13:32:41 2020-1
SELECT `date_sent` FROM `email_stats` WHERE `generated_sent_email` = '2020-1';
date_sent
2020-10-22 13:32:41
UPDATE `emails` SET `id` = 2 WHERE `id` = 1;
SELECT * FROM `email_stats`;
id email_id date_sent generated_sent_email
1 NULL 2020-10-22 13:32:41 2020-
SELECT `date_sent` FROM `email_stats` WHERE `generated_sent_email` = '2020-';
date_sent
2020-10-22 13:32:41
DROP TABLE `email_stats`;
DROP TABLE `emails`;
140 changes: 140 additions & 0 deletions mysql-test/suite/innodb/t/foreign_key.test
Expand Up @@ -113,3 +113,143 @@ WHERE table_name = 't2';

DROP TABLE t2;
DROP TABLE t1;

--echo #
--echo # Bug#33053297 VIRTUAL INDEX CORRUPTED DURING CASCADE UPDATE ON CHILD TABLE
--echo #

--echo #Test-Case 1
CREATE TABLE `emails` (
`id` int unsigned NOT NULL AUTO_INCREMENT,
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
ROW_FORMAT=DYNAMIC;

CREATE TABLE `email_stats` (
`id` bigint unsigned NOT NULL AUTO_INCREMENT,
`email_id` int unsigned DEFAULT NULL,
`date_sent` datetime NOT NULL,
`generated_sent_date` date GENERATED ALWAYS AS
(concat(year(`date_sent`),'-',lpad(month(`date_sent`),2,'0'),
'-',lpad(dayofmonth(`date_sent`),2,'0'))) VIRTUAL,
PRIMARY KEY (`id`),
KEY `IDX_ES1` (`email_id`),
KEY `mautic_generated_sent_date_email_id`
(`generated_sent_date`,`email_id`),
CONSTRAINT `FK_EA1` FOREIGN KEY (`email_id`) REFERENCES
`emails` (`id`) ON DELETE SET NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
ROW_FORMAT=DYNAMIC;

INSERT INTO `emails` VALUES (1);
INSERT INTO `email_stats` (`id`, `email_id`, `date_sent`) VALUES
(1,1,'2020-10-22 13:32:41');
SELECT * FROM `email_stats`;
DELETE FROM `emails`;
DELETE FROM `email_stats`;

#clean up.
DROP TABLE `email_stats`;
DROP TABLE `emails`;

--echo # Test-Case 2
CREATE TABLE `emails` (
`id` int unsigned NOT NULL AUTO_INCREMENT,
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
ROW_FORMAT=DYNAMIC;

CREATE TABLE `email_stats` (
`id` bigint unsigned NOT NULL AUTO_INCREMENT,
`email_id` int unsigned DEFAULT NULL,
`date_sent` datetime NOT NULL,
`generated_sent_date` date GENERATED ALWAYS AS
(concat(year(`date_sent`),'-',lpad(month(`date_sent`),2,'0'),
'-',lpad(dayofmonth(`date_sent`),2,'0'))) VIRTUAL,
PRIMARY KEY (`id`),
KEY `IDX_ES1` (`email_id`),
KEY `mautic_generated_sent_date_email_id`
(`generated_sent_date`,`email_id`),
CONSTRAINT `FK_EA1` FOREIGN KEY (`email_id`) REFERENCES
`emails` (`id`) ON DELETE SET NULL ON UPDATE SET NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
ROW_FORMAT=DYNAMIC;
INSERT INTO `emails` VALUES (1);
INSERT INTO `email_stats` (`id`, `email_id`, `date_sent`) VALUES
(1,1,'2020-10-22 13:32:41');
UPDATE `emails` SET `id` = 2 where `id` = 1;
SELECT id FROM `email_stats` WHERE `generated_sent_date` IS NULL;
SELECT * FROM `email_stats`;
UPDATE `email_stats` SET `email_id`=2
WHERE DATE(`generated_sent_date`) = '2020-10-22';
SELECT * FROM `email_stats`;

#clean up.
DROP TABLE `email_stats`;
DROP TABLE `emails`;

--echo # test-case 3
CREATE TABLE `emails` (
`id` int unsigned NOT NULL AUTO_INCREMENT,
PRIMARY KEY (`id`)
) ENGINE=INNODB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
ROW_FORMAT=DYNAMIC;
CREATE TABLE `email_stats` (
`id` bigint unsigned NOT NULL AUTO_INCREMENT,
`email_id` int unsigned DEFAULT NULL,
`date_sent` datetime NOT NULL,
`generated_sent_email` varchar(20) GENERATED ALWAYS AS
(CONCAT(YEAR(`date_sent`),'-', COALESCE(`email_id`, ' '))) VIRTUAL,
PRIMARY KEY (`id`),
KEY `idx_es1` (`email_id`),
KEY `mautic_generated_sent_date_email`
(`generated_sent_email`,`email_id`),
CONSTRAINT `fk_ea1` FOREIGN KEY (`email_id`) REFERENCES
`emails` (`id`) ON DELETE SET NULL
) ENGINE=INNODB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
ROW_FORMAT=DYNAMIC;
INSERT INTO `emails` VALUES (1);
INSERT INTO `email_stats` (`id`, `email_id`, `date_sent`) VALUES
(1,1,'2020-10-22 13:32:41');
SELECT * FROM `email_stats`;
SELECT `date_sent` FROM `email_stats` WHERE `generated_sent_email` = '2020-1';
DELETE FROM `emails`;
SELECT * FROM `email_stats`;
SELECT `date_sent` FROM `email_stats` WHERE `generated_sent_email` = '2020-';

#clean up.
DROP TABLE `email_stats`;
DROP TABLE `emails`;

--echo # test-case 4
CREATE TABLE `emails` (
`id` int unsigned NOT NULL AUTO_INCREMENT,
PRIMARY KEY (`id`)
) ENGINE=INNODB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
ROW_FORMAT=DYNAMIC;
CREATE TABLE `email_stats` (
`id` bigint unsigned NOT NULL AUTO_INCREMENT,
`email_id` int unsigned DEFAULT NULL,
`date_sent` datetime NOT NULL,
`generated_sent_email` varchar(20) GENERATED ALWAYS AS
(CONCAT(YEAR(`date_sent`),'-', COALESCE(`email_id`, ' '))) VIRTUAL,
PRIMARY KEY (`id`),
KEY `idx_es1` (`email_id`),
KEY `mautic_generated_sent_date_email`
(`generated_sent_email`,`email_id`),
CONSTRAINT `fk_ea1` FOREIGN KEY (`email_id`) REFERENCES
`emails` (`id`) ON UPDATE SET NULL
) ENGINE=INNODB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
ROW_FORMAT=DYNAMIC;
INSERT INTO `emails` VALUES (1);
INSERT INTO `email_stats` (`id`, `email_id`, `date_sent`) VALUES
(1,1,'2020-10-22 13:32:41');
SELECT * FROM `email_stats`;
SELECT `date_sent` FROM `email_stats` WHERE `generated_sent_email` = '2020-1';
UPDATE `emails` SET `id` = 2 WHERE `id` = 1;
SELECT * FROM `email_stats`;
SELECT `date_sent` FROM `email_stats` WHERE `generated_sent_email` = '2020-';

#clean up.
DROP TABLE `email_stats`;
DROP TABLE `emails`;
22 changes: 22 additions & 0 deletions storage/innobase/dict/dict0dict.cc
Expand Up @@ -7166,3 +7166,25 @@ dict_table_extent_size(

return(pages_in_extent);
}

/** @return number of base columns of virtual column in foreign key column
@param[in] vcol in-memory virtual column
@param[in] foreign in-memory Foreign key constraint */
uint32_t dict_vcol_base_is_foreign_key(dict_v_col_t *vcol,
dict_foreign_t *foreign) {

const dict_table_t *table = foreign->foreign_table;
uint32_t foreign_col_count = 0;

for (uint32_t i = 0; i < foreign->n_fields; i++) {
const char *foreign_col_name = foreign->foreign_col_names[i];
for (uint32_t j = 0; j < vcol->num_base; j++) {
if (innobase_strcasecmp(foreign_col_name,
dict_table_get_col_name(table,
vcol->base_col[j]->ind)) == 0) {
foreign_col_count++;
}
}
}
return foreign_col_count;
}
15 changes: 7 additions & 8 deletions storage/innobase/handler/ha_innodb.cc
Expand Up @@ -20788,20 +20788,19 @@ given col_no.
@param[in] update updated parent vector.
@param[in] col_no base column position of the child table to check
@return updated field from the parent update vector, else NULL */
static
dfield_t*
innobase_get_field_from_update_vector(
dict_foreign_t* foreign,
upd_t* update,
ulint col_no)
uint32_t col_no)
{
dict_table_t* parent_table = foreign->referenced_table;
dict_index_t* parent_index = foreign->referenced_index;
ulint parent_field_no;
ulint parent_col_no;
ulint child_col_no;
uint32_t parent_field_no;
uint32_t parent_col_no;
uint32_t child_col_no;

for (ulint i = 0; i < foreign->n_fields; i++) {
for (uint32_t i = 0; i < foreign->n_fields; i++) {
child_col_no = dict_index_get_nth_col_no(
foreign->foreign_index, i);
if (child_col_no != col_no) {
Expand All @@ -20811,7 +20810,7 @@ innobase_get_field_from_update_vector(
parent_field_no = dict_table_get_nth_col_pos(
parent_table, parent_col_no);

for (ulint j = 0; j < update->n_fields; j++) {
for (uint32_t j = 0; j < update->n_fields; j++) {
upd_field_t* parent_ufield
= &update->fields[j];

Expand Down Expand Up @@ -20891,7 +20890,7 @@ innobase_get_computed_value(
for (ulint i = 0; i < col->num_base; i++) {
dict_col_t* base_col = col->base_col[i];
const dfield_t* row_field = NULL;
ulint col_no = base_col->ind;
uint32_t col_no = base_col->ind;
const mysql_row_templ_t* templ
= index->table->vc_templ->vtempl[col_no];
const byte* data;
Expand Down
4 changes: 4 additions & 0 deletions storage/innobase/include/dict0dict.h
Expand Up @@ -2149,6 +2149,10 @@ bool
dict_table_is_partition(
const dict_table_t* table);

/** @return true if all base column of virtual column is foreign key column
@param[in] vcol in-memory virtul column
@param[in] foreign in-memory Foreign key constraint */
uint32_t dict_vcol_base_is_foreign_key(dict_v_col_t *vcol, dict_foreign_t *foreign);

#endif /* !UNIV_HOTBACKUP */

Expand Down
12 changes: 12 additions & 0 deletions storage/innobase/include/row0mysql.h
Expand Up @@ -951,6 +951,18 @@ struct SysIndexCallback {
virtual void operator()(mtr_t* mtr, btr_pcur_t* pcur) throw() = 0;
};

/** Get the updated parent field value from the update vector for the
given col_no.
@param[in] foreign foreign key information
@param[in] update updated parent vector.
@param[in] col_no base column position of the child table to check
@return updated field from the parent update vector, else NULL */
dfield_t*
innobase_get_field_from_update_vector(
dict_foreign_t* foreign,
upd_t* update,
uint32_t col_no);

/** Get the computed value by supplying the base column values.
@param[in,out] row the data row
@param[in] col virtual column
Expand Down

0 comments on commit 27130e2

Please sign in to comment.