From 73d32cc100fd08a7c563dceca29bb42cbd199a41 Mon Sep 17 00:00:00 2001 From: Yongxin Xu <55976466+yongxin-xu@users.noreply.github.com> Date: Fri, 23 Jul 2021 22:36:27 +0800 Subject: [PATCH] MDEV-24517: JSON_EXTRACT as conditions triggers syntax error on Spider (#1839) The `item_func::JSON_EXTRACT_FUNC` was not handled correctly in the previous versions on the Spider storage engine, which makes queries like `SELECT * FROM t1 WHERE json_extract(jdoc, '$.Age')=20` failed with syntax error. This patch writes specific code to handle JSON_EXTRACT in the Spider Storage Engine and fix that bug. --- .../bugfix/include/mdev_24517_deinit.inc | 11 +++ .../spider/bugfix/include/mdev_24517_init.inc | 43 ++++++++++ .../spider/bugfix/r/mdev_24517.result | 78 +++++++++++++++++++ .../mysql-test/spider/bugfix/t/mdev_24517.cnf | 3 + .../spider/bugfix/t/mdev_24517.test | 78 +++++++++++++++++++ storage/spider/spd_db_mysql.cc | 17 ++++ 6 files changed, 230 insertions(+) create mode 100644 storage/spider/mysql-test/spider/bugfix/include/mdev_24517_deinit.inc create mode 100644 storage/spider/mysql-test/spider/bugfix/include/mdev_24517_init.inc create mode 100644 storage/spider/mysql-test/spider/bugfix/r/mdev_24517.result create mode 100644 storage/spider/mysql-test/spider/bugfix/t/mdev_24517.cnf create mode 100644 storage/spider/mysql-test/spider/bugfix/t/mdev_24517.test diff --git a/storage/spider/mysql-test/spider/bugfix/include/mdev_24517_deinit.inc b/storage/spider/mysql-test/spider/bugfix/include/mdev_24517_deinit.inc new file mode 100644 index 00000000000..1880a1c7bba --- /dev/null +++ b/storage/spider/mysql-test/spider/bugfix/include/mdev_24517_deinit.inc @@ -0,0 +1,11 @@ +--let $MASTER_1_COMMENT_P_2_1= $MASTER_1_COMMENT_P_2_1_BACKUP +--let $CHILD2_1_DROP_TABLES= $CHILD2_1_DROP_TABLES_BACKUP +--let $CHILD2_1_CREATE_TABLES= $CHILD2_1_CREATE_TABLES_BACKUP +--let $CHILD2_1_SELECT_TABLES= $CHILD2_1_SELECT_TABLES_BACKUP +--disable_warnings +--disable_query_log +--disable_result_log +--source ../t/test_deinit.inc +--enable_result_log +--enable_query_log +--enable_warnings diff --git a/storage/spider/mysql-test/spider/bugfix/include/mdev_24517_init.inc b/storage/spider/mysql-test/spider/bugfix/include/mdev_24517_init.inc new file mode 100644 index 00000000000..b5b77a53798 --- /dev/null +++ b/storage/spider/mysql-test/spider/bugfix/include/mdev_24517_init.inc @@ -0,0 +1,43 @@ +--disable_warnings +--disable_query_log +--disable_result_log +--source ../t/test_init.inc +--enable_result_log +--enable_query_log +--enable_warnings +--let $MASTER_1_COMMENT_P_2_1_BACKUP= $MASTER_1_COMMENT_P_2_1 +let $MASTER_1_COMMENT_P_2_1= + PARTITION BY RANGE(i) ( + PARTITION pt1 VALUES LESS THAN (5) COMMENT='srv "s_2_1", table "ta_r2"', + PARTITION pt2 VALUES LESS THAN (10) COMMENT='srv "s_2_1", table "ta_r3"', + PARTITION pt3 VALUES LESS THAN MAXVALUE COMMENT='srv "s_2_1", table "ta_r4"' + ); +--let $CHILD2_1_DROP_TABLES_BACKUP= $CHILD2_1_DROP_TABLES +let $CHILD2_1_DROP_TABLES= + DROP TABLE IF EXISTS ta_r2 $STR_SEMICOLON + DROP TABLE IF EXISTS ta_r3 $STR_SEMICOLON + DROP TABLE IF EXISTS ta_r4; +--let $CHILD2_1_CREATE_TABLES_BACKUP= $CHILD2_1_CREATE_TABLES +let $CHILD2_1_CREATE_TABLES= + CREATE TABLE ta_r2 ( + i INT, + j JSON, + PRIMARY KEY(i) + ) $CHILD2_1_ENGINE $CHILD2_1_CHARSET $STR_SEMICOLON + CREATE TABLE ta_r3 ( + i INT, + j JSON, + PRIMARY KEY(i) + ) $CHILD2_1_ENGINE $CHILD2_1_CHARSET $STR_SEMICOLON + CREATE TABLE ta_r4 ( + i INT, + j JSON, + PRIMARY KEY(i) + ) $CHILD2_1_ENGINE $CHILD2_1_CHARSET; +--let $CHILD2_1_SELECT_TABLES_BACKUP= $CHILD2_1_SELECT_TABLES +let $CHILD2_1_SELECT_TABLES= + SELECT i, j FROM ta_r2 ORDER BY i $STR_SEMICOLON + SELECT i, j FROM ta_r3 ORDER BY i $STR_SEMICOLON + SELECT i, j FROM ta_r4 ORDER BY i; +let $CHILD2_1_SELECT_ARGUMENT1= + SELECT argument FROM mysql.general_log WHERE argument LIKE '%select %'; diff --git a/storage/spider/mysql-test/spider/bugfix/r/mdev_24517.result b/storage/spider/mysql-test/spider/bugfix/r/mdev_24517.result new file mode 100644 index 00000000000..f084c967435 --- /dev/null +++ b/storage/spider/mysql-test/spider/bugfix/r/mdev_24517.result @@ -0,0 +1,78 @@ +for master_1 +for child2 +child2_1 +child2_2 +child2_3 +for child3 + +this test is for MDEV-24517 + +drop and create databases +connection master_1; +CREATE DATABASE auto_test_local; +USE auto_test_local; +connection child2_1; +SET @old_log_output = @@global.log_output; +SET GLOBAL log_output = 'TABLE,FILE'; +CREATE DATABASE auto_test_remote; +USE auto_test_remote; + +create table and insert +connection child2_1; +CHILD2_1_CREATE_TABLES +TRUNCATE TABLE mysql.general_log; +connection master_1; +CREATE TABLE tbl_a ( +i INT, +j JSON, +PRIMARY KEY(i) +) ENGINE=Spider PARTITION BY RANGE(i) ( +PARTITION pt1 VALUES LESS THAN (5) COMMENT='srv "s_2_1", table "ta_r2"', +PARTITION pt2 VALUES LESS THAN (10) COMMENT='srv "s_2_1", table "ta_r3"', +PARTITION pt3 VALUES LESS THAN MAXVALUE COMMENT='srv "s_2_1", table "ta_r4"' + ) +INSERT INTO tbl_a (i, j) VALUES +(1, '{"ID": "3", "Name": "Barney", "Age": 18}'), +(2, '{"ID": "4", "Name": "Betty", "Age": 19}'), +(3, '{"ID": "2", "Name": "Wilma", "Age": 20}'), +(4, '[10, 20, [30, 40]]'); + +test 1 +connection child2_1; +TRUNCATE TABLE mysql.general_log; +connection master_1; +SELECT * FROM tbl_a WHERE JSON_EXTRACT(j, '$.Age')=19; +i j +2 {"ID": "4", "Name": "Betty", "Age": 19} +SELECT * FROM tbl_a WHERE JSON_EXTRACT(j, '$.Name')="Betty"; +i j +2 {"ID": "4", "Name": "Betty", "Age": 19} +SELECT i, JSON_EXTRACT(j, "$.ID") +FROM tbl_a +WHERE JSON_EXTRACT(j, "$.ID") > 1 AND i < 4 +ORDER BY JSON_EXTRACT(j, "$.Name"); +i JSON_EXTRACT(j, "$.ID") +1 "3" +2 "4" +3 "2" +SELECT * FROM tbl_a WHERE JSON_EXTRACT(j, '$[1]') = 20; +i j +4 [10, 20, [30, 40]] +SELECT * FROM tbl_a WHERE JSON_EXTRACT(j, '$[2][0]') = 30; +i j +4 [10, 20, [30, 40]] + +deinit +connection master_1; +DROP DATABASE IF EXISTS auto_test_local; +connection child2_1; +DROP DATABASE IF EXISTS auto_test_remote; +SET GLOBAL log_output = @old_log_output; +for master_1 +for child2 +child2_1 +child2_2 +child2_3 +for child3 + +end of test diff --git a/storage/spider/mysql-test/spider/bugfix/t/mdev_24517.cnf b/storage/spider/mysql-test/spider/bugfix/t/mdev_24517.cnf new file mode 100644 index 00000000000..05dfd8a0bce --- /dev/null +++ b/storage/spider/mysql-test/spider/bugfix/t/mdev_24517.cnf @@ -0,0 +1,3 @@ +!include include/default_mysqld.cnf +!include ../my_1_1.cnf +!include ../my_2_1.cnf diff --git a/storage/spider/mysql-test/spider/bugfix/t/mdev_24517.test b/storage/spider/mysql-test/spider/bugfix/t/mdev_24517.test new file mode 100644 index 00000000000..f5e53e03a65 --- /dev/null +++ b/storage/spider/mysql-test/spider/bugfix/t/mdev_24517.test @@ -0,0 +1,78 @@ +--source ../include/mdev_24517_init.inc +--echo +--echo this test is for MDEV-24517 +--echo +--echo drop and create databases + +--connection master_1 +--disable_warnings +CREATE DATABASE auto_test_local; +USE auto_test_local; + +--connection child2_1 +SET @old_log_output = @@global.log_output; +SET GLOBAL log_output = 'TABLE,FILE'; +CREATE DATABASE auto_test_remote; +USE auto_test_remote; +--enable_warnings + +--echo +--echo create table and insert + +--connection child2_1 +--disable_query_log +echo CHILD2_1_CREATE_TABLES; +eval $CHILD2_1_CREATE_TABLES; +--enable_query_log +TRUNCATE TABLE mysql.general_log; + +--connection master_1 +--disable_query_log +echo CREATE TABLE tbl_a ( + i INT, + j JSON, + PRIMARY KEY(i) +) $MASTER_1_ENGINE $MASTER_1_COMMENT_P_2_1; +eval CREATE TABLE tbl_a ( + i INT, + j JSON, + PRIMARY KEY(i) +) $MASTER_1_ENGINE $MASTER_1_COMMENT_P_2_1; +--enable_query_log +INSERT INTO tbl_a (i, j) VALUES + (1, '{"ID": "3", "Name": "Barney", "Age": 18}'), + (2, '{"ID": "4", "Name": "Betty", "Age": 19}'), + (3, '{"ID": "2", "Name": "Wilma", "Age": 20}'), + (4, '[10, 20, [30, 40]]'); + +--echo +--echo test 1 + +--connection child2_1 +TRUNCATE TABLE mysql.general_log; + +--connection master_1 +SELECT * FROM tbl_a WHERE JSON_EXTRACT(j, '$.Age')=19; +SELECT * FROM tbl_a WHERE JSON_EXTRACT(j, '$.Name')="Betty"; +SELECT i, JSON_EXTRACT(j, "$.ID") + FROM tbl_a + WHERE JSON_EXTRACT(j, "$.ID") > 1 AND i < 4 + ORDER BY JSON_EXTRACT(j, "$.Name"); +SELECT * FROM tbl_a WHERE JSON_EXTRACT(j, '$[1]') = 20; +SELECT * FROM tbl_a WHERE JSON_EXTRACT(j, '$[2][0]') = 30; + +--echo +--echo deinit +--disable_warnings + +--connection master_1 +DROP DATABASE IF EXISTS auto_test_local; + +--connection child2_1 +DROP DATABASE IF EXISTS auto_test_remote; +SET GLOBAL log_output = @old_log_output; + +--enable_warnings +--source ../include/mdev_24517_deinit.inc +--echo +--echo end of test diff --git a/storage/spider/spd_db_mysql.cc b/storage/spider/spd_db_mysql.cc index 6450506ecc9..85c765a1a27 100644 --- a/storage/spider/spd_db_mysql.cc +++ b/storage/spider/spd_db_mysql.cc @@ -5084,6 +5084,23 @@ int spider_db_mbase_util::open_item_func( #else DBUG_RETURN(ER_SPIDER_COND_SKIP_NUM); #endif + case Item_func::JSON_EXTRACT_FUNC: + func_name = (char*) item_func->func_name(); + func_name_length = strlen(func_name); + if (str) + { + if (str->reserve(func_name_length + SPIDER_SQL_OPEN_PAREN_LEN)) + DBUG_RETURN(HA_ERR_OUT_OF_MEM); + str->q_append(func_name, func_name_length); + str->q_append(SPIDER_SQL_OPEN_PAREN_STR, SPIDER_SQL_OPEN_PAREN_LEN); + } + func_name = SPIDER_SQL_COMMA_STR; + func_name_length = SPIDER_SQL_COMMA_LEN; + separator_str = SPIDER_SQL_COMMA_STR; + separator_str_length = SPIDER_SQL_COMMA_LEN; + last_str = SPIDER_SQL_CLOSE_PAREN_STR; + last_str_length = SPIDER_SQL_CLOSE_PAREN_LEN; + break; default: THD *thd = spider->trx->thd; SPIDER_SHARE *share = spider->share;