Commit ac1c6738 authored by Daniel Ye's avatar Daniel Ye Committed by GitHub

MDEV-26545 Spider does not correctly handle UDF and stored function in where conds

- Handle stored function conditions correctly, with the same logic as with UDFs.
- When running queries on Spider SE, by default, we do not push down WHERE conditions containing usage of UDFs/stored functions to remote data nodes, unless the user demands (by setting spider_use_pushdown_udf).
parent f4d6d017
for master_1
for child2
child2_1
child2_2
child2_3
for child3
child3_1
child3_2
child3_3
#
# MDEV-26545 Spider does not correctly handle UDF and stored function in where conds
#
##### enable general_log #####
connection child2_1;
SET @general_log_backup = @@global.general_log;
SET @log_output_backup = @@global.log_output;
SET @@global.general_log = 1;
SET @@global.log_output = "TABLE";
TRUNCATE TABLE mysql.general_log;
##### create databases #####
connection master_1;
CREATE DATABASE auto_test_local;
USE auto_test_local;
connection child2_1;
CREATE DATABASE auto_test_remote;
USE auto_test_remote;
##### create tables #####
connection child2_1;
CHILD_CREATE_TABLE
connection master_1;
MASTER_CREATE_TABLE
CREATE TABLE ta_l (
id INT NOT NULL,
a INT,
PRIMARY KEY(id)
) MASTER_1_ENGINE MASTER_1_CHARSET MASTER_1_COMMENT_2_1
INSERT INTO ta_l VALUES
(1, 11),
(2, 22),
(3, 33),
(4, 44),
(5, 55);
##### create functions #####
connection master_1;
CREATE FUNCTION `plusone`( param INT ) RETURNS INT
BEGIN
RETURN param + 1;
END //
connection child2_1;
CREATE FUNCTION `plusone`( param INT ) RETURNS INT
BEGIN
RETURN param + 1;
END //
########## spider_use_pushdown_udf=0 ##########
connection master_1;
SET @@spider_use_pushdown_udf = 0;
##### test SELECTs #####
connection master_1;
SELECT * FROM ta_l WHERE id = plusone(1);
id a
2 22
SELECT * FROM ta_l WHERE id IN (plusone(1), plusone(2)) AND a = plusone(32);
id a
3 33
connection child2_1;
SELECT argument FROM mysql.general_log WHERE argument LIKE "%select%" AND argument NOT LIKE "%argument%";
argument
select `id`,`a` from `auto_test_remote`.`ta_r`
select `id`,`a` from `auto_test_remote`.`ta_r`
##### test UPDATEs #####
connection master_1;
UPDATE ta_l SET a = plusone(221) WHERE id = plusone(1);
SELECT * FROM ta_l;
id a
1 11
2 222
3 33
4 44
5 55
UPDATE ta_l SET a = plusone(332) WHERE id IN (plusone(1), plusone(2)) AND a = plusone(32);
SELECT * FROM ta_l;
id a
1 11
2 222
3 333
4 44
5 55
connection child2_1;
SELECT argument FROM mysql.general_log WHERE argument LIKE "%update%" AND argument NOT LIKE "%argument%";
argument
select `id`,`a` from `auto_test_remote`.`ta_r` for update
update `auto_test_remote`.`ta_r` set `a` = 222 where `id` = 2 limit 1
select `id`,`a` from `auto_test_remote`.`ta_r` for update
update `auto_test_remote`.`ta_r` set `a` = 333 where `id` = 3 and `a` = 33 limit 1
##### test DELETEs #####
connection master_1;
DELETE FROM ta_l WHERE id = plusone(1);
SELECT * FROM ta_l;
id a
1 11
3 333
4 44
5 55
DELETE FROM ta_l WHERE id IN (plusone(1), plusone(2), plusone(3)) AND a = plusone(43);
SELECT * FROM ta_l;
id a
1 11
3 333
5 55
connection child2_1;
SELECT argument FROM mysql.general_log WHERE (argument LIKE "%delete%" OR argument LIKE "%update%") AND argument NOT LIKE "%argument%";
argument
select `id` from `auto_test_remote`.`ta_r` for update
delete from `auto_test_remote`.`ta_r` where `id` = 2 limit 1
select `id`,`a` from `auto_test_remote`.`ta_r` for update
delete from `auto_test_remote`.`ta_r` where `id` = 4 and `a` = 44 limit 1
##### reset records #####
connection master_1;
TRUNCATE TABLE ta_l;
INSERT INTO ta_l VALUES
(1, 11),
(2, 22),
(3, 33),
(4, 44),
(5, 55);
########## spider_use_pushdown_udf=1 ##########
connection master_1;
SET @@spider_use_pushdown_udf = 1;
##### test SELECTs #####
connection master_1;
SELECT * FROM ta_l WHERE id = plusone(1);
id a
2 22
SELECT * FROM ta_l WHERE id IN (plusone(1), plusone(2)) AND a = plusone(32);
id a
3 33
connection child2_1;
SELECT argument FROM mysql.general_log WHERE argument LIKE "%select%" AND argument NOT LIKE "%argument%";
argument
select `id`,`a` from `auto_test_remote`.`ta_r` where (`id` = (`plusone`(1)))
select `id`,`a` from `auto_test_remote`.`ta_r` where ((`id` in( (`plusone`(1)) , (`plusone`(2)))) and (`a` = (`plusone`(32))))
##### test UPDATEs #####
connection master_1;
UPDATE ta_l SET a = plusone(221) WHERE id = plusone(1);
SELECT * FROM ta_l;
id a
1 11
2 222
3 33
4 44
5 55
UPDATE ta_l SET a = plusone(332) WHERE id IN (plusone(1), plusone(2)) AND a = plusone(32);
SELECT * FROM ta_l;
id a
1 11
2 222
3 333
4 44
5 55
connection child2_1;
SELECT argument FROM mysql.general_log WHERE argument LIKE "%update%" AND argument NOT LIKE "%argument%";
argument
select `id`,`a` from `auto_test_remote`.`ta_r` where (`id` = (`plusone`(1))) for update
update `auto_test_remote`.`ta_r` set `a` = 222 where `id` = 2 limit 1
select `id`,`a` from `auto_test_remote`.`ta_r` where ((`id` in( (`plusone`(1)) , (`plusone`(2)))) and (`a` = (`plusone`(32)))) for update
update `auto_test_remote`.`ta_r` set `a` = 333 where `id` = 3 and `a` = 33 limit 1
##### test DELETEs #####
connection master_1;
DELETE FROM ta_l WHERE id = plusone(1);
SELECT * FROM ta_l;
id a
1 11
3 333
4 44
5 55
DELETE FROM ta_l WHERE id IN (plusone(1), plusone(2), plusone(3)) AND a = plusone(43);
SELECT * FROM ta_l;
id a
1 11
3 333
5 55
connection child2_1;
SELECT argument FROM mysql.general_log WHERE (argument LIKE "%delete%" OR argument LIKE "%update%") AND argument NOT LIKE "%argument%";
argument
select `id` from `auto_test_remote`.`ta_r` where (`id` = (`plusone`(1))) for update
delete from `auto_test_remote`.`ta_r` where `id` = 2 limit 1
select `id`,`a` from `auto_test_remote`.`ta_r` where ((`id` in( (`plusone`(1)) , (`plusone`(2)) , (`plusone`(3)))) and (`a` = (`plusone`(43)))) for update
delete from `auto_test_remote`.`ta_r` where `id` = 4 and `a` = 44 limit 1
deinit
connection master_1;
DROP FUNCTION `plusone`;
DROP DATABASE IF EXISTS auto_test_local;
connection child2_1;
SET @@global.general_log = @general_log_backup;
SET @@global.log_output = @log_output_backup;
DROP FUNCTION `plusone`;
DROP DATABASE IF EXISTS auto_test_remote;
for master_1
for child2
child2_1
child2_2
child2_3
for child3
child3_1
child3_2
child3_3
end of test
--echo
--echo ##### test SELECTs #####
--connection master_1
SELECT * FROM ta_l WHERE id = plusone(1);
SELECT * FROM ta_l WHERE id IN (plusone(1), plusone(2)) AND a = plusone(32);
if ($USE_CHILD_GROUP2)
{
--connection child2_1
SELECT argument FROM mysql.general_log WHERE argument LIKE "%select%" AND argument NOT LIKE "%argument%";
--disable_query_log
TRUNCATE TABLE mysql.general_log;
--enable_query_log
}
--echo
--echo ##### test UPDATEs #####
--connection master_1
UPDATE ta_l SET a = plusone(221) WHERE id = plusone(1);
SELECT * FROM ta_l;
UPDATE ta_l SET a = plusone(332) WHERE id IN (plusone(1), plusone(2)) AND a = plusone(32);
SELECT * FROM ta_l;
if ($USE_CHILD_GROUP2)
{
--connection child2_1
SELECT argument FROM mysql.general_log WHERE argument LIKE "%update%" AND argument NOT LIKE "%argument%";
--disable_query_log
TRUNCATE TABLE mysql.general_log;
--enable_query_log
}
--echo
--echo ##### test DELETEs #####
--connection master_1
DELETE FROM ta_l WHERE id = plusone(1);
SELECT * FROM ta_l;
DELETE FROM ta_l WHERE id IN (plusone(1), plusone(2), plusone(3)) AND a = plusone(43);
SELECT * FROM ta_l;
if ($USE_CHILD_GROUP2)
{
--connection child2_1
SELECT argument FROM mysql.general_log WHERE (argument LIKE "%delete%" OR argument LIKE "%update%") AND argument NOT LIKE "%argument%";
--disable_query_log
TRUNCATE TABLE mysql.general_log;
--enable_query_log
}
--disable_warnings
--disable_query_log
--disable_result_log
--source test_init.inc
--enable_result_log
--enable_query_log
--echo #
--echo # MDEV-26545 Spider does not correctly handle UDF and stored function in where conds
--echo #
let $CHILD_CREATE_TABLE=
CREATE TABLE ta_r (
id INT NOT NULL,
a INT,
PRIMARY KEY(id)
) $CHILD2_1_ENGINE $CHILD2_1_CHARSET;
let $MASTER_CREATE_TABLE_OUTPUT=
CREATE TABLE ta_l (
id INT NOT NULL,
a INT,
PRIMARY KEY(id)
) MASTER_1_ENGINE MASTER_1_CHARSET MASTER_1_COMMENT_2_1;
let $MASTER_CREATE_TABLE=
CREATE TABLE ta_l (
id INT NOT NULL,
a INT,
PRIMARY KEY(id)
) $MASTER_1_ENGINE $MASTER_1_CHARSET $MASTER_1_COMMENT_2_1;
--echo
--echo ##### enable general_log #####
--connection child2_1
SET @general_log_backup = @@global.general_log;
SET @log_output_backup = @@global.log_output;
SET @@global.general_log = 1;
SET @@global.log_output = "TABLE";
TRUNCATE TABLE mysql.general_log;
--echo
--echo ##### create databases #####
--connection master_1
CREATE DATABASE auto_test_local;
USE auto_test_local;
if ($USE_CHILD_GROUP2)
{
--connection child2_1
CREATE DATABASE auto_test_remote;
USE auto_test_remote;
}
--echo
--echo ##### create tables #####
if ($USE_CHILD_GROUP2)
{
--connection child2_1
--disable_query_log
echo CHILD_CREATE_TABLE;
eval $CHILD_CREATE_TABLE;
--enable_query_log
}
--connection master_1
--disable_query_log
echo MASTER_CREATE_TABLE;
echo $MASTER_CREATE_TABLE_OUTPUT;
eval $MASTER_CREATE_TABLE;
--enable_query_log
INSERT INTO ta_l VALUES
(1, 11),
(2, 22),
(3, 33),
(4, 44),
(5, 55);
--echo
--echo ##### create functions #####
--connection master_1
DELIMITER //;
CREATE FUNCTION `plusone`( param INT ) RETURNS INT
BEGIN
RETURN param + 1;
END //
DELIMITER ;//
--connection child2_1
DELIMITER //;
CREATE FUNCTION `plusone`( param INT ) RETURNS INT
BEGIN
RETURN param + 1;
END //
DELIMITER ;//
--echo
--echo ########## spider_use_pushdown_udf=0 ##########
--connection master_1
SET @@spider_use_pushdown_udf = 0;
--source udf_pushdown.inc
--echo
--echo ##### reset records #####
--connection master_1
TRUNCATE TABLE ta_l;
INSERT INTO ta_l VALUES
(1, 11),
(2, 22),
(3, 33),
(4, 44),
(5, 55);
--echo
--echo ########## spider_use_pushdown_udf=1 ##########
--connection master_1
SET @@spider_use_pushdown_udf = 1;
--source udf_pushdown.inc
--echo
--echo deinit
--disable_warnings
--connection master_1
DROP FUNCTION `plusone`;
DROP DATABASE IF EXISTS auto_test_local;
if ($USE_CHILD_GROUP2)
{
--connection child2_1
SET @@global.general_log = @general_log_backup;
SET @@global.log_output = @log_output_backup;
DROP FUNCTION `plusone`;
DROP DATABASE IF EXISTS auto_test_remote;
}
--disable_query_log
--disable_result_log
--source test_deinit.inc
--enable_result_log
--enable_query_log
--enable_warnings
--echo
--echo end of test
......@@ -4085,10 +4085,16 @@ int spider_db_mysql_util::open_item_func(
separete_str_length = SPIDER_SQL_AND_LEN;
}
break;
case Item_func::FUNC_SP:
case Item_func::UDF_FUNC:
use_pushdown_udf = spider_param_use_pushdown_udf(spider->trx->thd,
spider->share->use_pushdown_udf);
if (!use_pushdown_udf)
/*
This is the default behavior because the remote nodes may deal with
the function in an unexpected way (e.g. not having the same
definition). Users can turn it on if they know what they are doing.
*/
DBUG_RETURN(ER_SPIDER_COND_SKIP_NUM);
if (str)
{
......
......@@ -1931,7 +1931,7 @@ static MYSQL_THDVAR_INT(
"Remote server transmission existence when UDF is used at condition and \"engine_condition_pushdown=1\"", /* comment */
NULL, /* check */
NULL, /* update */
-1, /* def */
0, /* def */
-1, /* min */
1, /* max */
0 /* blk */
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment