From dffe3d1fb24f33047c53feae4ff2f4cb429ee31c Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Sun, 26 Jan 2025 20:39:38 -0800 Subject: [PATCH] MDEV-35910 Conditions with SP local variables are not pushed into derived table This bug prevented building conditions that could be pushed into a derived table if the derived table was used in a query of a stored procedure and the conditions contained local variables of the procedure. This could lead to a slow execution of the procedure. Also in some cases the bug prevented building conditions that could be pushed from the HAVING condition into the WHERE condition of a query if the conditions to be built used local variables of a stored procedure. To failure to build such pushable conditions was due to lack of a proper implementation of the virtual method to copy items for the objects of the class Item_splocal. Approved by Igor Babaev who had to change the original fix that just added the regular copying of the nodes of the Item_splocal class to take into account the wrappers do_get_copy() and do_build_clone() introduced after the fix had been prepared. He also changed the test case to demonstrate that the fix was really needed for pushdown from HAVING into WHERE. --- mysql-test/main/sp.result | 176 ++++++++++++++++++++++++++++++++++++++ mysql-test/main/sp.test | 88 +++++++++++++++++++ sql/item.h | 5 +- 3 files changed, 267 insertions(+), 2 deletions(-) diff --git a/mysql-test/main/sp.result b/mysql-test/main/sp.result index 1b3405e47b1..204af23f09f 100644 --- a/mysql-test/main/sp.result +++ b/mysql-test/main/sp.result @@ -8974,3 +8974,179 @@ DROP PROCEDURE p1; DROP PROCEDURE p2; # End of 10.4 tests # +# +# MDEV-35910: Pushdown of conditions with local SP variables +# into materialized derived table +# Pushdown of conditions with local variables from HAVING +# into WHERE +# +CREATE TABLE t1( +pk INT PRIMARY KEY AUTO_INCREMENT, +a INT, +b INT +); +INSERT INTO t1(a,b) VALUES (1, 2), (3, 2), (4, 5); +INSERT INTO t1(a,b) VALUES (3, 7), (4, 1), (3, 4); +CREATE PROCEDURE pushdownDerivedSp() +BEGIN +DECLARE localA INT DEFAULT 1; +DECLARE localB INT DEFAULT 2; +SELECT dt.a +FROM ( +SELECT t1.a, MIN(t1.b) as minB +FROM t1 +GROUP BY t1.a +) AS dt +WHERE dt.minB = localB AND dt.a = localA + localB; +END$$ +CREATE PROCEDURE explainPushdownDerivedSp() +BEGIN +DECLARE localA INT DEFAULT 1; +DECLARE localB INT DEFAULT 2; +EXPLAIN format=json SELECT dt.a +FROM ( +SELECT t1.a, MIN(t1.b) as minB +FROM t1 +GROUP BY t1.a +) AS dt +WHERE dt.minB = localB AND dt.a = localA + localB; +END$$ +CREATE PROCEDURE pushdownFromHavingSp() +BEGIN +DECLARE localA INT DEFAULT 1; +DECLARE localB INT DEFAULT 2; +SELECT t1.a, SUM(b) +FROM t1 +GROUP BY t1.a +HAVING t1.a > localA AND SUM(b) > 10 OR t1.a <= localB AND SUM(b) <= 2; +END$$ +CREATE PROCEDURE explainPushdownFromHavingSp() +BEGIN +DECLARE localA INT DEFAULT 1; +DECLARE localB INT DEFAULT 2; +EXPLAIN format=json +SELECT t1.a, SUM(b) +FROM t1 +GROUP BY t1.a +HAVING t1.a > localA AND SUM(b) > 10 OR t1.a <= localB AND SUM(b) <= 2; +END$$ +CALL pushdownDerivedSp(); +a +3 +set statement optimizer_switch='condition_pushdown_for_derived=off' +for CALL pushdownDerivedSp(); +a +3 +CALL explainPushdownDerivedSp(); +EXPLAIN +{ + "query_block": { + "select_id": 1, + "table": { + "table_name": "", + "access_type": "ALL", + "rows": 6, + "filtered": 100, + "attached_condition": "dt.minB = (localB@1) and dt.a = (localA@0 + localB@1)", + "materialized": { + "query_block": { + "select_id": 2, + "having_condition": "minB = (localB@1)", + "table": { + "table_name": "t1", + "access_type": "ALL", + "rows": 6, + "filtered": 100, + "attached_condition": "t1.a = (localA@0 + localB@1)" + } + } + } + } + } +} +set statement optimizer_switch='condition_pushdown_for_derived=off' for +CALL explainPushdownDerivedSp(); +EXPLAIN +{ + "query_block": { + "select_id": 1, + "table": { + "table_name": "", + "access_type": "ALL", + "rows": 6, + "filtered": 100, + "attached_condition": "dt.minB = (localB@1) and dt.a = (localA@0 + localB@1)", + "materialized": { + "query_block": { + "select_id": 2, + "filesort": { + "sort_key": "t1.a", + "temporary_table": { + "table": { + "table_name": "t1", + "access_type": "ALL", + "rows": 6, + "filtered": 100 + } + } + } + } + } + } + } +} +CALL pushdownFromHavingSp(); +a SUM(b) +1 2 +3 13 +set statement optimizer_switch='condition_pushdown_from_having=off' for +CALL pushdownFromHavingSp(); +a SUM(b) +1 2 +3 13 +CALL explainPushdownFromHavingSp(); +EXPLAIN +{ + "query_block": { + "select_id": 1, + "having_condition": "t1.a > (localA@0) and sum(t1.b) > 10 or t1.a <= (localB@1) and sum(t1.b) <= 2", + "filesort": { + "sort_key": "t1.a", + "temporary_table": { + "table": { + "table_name": "t1", + "access_type": "ALL", + "rows": 6, + "filtered": 100, + "attached_condition": "t1.a > (localA@0) or t1.a <= (localB@1)" + } + } + } + } +} +set statement optimizer_switch='condition_pushdown_from_having=off' for +CALL explainPushdownFromHavingSp(); +EXPLAIN +{ + "query_block": { + "select_id": 1, + "having_condition": "t1.a > (localA@0) and sum(t1.b) > 10 or t1.a <= (localB@1) and sum(t1.b) <= 2", + "filesort": { + "sort_key": "t1.a", + "temporary_table": { + "table": { + "table_name": "t1", + "access_type": "ALL", + "rows": 6, + "filtered": 100 + } + } + } + } +} +DROP PROCEDURE pushdownDerivedSp; +DROP PROCEDURE explainPushdownDerivedSp; +DROP PROCEDURE pushdownFromHavingSp; +DROP PROCEDURE explainPushdownFromHavingSp; +DROP TABLE t1; +# End of 10.5 tests diff --git a/mysql-test/main/sp.test b/mysql-test/main/sp.test index c1e107b69e1..7799e34210a 100644 --- a/mysql-test/main/sp.test +++ b/mysql-test/main/sp.test @@ -10593,3 +10593,91 @@ DROP PROCEDURE p2; --echo # End of 10.4 tests --echo # +--echo # +--echo # MDEV-35910: Pushdown of conditions with local SP variables +--echo # into materialized derived table +--echo # Pushdown of conditions with local variables from HAVING +--echo # into WHERE +--echo # + +CREATE TABLE t1( + pk INT PRIMARY KEY AUTO_INCREMENT, + a INT, + b INT +); +INSERT INTO t1(a,b) VALUES (1, 2), (3, 2), (4, 5); +INSERT INTO t1(a,b) VALUES (3, 7), (4, 1), (3, 4); + +DELIMITER $$; +CREATE PROCEDURE pushdownDerivedSp() +BEGIN + DECLARE localA INT DEFAULT 1; + DECLARE localB INT DEFAULT 2; + SELECT dt.a + FROM ( + SELECT t1.a, MIN(t1.b) as minB + FROM t1 + GROUP BY t1.a + ) AS dt + WHERE dt.minB = localB AND dt.a = localA + localB; +END$$ + +CREATE PROCEDURE explainPushdownDerivedSp() +BEGIN + DECLARE localA INT DEFAULT 1; + DECLARE localB INT DEFAULT 2; + EXPLAIN format=json SELECT dt.a + FROM ( + SELECT t1.a, MIN(t1.b) as minB + FROM t1 + GROUP BY t1.a + ) AS dt + WHERE dt.minB = localB AND dt.a = localA + localB; +END$$ + +CREATE PROCEDURE pushdownFromHavingSp() +BEGIN + DECLARE localA INT DEFAULT 1; + DECLARE localB INT DEFAULT 2; + SELECT t1.a, SUM(b) + FROM t1 + GROUP BY t1.a + HAVING t1.a > localA AND SUM(b) > 10 OR t1.a <= localB AND SUM(b) <= 2; +END$$ + +CREATE PROCEDURE explainPushdownFromHavingSp() +BEGIN + DECLARE localA INT DEFAULT 1; + DECLARE localB INT DEFAULT 2; + EXPLAIN format=json + SELECT t1.a, SUM(b) + FROM t1 + GROUP BY t1.a + HAVING t1.a > localA AND SUM(b) > 10 OR t1.a <= localB AND SUM(b) <= 2; +END$$ + +DELIMITER ;$$ + +CALL pushdownDerivedSp(); +set statement optimizer_switch='condition_pushdown_for_derived=off' +for CALL pushdownDerivedSp(); + +CALL explainPushdownDerivedSp(); +set statement optimizer_switch='condition_pushdown_for_derived=off' for +CALL explainPushdownDerivedSp(); + +CALL pushdownFromHavingSp(); +set statement optimizer_switch='condition_pushdown_from_having=off' for +CALL pushdownFromHavingSp(); + +CALL explainPushdownFromHavingSp(); +set statement optimizer_switch='condition_pushdown_from_having=off' for +CALL explainPushdownFromHavingSp(); + +DROP PROCEDURE pushdownDerivedSp; +DROP PROCEDURE explainPushdownDerivedSp; +DROP PROCEDURE pushdownFromHavingSp; +DROP PROCEDURE explainPushdownFromHavingSp; +DROP TABLE t1; + +--echo # End of 10.5 tests diff --git a/sql/item.h b/sql/item.h index a146107508f..ce02b0edda1 100644 --- a/sql/item.h +++ b/sql/item.h @@ -3099,8 +3099,9 @@ public: bool append_for_log(THD *thd, String *str) override; - Item *do_get_copy(THD *) const override { return nullptr; } - Item *do_build_clone(THD *thd) const override { return nullptr; } + Item *do_get_copy(THD *thd) const override + { return get_item_copy(thd, this); } + Item *do_build_clone(THD *thd) const override { return get_copy(thd); } /* Override the inherited create_field_for_create_select(),