MDEV-32086 Server crash when inserting from derived table containing insert target table

Use original solution for INSERT ... SELECT - select result buferisation.

Also fix MDEV-36447 and MDEV-33139
This commit is contained in:
Oleksandr Byelkin 2025-04-01 20:57:29 +02:00
parent 2f5c260f55
commit 9b313d2de1
7 changed files with 260 additions and 79 deletions

View File

@ -10249,9 +10249,8 @@ SELECT * FROM ( SELECT t1.f FROM v1 JOIN t1 ) AS t WHERE f IS NOT NULL;
EXPLAIN INSERT INTO t1
SELECT * FROM ( SELECT t1.f FROM v1 JOIN t1 ) AS t WHERE f IS NOT NULL;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 144 Using where
2 DERIVED <derived4> ALL NULL NULL NULL NULL 12
2 DERIVED t1 ALL NULL NULL NULL NULL 12 Using where; Using join buffer (flat, BNL join)
1 PRIMARY <derived4> ALL NULL NULL NULL NULL 12 Using temporary
1 PRIMARY t1 ALL NULL NULL NULL NULL 12 Using where; Using join buffer (flat, BNL join)
4 DERIVED t1 ALL NULL NULL NULL NULL 12
EXPLAIN FORMAT=JSON INSERT INTO t1
SELECT * FROM ( SELECT t1.f FROM v1 JOIN t1 ) AS t WHERE f IS NOT NULL;
@ -10259,45 +10258,35 @@ EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "<derived2>",
"access_type": "ALL",
"rows": 144,
"filtered": 100,
"attached_condition": "t.f is not null",
"materialized": {
"query_block": {
"select_id": 2,
"table": {
"table_name": "<derived4>",
"access_type": "ALL",
"rows": 12,
"filtered": 100,
"materialized": {
"query_block": {
"select_id": 4,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 12,
"filtered": 100
}
}
}
},
"block-nl-join": {
"temporary_table": {
"table": {
"table_name": "<derived4>",
"access_type": "ALL",
"rows": 12,
"filtered": 100,
"materialized": {
"query_block": {
"select_id": 4,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 12,
"filtered": 100,
"attached_condition": "t1.f is not null"
},
"buffer_type": "flat",
"buffer_size": "64",
"join_type": "BNL"
"filtered": 100
}
}
}
},
"block-nl-join": {
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 12,
"filtered": 100,
"attached_condition": "t1.f is not null"
},
"buffer_type": "flat",
"buffer_size": "64",
"join_type": "BNL"
}
}
}
@ -10328,43 +10317,33 @@ EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "<derived2>",
"access_type": "ALL",
"rows": 16,
"filtered": 100,
"attached_condition": "t.f is not null",
"materialized": {
"query_block": {
"select_id": 2,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 8,
"filtered": 100,
"attached_condition": "t1.f is not null"
},
"table": {
"table_name": "<derived4>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "4",
"used_key_parts": ["f"],
"ref": ["test.t1.f"],
"rows": 2,
"filtered": 100,
"materialized": {
"query_block": {
"select_id": 4,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 8,
"filtered": 100,
"attached_condition": "t1.f is not null"
}
}
"temporary_table": {
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 8,
"filtered": 100,
"attached_condition": "t1.f is not null"
},
"table": {
"table_name": "<derived4>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "4",
"used_key_parts": ["f"],
"ref": ["test.t1.f"],
"rows": 2,
"filtered": 100,
"materialized": {
"query_block": {
"select_id": 4,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 8,
"filtered": 100,
"attached_condition": "t1.f is not null"
}
}
}

View File

@ -2383,6 +2383,8 @@ SELECT * FROM t1;
a
1
1
1
1
drop table t1,t2;
set optimizer_switch=@save968720_optimizer_switch;
#

View File

@ -1030,6 +1030,133 @@ a
3
DROP VIEW v1;
DROP TABLE t1;
create table t1 (pk int, id int);
insert into t1 values (2,2), (3,3), (4,4);
insert into t1
select 1,10
from
(
select dt2.id from (select id from t1) dt2, t1 t where t.id=dt2.id
) dt
where dt.id=3;
select * from t1;
pk id
2 2
3 3
4 4
1 10
explain insert into t1
select 1,10
from
(
select dt2.id from (select id from t1) dt2, t1 t where t.id=dt2.id
) dt
where dt.id=3;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 4 Using where; Using temporary
1 SIMPLE t ALL NULL NULL NULL NULL 4 Using where; Using join buffer (flat, BNL join)
explain format=json insert into t1
select 1,10
from
(
select dt2.id from (select id from t1) dt2, t1 t where t.id=dt2.id
) dt
where dt.id=3;
EXPLAIN
{
"query_block": {
"select_id": 1,
"temporary_table": {
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 4,
"filtered": 100,
"attached_condition": "t1.`id` = 3"
},
"block-nl-join": {
"table": {
"table_name": "t",
"access_type": "ALL",
"rows": 4,
"filtered": 100,
"attached_condition": "t.`id` = 3"
},
"buffer_type": "flat",
"buffer_size": "65",
"join_type": "BNL"
}
}
}
}
prepare stmt from "insert into t1
select 1,10
from
(
select dt2.id from (select id from t1) dt2, t1 t where t.id=dt2.id
) dt
where dt.id=3";
execute stmt;
select * from t1;
pk id
2 2
3 3
4 4
1 10
1 10
execute stmt;
select * from t1;
pk id
2 2
3 3
4 4
1 10
1 10
1 10
deallocate prepare stmt;
create procedure p() insert into t1
select 1,10
from
(
select dt2.id from (select id from t1) dt2, t1 t where t.id=dt2.id
) dt
where dt.id=3;
call p();
select * from t1;
pk id
2 2
3 3
4 4
1 10
1 10
1 10
1 10
call p();
select * from t1;
pk id
2 2
3 3
4 4
1 10
1 10
1 10
1 10
1 10
drop procedure p;
drop table t1;
#
# End of 10.5 test
# MDEV-33139: Crash of INSERT SELECT when preparing structures for
# split optimization
#
CREATE TABLE v0 ( v1 INT UNIQUE ) ;
INSERT INTO v0 ( v1 ) VALUES
( ( SELECT 1
FROM
( SELECT v1
FROM v0 GROUP BY v1 ) AS v6 NATURAL JOIN
v0 AS v2 NATURAL JOIN
v0 AS v4 NATURAL JOIN
v0 AS v3 NATURAL JOIN
( SELECT v1 FROM v0 ) AS v7 ) ) ;
DROP TABLE v0;
# End of 10.5 tests

View File

@ -591,6 +591,60 @@ SELECT * FROM t1;
DROP VIEW v1;
DROP TABLE t1;
#
# MDEV-32086: condition pushdown into two mergeable derived tables,
# one containing the other, when they are forced to be
# materialized in INSERT
#
create table t1 (pk int, id int);
insert into t1 values (2,2), (3,3), (4,4);
let $q=
insert into t1
select 1,10
from
(
select dt2.id from (select id from t1) dt2, t1 t where t.id=dt2.id
) dt
where dt.id=3;
eval $q;
select * from t1;
eval explain $q;
eval explain format=json $q;
eval prepare stmt from "$q";
execute stmt;
select * from t1;
execute stmt;
select * from t1;
deallocate prepare stmt;
eval create procedure p() $q;
call p();
select * from t1;
call p();
select * from t1;
drop procedure p;
drop table t1;
--echo #
--echo # End of 10.5 test
--echo # MDEV-33139: Crash of INSERT SELECT when preparing structures for
--echo # split optimization
--echo #
CREATE TABLE v0 ( v1 INT UNIQUE ) ;
INSERT INTO v0 ( v1 ) VALUES
( ( SELECT 1
FROM
( SELECT v1
FROM v0 GROUP BY v1 ) AS v6 NATURAL JOIN
v0 AS v2 NATURAL JOIN
v0 AS v4 NATURAL JOIN
v0 AS v3 NATURAL JOIN
( SELECT v1 FROM v0 ) AS v7 ) ) ;
DROP TABLE v0;
--echo # End of 10.5 tests

View File

@ -1184,11 +1184,20 @@ retry:
DBUG_PRINT("info",
("found same copy of table or table which we should skip"));
}
if (res && res->belong_to_derived)
/*
If we've found a duplicate in a derived table, try to work around that.
For INSERT...SELECT, do not do any workarounds, return the duplicate. The
caller will enable buffering to handle this.
*/
if (res && res->belong_to_derived &&
!(check_flag & CHECK_DUP_FOR_INSERT_SELECT))
{
/*
We come here for queries of type:
INSERT INTO t1 (SELECT tmp.a FROM (select * FROM t1) as tmp);
We come here for queries like this:
INSERT INTO t1 VALUES ((SELECT tmp.a FROM (select * FROM t1)));
DELETE FROM t1 WHERE ( ... (SELECT ... FROM t1) ) ;
Try to fix by materializing the derived table
*/

View File

@ -72,6 +72,7 @@ enum find_item_error_report_type {REPORT_ALL_ERRORS, REPORT_EXCEPT_NOT_FOUND,
#define CHECK_DUP_ALLOW_DIFFERENT_ALIAS 1
#define CHECK_DUP_FOR_CREATE 2
#define CHECK_DUP_SKIP_TEMP_TABLE 4
#define CHECK_DUP_FOR_INSERT_SELECT 8
uint get_table_def_key(const TABLE_LIST *table_list, const char **key);
TABLE *open_ltable(THD *thd, TABLE_LIST *table_list, thr_lock_type update,

View File

@ -1710,6 +1710,14 @@ int mysql_prepare_insert(THD *thd, TABLE_LIST *table_list,
DBUG_RETURN(1);
}
/*
Check if we read from the same table we're inserting into.
Queries like INSERT INTO t1 VALUES ((SELECT ... FROM t1...)) are not
allowed.
INSERT...SELECT is an exception: it will detect this case and use
buffering to handle it correctly.
*/
if (!select_insert)
{
Item *fake_conds= 0;
@ -4042,7 +4050,8 @@ select_insert::prepare(List<Item> &values, SELECT_LEX_UNIT *u)
Is table which we are changing used somewhere in other parts of
query
*/
if (unique_table(thd, table_list, table_list->next_global, 0))
if (unique_table(thd, table_list, table_list->next_global,
CHECK_DUP_FOR_INSERT_SELECT))
{
/* Using same table for INSERT and SELECT */
lex->current_select->options|= OPTION_BUFFER_RESULT;