mirror of
https://github.com/MariaDB/server.git
synced 2025-12-24 11:21:21 +03:00
MDEV-3900 Optimizer difference between MySQL and MariaDB with stored functions in WHERE clause of UPDATE or DELETE statements
Analysis The reason for the less efficient plan was result of a prior design decision - to limit the eveluation of constant expressions during optimization to only non-expensive ones. With this approach all stored procedures were considered expensive, and were not evaluated during optimization. As a result, SPs didn't participate in range optimization, which resulted in a plan with table scan rather than index range scan. Solution Instead of considering all SPs expensive, consider expensive only those SPs that are non-deterministic. If an SP is deterministic, the optimizer will checj if it is constant, and may eventually evaluate it during optimization.
This commit is contained in:
@@ -6420,16 +6420,16 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref c1 c1 5 const 1 Using index
|
||||
EXPLAIN SELECT * FROM t1 WHERE c1=f1();
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref c1 c1 5 const 0 Using index
|
||||
1 SIMPLE t1 ref c1 c1 5 const 1 Using index
|
||||
EXPLAIN SELECT * FROM v1 WHERE c1=1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref c1 c1 5 const 1 Using index
|
||||
EXPLAIN SELECT * FROM v1 WHERE c1=f1();
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref c1 c1 5 const 0 Using index
|
||||
1 SIMPLE t1 ref c1 c1 5 const 1 Using index
|
||||
EXPLAIN SELECT * FROM t1 WHERE c1=f2(10);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref c1 c1 5 const 0 Using index
|
||||
1 SIMPLE t1 ref c1 c1 5 const 1 Using index
|
||||
EXPLAIN SELECT * FROM t1 WHERE c1=f2(c1);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 index NULL c1 5 NULL 5 Using where; Using index
|
||||
@@ -7146,3 +7146,33 @@ c1 c2 count(c3)
|
||||
2012-03-01 01:00:00 3 1
|
||||
2012-03-01 02:00:00 3 1
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
MDEV-3900 Optimizer difference between MySQL and MariaDB with stored functions in WHERE clause of UPDATE or DELETE statements
|
||||
|
||||
CREATE FUNCTION tdn() RETURNS int(7) DETERMINISTIC RETURN to_days(now());
|
||||
CREATE TABLE t1 (pk INT NOT NULL AUTO_INCREMENT PRIMARY KEY, daynum INT, a CHAR(1), INDEX(daynum), INDEX(a)) ENGINE=MyISAM;
|
||||
INSERT INTO t1 (daynum) VALUES (1),(2),(3),(4),(5),(TO_DAYS(NOW())),(7),(8);
|
||||
INSERT INTO t1 (daynum) SELECT a1.daynum FROM t1 a1, t1 a2, t1 a3, t1 a4, t1 a5;
|
||||
FLUSH TABLES;
|
||||
FLUSH STATUS;
|
||||
SHOW STATUS LIKE '%Handler_read%';
|
||||
Variable_name Value
|
||||
Handler_read_first 0
|
||||
Handler_read_key 0
|
||||
Handler_read_next 0
|
||||
Handler_read_prev 0
|
||||
Handler_read_rnd 0
|
||||
Handler_read_rnd_deleted 0
|
||||
Handler_read_rnd_next 0
|
||||
UPDATE t1 SET a = '+' WHERE daynum=tdn();
|
||||
SHOW STATUS LIKE '%Handler_read%';
|
||||
Variable_name Value
|
||||
Handler_read_first 0
|
||||
Handler_read_key 2
|
||||
Handler_read_next 4097
|
||||
Handler_read_prev 0
|
||||
Handler_read_rnd 0
|
||||
Handler_read_rnd_deleted 0
|
||||
Handler_read_rnd_next 0
|
||||
drop function tdn;
|
||||
drop table t1;
|
||||
|
||||
@@ -8478,3 +8478,22 @@ CALL p1(1);
|
||||
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
--echo
|
||||
--echo MDEV-3900 Optimizer difference between MySQL and MariaDB with stored functions in WHERE clause of UPDATE or DELETE statements
|
||||
--echo
|
||||
|
||||
CREATE FUNCTION tdn() RETURNS int(7) DETERMINISTIC RETURN to_days(now());
|
||||
|
||||
CREATE TABLE t1 (pk INT NOT NULL AUTO_INCREMENT PRIMARY KEY, daynum INT, a CHAR(1), INDEX(daynum), INDEX(a)) ENGINE=MyISAM;
|
||||
INSERT INTO t1 (daynum) VALUES (1),(2),(3),(4),(5),(TO_DAYS(NOW())),(7),(8);
|
||||
INSERT INTO t1 (daynum) SELECT a1.daynum FROM t1 a1, t1 a2, t1 a3, t1 a4, t1 a5;
|
||||
|
||||
FLUSH TABLES;
|
||||
FLUSH STATUS;
|
||||
|
||||
SHOW STATUS LIKE '%Handler_read%';
|
||||
UPDATE t1 SET a = '+' WHERE daynum=tdn();
|
||||
SHOW STATUS LIKE '%Handler_read%';
|
||||
|
||||
drop function tdn;
|
||||
drop table t1;
|
||||
|
||||
@@ -6056,6 +6056,19 @@ Item_func_sp::init_result_field(THD *thd)
|
||||
}
|
||||
|
||||
|
||||
/**
|
||||
@note
|
||||
Deterministic stored procedures are considered inexpensive.
|
||||
Consequently such procedures may be evaluated during optimization,
|
||||
if they are constant (checked by the optimizer).
|
||||
*/
|
||||
|
||||
bool Item_func_sp::is_expensive()
|
||||
{
|
||||
return !(m_sp->m_chistics->detistic);
|
||||
}
|
||||
|
||||
|
||||
/**
|
||||
@brief Initialize local members with values from the Field interface.
|
||||
|
||||
|
||||
@@ -1807,7 +1807,8 @@ private:
|
||||
bool init_result_field(THD *thd);
|
||||
|
||||
protected:
|
||||
bool is_expensive_processor(uchar *arg) { return TRUE; }
|
||||
bool is_expensive_processor(uchar *arg)
|
||||
{ return is_expensive(); }
|
||||
|
||||
public:
|
||||
|
||||
@@ -1881,7 +1882,7 @@ public:
|
||||
|
||||
bool fix_fields(THD *thd, Item **ref);
|
||||
void fix_length_and_dec(void);
|
||||
bool is_expensive() { return 1; }
|
||||
bool is_expensive();
|
||||
|
||||
inline Field *get_sp_result_field()
|
||||
{
|
||||
|
||||
Reference in New Issue
Block a user