MDEV-30073 Wrong result on 2nd execution of PS for query with NOT EXISTS
Items allocated on execution memory are involved in permanent
optimizer transformations. This commit reallocates these items
to statement memory.
Queries affected by this bug are numerous, but will always involve
1) 2nd execution of a prepared statement or procedure
2) a permanent transformation, such as a semi-join optimization
The fix mainly affects the operation of Item*::fix_fields
--echo # MDEV-29179 Condition pushdown from HAVING into WHERE is not shown in optimizer trace
--echo #
#Enable after fix MDEV-32034
--disable_view_protocol
CREATE TABLE t1 (a INT, b VARCHAR(1), KEY (a), KEY(b,a)) ENGINE=MEMORY;
INSERT INTO t1 VALUES (4,'n'),(1,'h'),(NULL,'w');
SET optimizer_trace= 'enabled=on';
SELECT b, a FROM t1 WHERE b <> 'p' OR a = 4 GROUP BY b, a HAVING a <= 7; SELECT json_detailed(json_extract(trace, '$**.steps[*].join_optimization.steps[*].condition_pushdown_from_having') ) exp1, JSON_VALID(trace) exp2 FROM information_schema.optimizer_trace;
DROP TABLE t1;
--enable_view_protocol
--echo #
--echo # MDEV-30334 Optimizer trace produces invalid JSON with WHERE subquery
@ -933,11 +888,8 @@ insert into t3 select a,a from t0;
explain
select * from t1 left join (t2 join t3 on t3.pk=1000) on t2.a=t1.a and t2.pk is null;
#Enable after fix MDEV-32034
--disable_view_protocol
select JSON_DETAILED(JSON_EXTRACT(trace, '$**.mark_join_nest_as_const')) as jd
from information_schema.optimizer_trace;
--disable_view_protocol
drop table t0, t1, t2, t3;
@ -953,27 +905,18 @@ set in_predicate_conversion_threshold=3;
explain select * from t0 where a in (1,2,3,4,5,6);
#Enable after fix MDEV-32034
--disable_view_protocol
select json_detailed(json_extract(trace, '$**.in_to_subquery_conversion')) as jd
from information_schema.optimizer_trace;
--enable_view_protocol
explain select * from t0 where a in (1,2,3,4,5,a+1);
#Enable after fix MDEV-32034
--disable_view_protocol
select json_detailed(json_extract(trace, '$**.in_to_subquery_conversion')) as jd
from information_schema.optimizer_trace;
--enable_view_protocol
explain select * from t0 where a in ('1','2','3','4','5','6');
#Enable after fix MDEV-32034
--disable_view_protocol
select json_detailed(json_extract(trace, '$**.in_to_subquery_conversion')) as jd
# MDEV-30073 Wrong result on 2nd execution of PS for query with NOT EXISTS
#
CREATE TABLE t1 (
product_key int,
dealerid int
);
INSERT INTO t1 VALUES
(3569, 4),
(3569, 112);
CREATE TABLE t2 (
id int,
product_key int
);
INSERT INTO t2 VALUES
(16494, 3569),
(16494, 3569);
CREATE TABLE t3 (
dealerid int
);
INSERT INTO t3 VALUES (4), (5);
set optimizer_switch='subquery_cache=off';
EXPLAIN EXTENDED
SELECT * FROM t1
WHERE
! EXISTS
(
SELECT dt.id
FROM (SELECT id, product_key FROM t2) dt, t3
WHERE
dt.product_key = t1.product_key AND
t3.dealerid = t1.dealerid
);
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 2 100.00 Using where
2 MATERIALIZED t2 ALL NULL NULL NULL NULL 2 100.00 Using where
2 MATERIALIZED t3 ALL NULL NULL NULL NULL 2 100.00 Using where; Using join buffer (flat, BNL join)
Warnings:
Note 1276 Field or reference 'test.t1.product_key' of SELECT #2 was resolved in SELECT #1
Note 1276 Field or reference 'test.t1.dealerid' of SELECT #2 was resolved in SELECT #1
Note 1003 /* select#1 */ select `test`.`t1`.`product_key` AS `product_key`,`test`.`t1`.`dealerid` AS `dealerid` from `test`.`t1` where !(<in_optimizer>((`test`.`t1`.`product_key`,`test`.`t1`.`dealerid`),(`test`.`t1`.`product_key`,`test`.`t1`.`dealerid`) in ( <materialize> (/* select#2 */ select `test`.`t2`.`product_key`,`test`.`t3`.`dealerid` from `test`.`t2` join `test`.`t3` where `test`.`t2`.`product_key` is not null and `test`.`t3`.`dealerid` is not null ), <primary_index_lookup>(`test`.`t1`.`product_key` in <temporary table> on distinct_key where `test`.`t1`.`product_key` = `<subquery2>`.`product_key` and `test`.`t1`.`dealerid` = `<subquery2>`.`dealerid`))) and `test`.`t1`.`dealerid` is not null and `test`.`t1`.`product_key` is not null)
SELECT * FROM t1
WHERE
! EXISTS
(
SELECT dt.id
FROM (SELECT id, product_key FROM t2) dt, t3
WHERE
dt.product_key = t1.product_key AND
t3.dealerid = t1.dealerid
);
product_key dealerid
3569 112
PREPARE stmt FROM "
SELECT * FROM t1
WHERE
! EXISTS
(
SELECT dt.id
FROM (SELECT id, product_key FROM t2) dt, t3
WHERE
dt.product_key = t1.product_key AND
t3.dealerid = t1.dealerid
)";
EXECUTE stmt;
product_key dealerid
3569 112
EXECUTE stmt;
product_key dealerid
3569 112
DEALLOCATE PREPARE stmt;
DROP TABLE t1,t2,t3;
CREATE TABLE t1 (a int, b int);
INSERT INTO t1 VALUES (3569, 4), (3569, 112);
CREATE TABLE t2 (c int, a int);
INSERT INTO t2 VALUES (16494, 3569), (16494, 3569);
PREPARE stmt FROM "
SELECT * FROM t1
WHERE EXISTS (SELECT dt.c FROM (SELECT c, a FROM t2) dt WHERE dt.a = t1.a)