From e9dbbf112041cd9441ec0eee934e526617eb1213 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Sat, 6 Jun 2020 11:38:38 -0700 Subject: [PATCH 1/5] MDEV-22748 MariaDB crash on WITH RECURSIVE large query This bug is the same as the bug MDEV-17024. The crashes caused by these bugs were due to premature cleanups of the unit specifying recursive CTEs that happened in some cases when there were several outer references the same recursive CTE. The problem of premature cleanups for recursive CTEs could be already resolved by the correction in TABLE_LIST::set_as_with_table() introduced in this patch. ALL other changes introduced by the patches for MDEV-17024 and MDEV-22748 guarantee that this clean-ups are performed as soon as possible: when the select containing the last outer reference to a recursive CTE is being cleaned up the specification of the recursive CTE should be cleaned up as well. --- mysql-test/r/cte_recursive.result | 170 ++++++++++++++++++++++++++++-- mysql-test/t/cte_recursive.test | 70 +++++++++++- sql/sql_cte.cc | 1 + sql/sql_derived.cc | 6 +- sql/sql_union.cc | 13 +++ 5 files changed, 247 insertions(+), 13 deletions(-) diff --git a/mysql-test/r/cte_recursive.result b/mysql-test/r/cte_recursive.result index 0b8bc3fa8ab..640493142bd 100644 --- a/mysql-test/r/cte_recursive.result +++ b/mysql-test/r/cte_recursive.result @@ -691,13 +691,13 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 Using where 1 PRIMARY ref key0 key0 5 c.h_id 2 100.00 1 PRIMARY ref key0 key0 5 c.w_id 2 100.00 -2 DERIVED ALL NULL NULL NULL NULL 12 100.00 Using where 3 DERIVED folks ALL NULL NULL NULL NULL 12 100.00 Using where 4 RECURSIVE UNION ALL NULL NULL NULL NULL 2 100.00 4 RECURSIVE UNION p ALL NULL NULL NULL NULL 12 100.00 Using where; Using join buffer (flat, BNL join) 5 RECURSIVE UNION ALL NULL NULL NULL NULL 2 100.00 5 RECURSIVE UNION p ALL NULL NULL NULL NULL 12 100.00 Using where; Using join buffer (flat, BNL join) NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +2 DERIVED ALL NULL NULL NULL NULL 12 100.00 Using where Warnings: Note 1003 with recursive ancestor_couple_ids as (select `a`.`father` AS `h_id`,`a`.`mother` AS `w_id` from `coupled_ancestors` `a` where `a`.`father` is not null and `a`.`mother` is not null), coupled_ancestors as (select `test`.`folks`.`id` AS `id`,`test`.`folks`.`name` AS `name`,`test`.`folks`.`dob` AS `dob`,`test`.`folks`.`father` AS `father`,`test`.`folks`.`mother` AS `mother` from `test`.`folks` where `test`.`folks`.`name` = 'Me' union all select `test`.`p`.`id` AS `id`,`test`.`p`.`name` AS `name`,`test`.`p`.`dob` AS `dob`,`test`.`p`.`father` AS `father`,`test`.`p`.`mother` AS `mother` from `test`.`folks` `p` join `ancestor_couple_ids` `fa` where `test`.`p`.`id` = `fa`.`h_id` union all select `test`.`p`.`id` AS `id`,`test`.`p`.`name` AS `name`,`test`.`p`.`dob` AS `dob`,`test`.`p`.`father` AS `father`,`test`.`p`.`mother` AS `mother` from `test`.`folks` `p` join `ancestor_couple_ids` `ma` where `test`.`p`.`id` = `ma`.`w_id`)select `h`.`name` AS `name`,`h`.`dob` AS `dob`,`w`.`name` AS `name`,`w`.`dob` AS `dob` from `ancestor_couple_ids` `c` join `coupled_ancestors` `h` join `coupled_ancestors` `w` where `h`.`id` = `c`.`h_id` and `w`.`id` = `c`.`w_id` # simple mutual recursion @@ -1302,12 +1302,12 @@ id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY ALL NULL NULL NULL NULL 24 4 DERIVED folks ALL NULL NULL NULL NULL 12 Using where 6 RECURSIVE UNION ALL NULL NULL NULL NULL 12 +5 RECURSIVE UNION ALL NULL NULL NULL NULL 24 +NULL UNION RESULT ALL NULL NULL NULL NULL NULL 3 DERIVED folks ALL NULL NULL NULL NULL 12 Using where 2 RECURSIVE UNION folks ALL PRIMARY NULL NULL NULL 12 2 RECURSIVE UNION ALL NULL NULL NULL NULL 12 Using where; Using join buffer (flat, BNL join) NULL UNION RESULT ALL NULL NULL NULL NULL NULL -5 RECURSIVE UNION ALL NULL NULL NULL NULL 24 -NULL UNION RESULT ALL NULL NULL NULL NULL NULL explain FORMAT=JSON with recursive prev_gen @@ -3326,13 +3326,13 @@ select * from cte1, cte2; id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY ALL NULL NULL NULL NULL 6 100.00 1 PRIMARY ALL NULL NULL NULL NULL 6 100.00 Using join buffer (flat, BNL join) +2 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +3 RECURSIVE UNION ALL NULL NULL NULL NULL 2 100.00 Using where +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL 4 DERIVED ALL NULL NULL NULL NULL 2 100.00 Using where 4 DERIVED t1 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (flat, BNL join) 5 DERIVED ALL NULL NULL NULL NULL 2 100.00 Using where 5 DERIVED t1 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (flat, BNL join) -2 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used -3 RECURSIVE UNION ALL NULL NULL NULL NULL 2 100.00 Using where -NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL Warnings: Note 1003 with recursive rcte as (select 1 AS `a` union select cast(`rcte`.`a` + 1 as unsigned) AS `cast(a+1 as unsigned)` from `rcte` where `rcte`.`a` < 10), cte1 as (select count(0) AS `c1` from `rcte` join `test`.`t1` where `rcte`.`a` between 3 and 5 and `test`.`t1`.`id` = `rcte`.`a` - 3), cte2 as (select count(0) AS `c2` from `rcte` join `test`.`t1` where `rcte`.`a` between 7 and 8 and `test`.`t1`.`id` = `rcte`.`a` - 7)select `cte1`.`c1` AS `c1`,`cte2`.`c2` AS `c2` from `cte1` join `cte2` prepare stmt from "with recursive @@ -3391,6 +3391,65 @@ cte2 as (select count(*) as c2 from rcte,t1 where a between 7 and 8 and id=a-7) select * from cte1, cte2 where cte1.c1 = 3; c1 c2 +with recursive +rcte(a) as +(select 1 union select cast(a+1 as unsigned) from rcte where a < 10), +cte1 as +(select count(*) as c1 from rcte,t1 where a between 3 and 5 and id=a-3), +cte2 as +(select count(*) as c2 from rcte,t1 where a between 7 and 8 and id=a-7) +select * from cte2, cte1; +c2 c1 +1 2 +explain extended with recursive +rcte(a) as +(select 1 union select cast(a+1 as unsigned) from rcte where a < 10), +cte1 as +(select count(*) as c1 from rcte,t1 where a between 3 and 5 and id=a-3), +cte2 as +(select count(*) as c2 from rcte,t1 where a between 7 and 8 and id=a-7) +select * from cte2, cte1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 6 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 6 100.00 Using join buffer (flat, BNL join) +2 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +3 RECURSIVE UNION ALL NULL NULL NULL NULL 2 100.00 Using where +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +5 DERIVED ALL NULL NULL NULL NULL 2 100.00 Using where +5 DERIVED t1 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (flat, BNL join) +4 DERIVED ALL NULL NULL NULL NULL 2 100.00 Using where +4 DERIVED t1 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 with recursive rcte as (select 1 AS `a` union select cast(`rcte`.`a` + 1 as unsigned) AS `cast(a+1 as unsigned)` from `rcte` where `rcte`.`a` < 10), cte1 as (select count(0) AS `c1` from `rcte` join `test`.`t1` where `rcte`.`a` between 3 and 5 and `test`.`t1`.`id` = `rcte`.`a` - 3), cte2 as (select count(0) AS `c2` from `rcte` join `test`.`t1` where `rcte`.`a` between 7 and 8 and `test`.`t1`.`id` = `rcte`.`a` - 7)select `cte2`.`c2` AS `c2`,`cte1`.`c1` AS `c1` from `cte2` join `cte1` +prepare stmt from "with recursive +rcte(a) as +(select 1 union select cast(a+1 as unsigned) from rcte where a < 10), +cte1 as +(select count(*) as c1 from rcte,t1 where a between 3 and 5 and id=a-3), +cte2 as +(select count(*) as c2 from rcte,t1 where a between 7 and 8 and id=a-7) +select * from cte2, cte1"; +execute stmt; +c2 c1 +1 2 +execute stmt; +c2 c1 +1 2 +drop procedure p; +drop table t2; +create table t2 (c1 int, c2 int); +create procedure p() insert into t2 with recursive +rcte(a) as +(select 1 union select cast(a+1 as unsigned) from rcte where a < 10), +cte1 as +(select count(*) as c1 from rcte,t1 where a between 3 and 5 and id=a-3), +cte2 as +(select count(*) as c2 from rcte,t1 where a between 7 and 8 and id=a-7) +select * from cte2, cte1; +call p(); +select * from t2; +c1 c2 +1 2 drop procedure p; drop table t1,t2; # @@ -3809,4 +3868,101 @@ ANALYZE } drop function f1; drop table t1,t2; -End of 10.2 tests +# +# MDEV-22748: two materialized CTEs using the same recursive CTE +# (see also test case for MDEV-17024) +# +CREATE TABLE t1 (YEAR int(4), d1 date , d2 date) ; +INSERT INTO t1 VALUES (2018,'2018-01-01','2018-09-20'); +CREATE TABLE t2 (id int, tm date); +INSERT INTO t2 VALUES (1,'2018-08-30'),(2,'2018-08-30'),(3,'2018-08-30'); +CREATE TABLE t3 (id int, tm date); +INSERT INTO t3 VALUES (1,'2018-08-30'),(2,'2018-08-30'); +WITH RECURSIVE +cte AS +(SELECT YEAR(t1.d1) AS YEAR, t1.d1 AS st, t1.d1 + INTERVAL 1 MONTH AS fn +FROM t1 +UNION ALL +SELECT YEAR(cte.st + INTERVAL 1 MONTH), +cte.st + INTERVAL 1 MONTH, t1.d2 + INTERVAL 1 DAY +FROM cte JOIN t1 +WHERE cte.st + INTERVAL 1 MONTH < t1.d2 ), +cte2 AS (SELECT YEAR, COUNT(*) +FROM cte JOIN t2 ON t2.tm BETWEEN cte.st AND cte.fn), +cte3 AS (SELECT YEAR, COUNT(*) +FROM cte JOIN t3 ON t3.tm BETWEEN cte.st AND cte.fn) +SELECT t1.* FROM t1 JOIN cte2 USING (YEAR) JOIN cte3 USING (YEAR); +YEAR d1 d2 +2018 2018-01-01 2018-09-20 +EXPLAIN EXTENDED WITH RECURSIVE +cte AS +(SELECT YEAR(t1.d1) AS YEAR, t1.d1 AS st, t1.d1 + INTERVAL 1 MONTH AS fn +FROM t1 +UNION ALL +SELECT YEAR(cte.st + INTERVAL 1 MONTH), +cte.st + INTERVAL 1 MONTH, t1.d2 + INTERVAL 1 DAY +FROM cte JOIN t1 +WHERE cte.st + INTERVAL 1 MONTH < t1.d2 ), +cte2 AS (SELECT YEAR, COUNT(*) +FROM cte JOIN t2 ON t2.tm BETWEEN cte.st AND cte.fn), +cte3 AS (SELECT YEAR, COUNT(*) +FROM cte JOIN t3 ON t3.tm BETWEEN cte.st AND cte.fn) +SELECT t1.* FROM t1 JOIN cte2 USING (YEAR) JOIN cte3 USING (YEAR); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 system NULL NULL NULL NULL 1 100.00 +1 PRIMARY ref key0 key0 9 const 0 0.00 Using where +1 PRIMARY ref key0 key0 9 const 0 0.00 Using where +2 DERIVED t1 system NULL NULL NULL NULL 1 100.00 +3 RECURSIVE UNION t1 system NULL NULL NULL NULL 1 100.00 +3 RECURSIVE UNION ALL NULL NULL NULL NULL 2 100.00 Using where +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +4 DERIVED ALL NULL NULL NULL NULL 2 100.00 +4 DERIVED t2 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (flat, BNL join) +5 DERIVED ALL NULL NULL NULL NULL 2 100.00 +5 DERIVED t3 ALL NULL NULL NULL NULL 2 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 with recursive cte as (select year(`test`.`t1`.`d1`) AS `YEAR`,`test`.`t1`.`d1` AS `st`,`test`.`t1`.`d1` + interval 1 month AS `fn` from `test`.`t1` union all select year(`cte`.`st` + interval 1 month) AS `YEAR(cte.st + INTERVAL 1 MONTH)`,`cte`.`st` + interval 1 month AS `cte.st + INTERVAL 1 MONTH`,`test`.`t1`.`d2` + interval 1 day AS `t1.d2 + INTERVAL 1 DAY` from `cte` join `test`.`t1` where `cte`.`st` + interval 1 month < `test`.`t1`.`d2`), cte2 as (select `cte`.`YEAR` AS `YEAR`,count(0) AS `COUNT(*)` from `cte` join `test`.`t2` where `test`.`t2`.`tm` between `cte`.`st` and `cte`.`fn`), cte3 as (select `cte`.`YEAR` AS `YEAR`,count(0) AS `COUNT(*)` from `cte` join `test`.`t3` where `test`.`t3`.`tm` between `cte`.`st` and `cte`.`fn`)select 2018 AS `YEAR`,'2018-01-01' AS `d1`,'2018-09-20' AS `d2` from `cte2` join `cte3` where 2018 = `cte3`.`YEAR` and 2018 = `cte2`.`YEAR` +PREPARE stmt FROM "WITH RECURSIVE +cte AS +(SELECT YEAR(t1.d1) AS YEAR, t1.d1 AS st, t1.d1 + INTERVAL 1 MONTH AS fn +FROM t1 +UNION ALL +SELECT YEAR(cte.st + INTERVAL 1 MONTH), +cte.st + INTERVAL 1 MONTH, t1.d2 + INTERVAL 1 DAY +FROM cte JOIN t1 +WHERE cte.st + INTERVAL 1 MONTH < t1.d2 ), +cte2 AS (SELECT YEAR, COUNT(*) +FROM cte JOIN t2 ON t2.tm BETWEEN cte.st AND cte.fn), +cte3 AS (SELECT YEAR, COUNT(*) +FROM cte JOIN t3 ON t3.tm BETWEEN cte.st AND cte.fn) +SELECT t1.* FROM t1 JOIN cte2 USING (YEAR) JOIN cte3 USING (YEAR)"; +EXECUTE stmt; +YEAR d1 d2 +2018 2018-01-01 2018-09-20 +EXECUTE stmt; +YEAR d1 d2 +2018 2018-01-01 2018-09-20 +CREATE TABLE t4 (YEAR int(4), d1 date , d2 date); +CREATE PROCEDURE p() INSERT INTO t4 WITH RECURSIVE +cte AS +(SELECT YEAR(t1.d1) AS YEAR, t1.d1 AS st, t1.d1 + INTERVAL 1 MONTH AS fn +FROM t1 +UNION ALL +SELECT YEAR(cte.st + INTERVAL 1 MONTH), +cte.st + INTERVAL 1 MONTH, t1.d2 + INTERVAL 1 DAY +FROM cte JOIN t1 +WHERE cte.st + INTERVAL 1 MONTH < t1.d2 ), +cte2 AS (SELECT YEAR, COUNT(*) +FROM cte JOIN t2 ON t2.tm BETWEEN cte.st AND cte.fn), +cte3 AS (SELECT YEAR, COUNT(*) +FROM cte JOIN t3 ON t3.tm BETWEEN cte.st AND cte.fn) +SELECT t1.* FROM t1 JOIN cte2 USING (YEAR) JOIN cte3 USING (YEAR); +CALL p(); +SELECT * FROM t4; +YEAR d1 d2 +2018 2018-01-01 2018-09-20 +DROP PROCEDURE p; +DROP TABLE t1,t2,t3,t4; +# +# End of 10.2 tests +# diff --git a/mysql-test/t/cte_recursive.test b/mysql-test/t/cte_recursive.test index 1c0280f065e..d1904586ffe 100644 --- a/mysql-test/t/cte_recursive.test +++ b/mysql-test/t/cte_recursive.test @@ -2390,6 +2390,30 @@ select * from cte1, cte2 where cte1.c1 = 3; eval $q3; +let $q4= +with recursive +rcte(a) as +(select 1 union select cast(a+1 as unsigned) from rcte where a < 10), +cte1 as +(select count(*) as c1 from rcte,t1 where a between 3 and 5 and id=a-3), +cte2 as +(select count(*) as c2 from rcte,t1 where a between 7 and 8 and id=a-7) +select * from cte2, cte1; + +eval $q4; +eval explain extended $q4; +eval prepare stmt from "$q4"; +execute stmt; +execute stmt; + +drop procedure p; +drop table t2; + +create table t2 (c1 int, c2 int); +eval create procedure p() insert into t2 $q4; +call p(); +select * from t2; + drop procedure p; drop table t1,t2; @@ -2574,4 +2598,48 @@ eval analyze format=json $q; drop function f1; drop table t1,t2; ---echo End of 10.2 tests +--echo # +--echo # MDEV-22748: two materialized CTEs using the same recursive CTE +--echo # (see also test case for MDEV-17024) +--echo # + +CREATE TABLE t1 (YEAR int(4), d1 date , d2 date) ; +INSERT INTO t1 VALUES (2018,'2018-01-01','2018-09-20'); +CREATE TABLE t2 (id int, tm date); +INSERT INTO t2 VALUES (1,'2018-08-30'),(2,'2018-08-30'),(3,'2018-08-30'); +CREATE TABLE t3 (id int, tm date); +INSERT INTO t3 VALUES (1,'2018-08-30'),(2,'2018-08-30'); + +let $q= +WITH RECURSIVE +cte AS + (SELECT YEAR(t1.d1) AS YEAR, t1.d1 AS st, t1.d1 + INTERVAL 1 MONTH AS fn + FROM t1 + UNION ALL + SELECT YEAR(cte.st + INTERVAL 1 MONTH), + cte.st + INTERVAL 1 MONTH, t1.d2 + INTERVAL 1 DAY + FROM cte JOIN t1 + WHERE cte.st + INTERVAL 1 MONTH < t1.d2 ), +cte2 AS (SELECT YEAR, COUNT(*) + FROM cte JOIN t2 ON t2.tm BETWEEN cte.st AND cte.fn), +cte3 AS (SELECT YEAR, COUNT(*) + FROM cte JOIN t3 ON t3.tm BETWEEN cte.st AND cte.fn) +SELECT t1.* FROM t1 JOIN cte2 USING (YEAR) JOIN cte3 USING (YEAR); + +eval $q; +eval EXPLAIN EXTENDED $q; +eval PREPARE stmt FROM "$q"; +EXECUTE stmt; +EXECUTE stmt; + +CREATE TABLE t4 (YEAR int(4), d1 date , d2 date); +eval CREATE PROCEDURE p() INSERT INTO t4 $q; +CALL p(); +SELECT * FROM t4; + +DROP PROCEDURE p; +DROP TABLE t1,t2,t3,t4; + +--echo # +--echo # End of 10.2 tests +--echo # diff --git a/sql/sql_cte.cc b/sql/sql_cte.cc index d922a7a7551..fe8e0de71b4 100644 --- a/sql/sql_cte.cc +++ b/sql/sql_cte.cc @@ -1099,6 +1099,7 @@ bool TABLE_LIST::set_as_with_table(THD *thd, With_element *with_elem) { derived= with_elem->spec; if (derived != select_lex->master_unit() && + !with_elem->is_recursive && !is_with_table_recursive_reference()) { derived->move_as_slave(select_lex); diff --git a/sql/sql_derived.cc b/sql/sql_derived.cc index 6785bf8e815..39499e6895f 100644 --- a/sql/sql_derived.cc +++ b/sql/sql_derived.cc @@ -1054,7 +1054,6 @@ bool mysql_derived_fill(THD *thd, LEX *lex, TABLE_LIST *derived) DBUG_ASSERT(derived->table && derived->table->is_created()); select_union *derived_result= derived->derived_result; SELECT_LEX *save_current_select= lex->current_select; - bool derived_recursive_is_filled= false; if (derived_is_recursive) { @@ -1067,7 +1066,6 @@ bool mysql_derived_fill(THD *thd, LEX *lex, TABLE_LIST *derived) { /* In this case all iteration are performed */ res= derived->fill_recursive(thd); - derived_recursive_is_filled= true; } } else if (unit->is_union()) @@ -1123,9 +1121,7 @@ bool mysql_derived_fill(THD *thd, LEX *lex, TABLE_LIST *derived) } } - if (res || (!lex->describe && - (!derived_is_recursive || - derived_recursive_is_filled))) + if (res || (!lex->describe && !derived_is_recursive)) unit->cleanup(); lex->current_select= save_current_select; diff --git a/sql/sql_union.cc b/sql/sql_union.cc index 7e4d06b03f2..b2198eb2b31 100644 --- a/sql/sql_union.cc +++ b/sql/sql_union.cc @@ -1540,6 +1540,19 @@ bool st_select_lex::cleanup() delete join; join= 0; } + for (TABLE_LIST *tbl= get_table_list(); tbl; tbl= tbl->next_local) + { + if (tbl->is_recursive_with_table() && + !tbl->is_with_table_recursive_reference()) + { + /* + If query is killed before open_and_process_table() for tbl + is called then 'with' is already set, but 'derived' is not. + */ + st_select_lex_unit *unit= tbl->with->spec; + error|= (bool) error | (uint) unit->cleanup(); + } + } for (SELECT_LEX_UNIT *lex_unit= first_inner_unit(); lex_unit ; lex_unit= lex_unit->next_unit()) { From fad348a9a69211351c3b27b21ba03ef910c8f623 Mon Sep 17 00:00:00 2001 From: Alexander Barkov Date: Sun, 7 Jun 2020 16:23:47 +0400 Subject: [PATCH 2/5] MDEV-22822 sql_mode="oracle" cannot declare without variable errors --- .../suite/compat/oracle/r/parser.result | 34 ++++++++++++++ mysql-test/suite/compat/oracle/t/parser.test | 47 +++++++++++++++++++ sql/sql_yacc_ora.yy | 4 +- 3 files changed, 83 insertions(+), 2 deletions(-) diff --git a/mysql-test/suite/compat/oracle/r/parser.result b/mysql-test/suite/compat/oracle/r/parser.result index 1c60c1434a3..0b573027c6d 100644 --- a/mysql-test/suite/compat/oracle/r/parser.result +++ b/mysql-test/suite/compat/oracle/r/parser.result @@ -607,5 +607,39 @@ ERROR HY000: Unknown system variable 'password' SELECT @@GLOBAL.role; ERROR HY000: Unknown system variable 'role' # +# MDEV-22822 sql_mode="oracle" cannot declare without variable errors +# +# It's OK to have no declarations between DECLARE and BEGIN. +# +BEGIN +DECLARE +BEGIN +NULL; +END; +EXCEPTION +WHEN OTHERS THEN +NULL; +END; +// +DECLARE +BEGIN +NULL; +EXCEPTION +WHEN OTHERS THEN +NULL; +END; +// +BEGIN +<> +DECLARE +BEGIN +NULL; +END; +EXCEPTION +WHEN OTHERS THEN +NULL; +END; +// +# # End of 10.3 tests # diff --git a/mysql-test/suite/compat/oracle/t/parser.test b/mysql-test/suite/compat/oracle/t/parser.test index 067fd9beb48..4d558c5d153 100644 --- a/mysql-test/suite/compat/oracle/t/parser.test +++ b/mysql-test/suite/compat/oracle/t/parser.test @@ -409,6 +409,53 @@ SELECT @@GLOBAL.password; SELECT @@GLOBAL.role; +--echo # +--echo # MDEV-22822 sql_mode="oracle" cannot declare without variable errors +--echo # +--echo # It's OK to have no declarations between DECLARE and BEGIN. +--echo # + +DELIMITER //; +BEGIN + DECLARE + BEGIN + NULL; + END; +EXCEPTION +WHEN OTHERS THEN + NULL; +END; +// +DELIMITER ;// + + +DELIMITER //; +DECLARE +BEGIN + NULL; +EXCEPTION +WHEN OTHERS THEN + NULL; +END; +// +DELIMITER ;// + + +DELIMITER //; +BEGIN +<> + DECLARE + BEGIN + NULL; + END; +EXCEPTION +WHEN OTHERS THEN + NULL; +END; +// +DELIMITER ;// + + --echo # --echo # End of 10.3 tests --echo # diff --git a/sql/sql_yacc_ora.yy b/sql/sql_yacc_ora.yy index 60ff19e06b2..942f7892f04 100644 --- a/sql/sql_yacc_ora.yy +++ b/sql/sql_yacc_ora.yy @@ -4463,7 +4463,7 @@ sp_labeled_block: { Lex->sp_block_init(thd, &$1); } - sp_decl_body_list + opt_sp_decl_body_list { if (unlikely(Lex->sp_block_with_exceptions_finalize_declarations(thd))) MYSQL_YYABORT; @@ -4505,7 +4505,7 @@ sp_unlabeled_block: MYSQL_YYABORT; Lex->sp_block_init(thd); } - sp_decl_body_list + opt_sp_decl_body_list { if (unlikely(Lex->sp_block_with_exceptions_finalize_declarations(thd))) MYSQL_YYABORT; From e6a6382f15834943ce3814e4f30debe58076e24d Mon Sep 17 00:00:00 2001 From: Monty Date: Sun, 7 Jun 2020 16:23:44 +0300 Subject: [PATCH 3/5] Don't allow illegal create options for SEQUENCE MDEV-19977 Assertion `(0xFUL & mode) == LOCK_S || (0xFUL & mode) == LOCK_X' failed in lock_rec_lock --- mysql-test/suite/sql_sequence/alter.result | 4 ++ mysql-test/suite/sql_sequence/alter.test | 10 +++++ mysql-test/suite/sql_sequence/create.result | 34 +++++++++++++++++ mysql-test/suite/sql_sequence/create.test | 42 +++++++++++++++++++++ sql/sql_sequence.cc | 8 +++- 5 files changed, 97 insertions(+), 1 deletion(-) diff --git a/mysql-test/suite/sql_sequence/alter.result b/mysql-test/suite/sql_sequence/alter.result index 3cf085bc948..2ac8ac07994 100644 --- a/mysql-test/suite/sql_sequence/alter.result +++ b/mysql-test/suite/sql_sequence/alter.result @@ -238,3 +238,7 @@ select next value for t1; next value for t1 90 drop sequence t1; +CREATE SEQUENCE t1 engine=innodb; +ALTER IGNORE TABLE t1 ADD CHECK (start_value < minimum_value); +ERROR HY000: Sequence 'test.t1' table structure is invalid (Sequence tables cannot have any constraints) +DROP SEQUENCE t1; diff --git a/mysql-test/suite/sql_sequence/alter.test b/mysql-test/suite/sql_sequence/alter.test index fd1809ccd2f..7132c45ef07 100644 --- a/mysql-test/suite/sql_sequence/alter.test +++ b/mysql-test/suite/sql_sequence/alter.test @@ -139,3 +139,13 @@ select next value for t1; alter sequence t1 restart with 90; select next value for t1; drop sequence t1; + +# +# MDEV-19977 Assertion `(0xFUL & mode) == LOCK_S || (0xFUL & mode) == LOCK_X' +# failed in lock_rec_lock +# + +CREATE SEQUENCE t1 engine=innodb; +--error ER_SEQUENCE_INVALID_TABLE_STRUCTURE +ALTER IGNORE TABLE t1 ADD CHECK (start_value < minimum_value); +DROP SEQUENCE t1; diff --git a/mysql-test/suite/sql_sequence/create.result b/mysql-test/suite/sql_sequence/create.result index 55d45a75abf..14464c60e99 100644 --- a/mysql-test/suite/sql_sequence/create.result +++ b/mysql-test/suite/sql_sequence/create.result @@ -375,6 +375,40 @@ CREATE OR REPLACE TABLE t1 ( key key1 (next_not_cached_value) ) sequence=1; ERROR HY000: Sequence 'test.t1' table structure is invalid (Sequence tables cannot have any keys) +CREATE TABLE t1 ( +`next_not_cached_value` bigint(21) NOT NULL, +`minimum_value` bigint(21) NOT NULL, +`maximum_value` bigint(21) NOT NULL, +`start_value` bigint(21) NOT NULL, +`increment` bigint(21) NOT NULL, +`cache_size` bigint(21) unsigned NOT NULL, +`cycle_option` tinyint(1) unsigned NOT NULL, +`cycle_count` bigint(21) NOT NULL, +CHECK (start_value < minimum_value) +) sequence=1; +ERROR HY000: Sequence 'test.t1' table structure is invalid (Sequence tables cannot have any constraints) +CREATE TABLE t1 ( +`next_not_cached_value` bigint(21) NOT NULL, +`minimum_value` bigint(21) NOT NULL, +`maximum_value` bigint(21) NOT NULL, +`start_value` bigint(21) NOT NULL CHECK (start_value < minimum_value), +`increment` bigint(21) NOT NULL, +`cache_size` bigint(21) unsigned NOT NULL, +`cycle_option` tinyint(1) unsigned NOT NULL, +`cycle_count` bigint(21) NOT NULL +) sequence=1; +ERROR HY000: Sequence 'test.t1' table structure is invalid (start_value) +CREATE TABLE t1 ( +`next_not_cached_value` bigint(21) NOT NULL, +`minimum_value` bigint(21) NOT NULL, +`maximum_value` bigint(21) NOT NULL, +`start_value` bigint(21) NOT NULL, +`increment` bigint(21) NOT NULL, +`cache_size` bigint(21) unsigned NOT NULL, +`cycle_option` tinyint(1) unsigned NOT NULL, +`cycle_count` bigint(21) generated always as (1) virtual +) sequence=1; +ERROR HY000: Sequence 'test.t1' table structure is invalid (cycle_count) drop sequence if exists t1; Warnings: Note 4091 Unknown SEQUENCE: 'test.t1' diff --git a/mysql-test/suite/sql_sequence/create.test b/mysql-test/suite/sql_sequence/create.test index 1bc62117526..2c41fb3658b 100644 --- a/mysql-test/suite/sql_sequence/create.test +++ b/mysql-test/suite/sql_sequence/create.test @@ -270,6 +270,48 @@ CREATE OR REPLACE TABLE t1 ( key key1 (next_not_cached_value) ) sequence=1; +# Check constraint + +--error ER_SEQUENCE_INVALID_TABLE_STRUCTURE +CREATE TABLE t1 ( + `next_not_cached_value` bigint(21) NOT NULL, + `minimum_value` bigint(21) NOT NULL, + `maximum_value` bigint(21) NOT NULL, + `start_value` bigint(21) NOT NULL, + `increment` bigint(21) NOT NULL, + `cache_size` bigint(21) unsigned NOT NULL, + `cycle_option` tinyint(1) unsigned NOT NULL, + `cycle_count` bigint(21) NOT NULL, + CHECK (start_value < minimum_value) +) sequence=1; + +--error ER_SEQUENCE_INVALID_TABLE_STRUCTURE +CREATE TABLE t1 ( + `next_not_cached_value` bigint(21) NOT NULL, + `minimum_value` bigint(21) NOT NULL, + `maximum_value` bigint(21) NOT NULL, + `start_value` bigint(21) NOT NULL CHECK (start_value < minimum_value), + `increment` bigint(21) NOT NULL, + `cache_size` bigint(21) unsigned NOT NULL, + `cycle_option` tinyint(1) unsigned NOT NULL, + `cycle_count` bigint(21) NOT NULL +) sequence=1; + + +# Virtual field + +--error ER_SEQUENCE_INVALID_TABLE_STRUCTURE +CREATE TABLE t1 ( + `next_not_cached_value` bigint(21) NOT NULL, + `minimum_value` bigint(21) NOT NULL, + `maximum_value` bigint(21) NOT NULL, + `start_value` bigint(21) NOT NULL, + `increment` bigint(21) NOT NULL, + `cache_size` bigint(21) unsigned NOT NULL, + `cycle_option` tinyint(1) unsigned NOT NULL, + `cycle_count` bigint(21) generated always as (1) virtual +) sequence=1; + drop sequence if exists t1; # diff --git a/sql/sql_sequence.cc b/sql/sql_sequence.cc index 96c1cd19433..68d9efb3093 100644 --- a/sql/sql_sequence.cc +++ b/sql/sql_sequence.cc @@ -203,6 +203,11 @@ bool check_sequence_fields(LEX *lex, List *fields) reason= "Sequence tables cannot have any keys"; goto err; } + if (lex->alter_info.check_constraint_list.elements > 0) + { + reason= "Sequence tables cannot have any constraints"; + goto err; + } for (field_no= 0; (field= it++); field_no++) { @@ -210,7 +215,8 @@ bool check_sequence_fields(LEX *lex, List *fields) if (my_strcasecmp(system_charset_info, field_def->field_name, field->field_name.str) || field->flags != field_def->flags || - field->type_handler() != field_def->type_handler) + field->type_handler() != field_def->type_handler || + field->check_constraint || field->vcol_info) { reason= field->field_name.str; goto err; From a9bee9884aed7d9221bf028138349a1e7b5c984c Mon Sep 17 00:00:00 2001 From: Monty Date: Sun, 7 Jun 2020 16:30:50 +0300 Subject: [PATCH 4/5] Don't allow ALTER TABLE ... ORDER BY on SEQUENCE objects MDEV-19320 Sequence gets corrupted and produces ER_KEY_NOT_FOUND (Can't find record) after ALTER .. ORDER BY --- mysql-test/suite/sql_sequence/alter.result | 7 +++++++ mysql-test/suite/sql_sequence/alter.test | 11 +++++++++++ sql/sql_sequence.cc | 5 +++++ 3 files changed, 23 insertions(+) diff --git a/mysql-test/suite/sql_sequence/alter.result b/mysql-test/suite/sql_sequence/alter.result index 2ac8ac07994..612e2201d26 100644 --- a/mysql-test/suite/sql_sequence/alter.result +++ b/mysql-test/suite/sql_sequence/alter.result @@ -242,3 +242,10 @@ CREATE SEQUENCE t1 engine=innodb; ALTER IGNORE TABLE t1 ADD CHECK (start_value < minimum_value); ERROR HY000: Sequence 'test.t1' table structure is invalid (Sequence tables cannot have any constraints) DROP SEQUENCE t1; +CREATE SEQUENCE s; +ALTER TABLE s ORDER BY cache_size; +ERROR HY000: Sequence 'test.s' table structure is invalid (ORDER BY) +SELECT NEXTVAL(s); +NEXTVAL(s) +1 +DROP SEQUENCE s; diff --git a/mysql-test/suite/sql_sequence/alter.test b/mysql-test/suite/sql_sequence/alter.test index 7132c45ef07..53f71018337 100644 --- a/mysql-test/suite/sql_sequence/alter.test +++ b/mysql-test/suite/sql_sequence/alter.test @@ -149,3 +149,14 @@ CREATE SEQUENCE t1 engine=innodb; --error ER_SEQUENCE_INVALID_TABLE_STRUCTURE ALTER IGNORE TABLE t1 ADD CHECK (start_value < minimum_value); DROP SEQUENCE t1; + +# +# MDEV-19320 Sequence gets corrupted and produces ER_KEY_NOT_FOUND (Can't +# find record) after ALTER .. ORDER BY +# + +CREATE SEQUENCE s; +--error ER_SEQUENCE_INVALID_TABLE_STRUCTURE +ALTER TABLE s ORDER BY cache_size; +SELECT NEXTVAL(s); +DROP SEQUENCE s; diff --git a/sql/sql_sequence.cc b/sql/sql_sequence.cc index 68d9efb3093..939963de682 100644 --- a/sql/sql_sequence.cc +++ b/sql/sql_sequence.cc @@ -208,6 +208,11 @@ bool check_sequence_fields(LEX *lex, List *fields) reason= "Sequence tables cannot have any constraints"; goto err; } + if (lex->alter_info.flags & ALTER_ORDER) + { + reason= "ORDER BY"; + goto err; + } for (field_no= 0; (field= it++); field_no++) { From f458b40f66f33521ad3e4f0d4ebcbbcc501c89ed Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Marko=20M=C3=A4kel=C3=A4?= Date: Mon, 8 Jun 2020 10:28:34 +0300 Subject: [PATCH 5/5] MDEV-22827 InnoDB: Failing assertion: purge_sys->n_stop == 0 When MDEV-22769 introduced srv_shutdown_state=SRV_SHUTDOWN_INITIATED in commit efc70da5fd0459ff44153529d13651741cc32bc4 we forgot to adjust a few checks for SRV_SHUTDOWN_NONE. In the initial shutdown step, we are waiting for the background DROP TABLE queue to be processed or discarded. At that time, some background tasks (such as buffer pool resizing or dumping or encryption key rotation) may be terminated, but others must remain running normally. srv_purge_coordinator_suspend(), srv_purge_coordinator_thread(), srv_start_wait_for_purge_to_start(): Treat SRV_SHUTDOWN_NONE and SRV_SHUTDOWN_INITIATED equally. --- storage/innobase/srv/srv0srv.cc | 4 ++-- storage/innobase/srv/srv0start.cc | 2 +- 2 files changed, 3 insertions(+), 3 deletions(-) diff --git a/storage/innobase/srv/srv0srv.cc b/storage/innobase/srv/srv0srv.cc index cc85416aac7..6388f84cdea 100644 --- a/storage/innobase/srv/srv0srv.cc +++ b/storage/innobase/srv/srv0srv.cc @@ -2780,7 +2780,7 @@ srv_purge_coordinator_suspend( rw_lock_x_lock(&purge_sys->latch); - stop = (srv_shutdown_state == SRV_SHUTDOWN_NONE + stop = (srv_shutdown_state <= SRV_SHUTDOWN_INITIATED && purge_sys->state == PURGE_STATE_STOP); if (!stop) { @@ -2856,7 +2856,7 @@ DECLARE_THREAD(srv_purge_coordinator_thread)( /* If there are no records to purge or the last purge didn't purge any records then wait for activity. */ - if (srv_shutdown_state == SRV_SHUTDOWN_NONE + if (srv_shutdown_state <= SRV_SHUTDOWN_INITIATED && srv_undo_sources && (purge_sys->state == PURGE_STATE_STOP || n_total_purged == 0)) { diff --git a/storage/innobase/srv/srv0start.cc b/storage/innobase/srv/srv0start.cc index 8efae318ee0..8479847f779 100644 --- a/storage/innobase/srv/srv0start.cc +++ b/storage/innobase/srv/srv0start.cc @@ -1092,7 +1092,7 @@ srv_start_wait_for_purge_to_start() ut_a(state != PURGE_STATE_DISABLED); - while (srv_shutdown_state == SRV_SHUTDOWN_NONE + while (srv_shutdown_state <= SRV_SHUTDOWN_INITIATED && srv_force_recovery < SRV_FORCE_NO_BACKGROUND && state == PURGE_STATE_INIT) {