Skip to content

Commit

Permalink
Bug#33275457: Fix multi-valued index
Browse files Browse the repository at this point in the history
Patch #2: Support multi-valued indexes for prepared statements.

Parameters to prepared statements are not denoted as constant but
constant during statement execution, however only constant values are
considered for use with multi-valued indexes.

Replace const_item() with const_for_execution() to enable use of
such parameters with multi-valued indexes.

This is a contribution by Yubao Liu.

Change-Id: I8cf843a95d2657e5fcc67a04df65815f9ad3154a
  • Loading branch information
roylyseng committed Sep 2, 2021
1 parent a77152a commit 1c73559
Show file tree
Hide file tree
Showing 3 changed files with 259 additions and 9 deletions.
151 changes: 150 additions & 1 deletion mysql-test/suite/json/r/array_index.result
Original file line number Diff line number Diff line change
Expand Up @@ -2462,7 +2462,9 @@ f2 JSON NOT NULL,
INDEX idx2 ( (CAST(f2 AS CHAR(50) ARRAY)) )
);
CREATE VIEW v1 AS
SELECT * FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH '$')) AS ids;
SELECT *
FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
PATH '$')) AS ids;
INSERT INTO t1 VALUES ('foo', '["aa", "bb"]'), ('bar', '["xx", "yy"]');
ANALYZE TABLE t1;
Table Op Msg_type Msg_text
Expand Down Expand Up @@ -2572,6 +2574,153 @@ WHERE json_overlaps(f2, '["xx", "zz"]');
f1 f2 i id
bar ["xx", "yy"] 1 xx
bar ["xx", "yy"] 2 yy
PREPARE stmt FROM 'EXPLAIN SELECT * FROM t1 WHERE ? MEMBER OF (f2)';
SET @a='xx';
EXECUTE stmt USING @a;
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 NULL ref idx2 idx2 203 const 1 100.00 Using where
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2` from `test`.`t1` where json'"xx"' member of (cast(`f2` as char(50) array))
PREPARE stmt FROM 'EXPLAIN SELECT * FROM t1 WHERE json_contains(f2, ?)';
SET @a='"xx"';
EXECUTE stmt USING @a;
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 1 100.00 Using where; Using MRR
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2` from `test`.`t1` where json_contains(cast(`f2` as char(50) array),json'["xx"]')
PREPARE stmt FROM 'EXPLAIN SELECT * FROM t1 WHERE json_overlaps(f2, ?)';
SET @a='["xx", "cc"]';
EXECUTE stmt USING @a;
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 2 100.00 Using where; Using MRR
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2` from `test`.`t1` where json_overlaps(cast(`f2` as char(50) array),json'["xx", "cc"]')
PREPARE stmt FROM 'EXPLAIN SELECT * FROM v1 WHERE ? MEMBER OF (f2)';
SET @a='xx';
EXECUTE stmt USING @a;
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 NULL ref idx2 idx2 203 const 1 100.00 Using where
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`ids`.`i` AS `i`,`ids`.`id` AS `id` from `test`.`t1` join json_table(`test`.`t1`.`f2`, '$[*]' columns (`i` for ordinality, `id` varchar(50) character set utf8mb4 path '$')) `ids` where json'"xx"' member of (cast(`f2` as char(50) array))
PREPARE stmt FROM 'EXPLAIN SELECT * FROM v1 WHERE json_contains(f2, ?)';
SET @a='"xx"';
EXECUTE stmt USING @a;
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 1 100.00 Using where; Using MRR
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`ids`.`i` AS `i`,`ids`.`id` AS `id` from `test`.`t1` join json_table(`test`.`t1`.`f2`, '$[*]' columns (`i` for ordinality, `id` varchar(50) character set utf8mb4 path '$')) `ids` where json_contains(cast(`f2` as char(50) array),json'["xx"]')
PREPARE stmt FROM 'EXPLAIN SELECT * FROM v1 WHERE json_overlaps(f2, ?)';
SET @a='["xx", "cc"]';
EXECUTE stmt USING @a;
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 2 100.00 Using where; Using MRR
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`ids`.`i` AS `i`,`ids`.`id` AS `id` from `test`.`t1` join json_table(`test`.`t1`.`f2`, '$[*]' columns (`i` for ordinality, `id` varchar(50) character set utf8mb4 path '$')) `ids` where json_overlaps(cast(`f2` as char(50) array),json'["xx", "cc"]')
PREPARE stmt FROM '
EXPLAIN
SELECT *
FROM t1, JSON_TABLE(f2, \'$[*]\'
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
WHERE ? MEMBER OF (f2)';
SET @a='xx';
EXECUTE stmt USING @a;
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 NULL ref idx2 idx2 203 const 1 100.00 Using where
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`ids`.`i` AS `i`,`ids`.`id` AS `id` from `test`.`t1` join json_table(`test`.`t1`.`f2`, '$[*]' columns (`i` for ordinality, `id` varchar(50) character set utf8mb4 path '$')) `ids` where json'"xx"' member of (cast(`f2` as char(50) array))
PREPARE stmt FROM '
EXPLAIN
SELECT *
FROM t1, JSON_TABLE(f2, \'$[*]\'
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
WHERE json_contains(f2, ?)';
SET @a='"xx"';
EXECUTE stmt USING @a;
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 1 100.00 Using where; Using MRR
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`ids`.`i` AS `i`,`ids`.`id` AS `id` from `test`.`t1` join json_table(`test`.`t1`.`f2`, '$[*]' columns (`i` for ordinality, `id` varchar(50) character set utf8mb4 path '$')) `ids` where json_contains(cast(`f2` as char(50) array),json'["xx"]')
PREPARE stmt FROM '
EXPLAIN
SELECT *
FROM t1, JSON_TABLE(f2, \'$[*]\'
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
WHERE json_overlaps(f2, ?)';
SET @a='["xx", "cc"]';
EXECUTE stmt USING @a;
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 2 100.00 Using where; Using MRR
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`ids`.`i` AS `i`,`ids`.`id` AS `id` from `test`.`t1` join json_table(`test`.`t1`.`f2`, '$[*]' columns (`i` for ordinality, `id` varchar(50) character set utf8mb4 path '$')) `ids` where json_overlaps(cast(`f2` as char(50) array),json'["xx", "cc"]')
PREPARE stmt FROM 'SELECT * FROM t1 WHERE ? MEMBER OF (f2)';
SET @a='xx';
EXECUTE stmt USING @a;
f1 f2
bar ["xx", "yy"]
PREPARE stmt FROM 'SELECT * FROM t1 WHERE json_contains(f2, ?)';
SET @a='"xx"';
EXECUTE stmt USING @a;
f1 f2
bar ["xx", "yy"]
PREPARE stmt FROM 'SELECT * FROM t1 WHERE json_overlaps(f2, ?)';
SET @a='["xx", "cc"]';
EXECUTE stmt USING @a;
f1 f2
bar ["xx", "yy"]
PREPARE stmt FROM 'SELECT * FROM v1 WHERE ? MEMBER OF (f2)';
SET @a='xx';
EXECUTE stmt USING @a;
f1 f2 i id
bar ["xx", "yy"] 1 xx
bar ["xx", "yy"] 2 yy
PREPARE stmt FROM 'SELECT * FROM v1 WHERE json_contains(f2, ?)';
SET @a='"xx"';
EXECUTE stmt USING @a;
f1 f2 i id
bar ["xx", "yy"] 1 xx
bar ["xx", "yy"] 2 yy
PREPARE stmt FROM 'SELECT * FROM v1 WHERE json_overlaps(f2, ?)';
SET @a='["xx", "cc"]';
EXECUTE stmt USING @a;
f1 f2 i id
bar ["xx", "yy"] 1 xx
bar ["xx", "yy"] 2 yy
PREPARE stmt FROM '
SELECT *
FROM t1, JSON_TABLE(f2, \'$[*]\'
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
WHERE ? MEMBER OF (f2)';
SET @a='xx';
EXECUTE stmt USING @a;
f1 f2 i id
bar ["xx", "yy"] 1 xx
bar ["xx", "yy"] 2 yy
PREPARE stmt FROM '
SELECT *
FROM t1, JSON_TABLE(f2, \'$[*]\'
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
WHERE json_contains(f2, ?)';
SET @a='"xx"';
EXECUTE stmt USING @a;
f1 f2 i id
bar ["xx", "yy"] 1 xx
bar ["xx", "yy"] 2 yy
PREPARE stmt FROM '
SELECT *
FROM t1, JSON_TABLE(f2, \'$[*]\'
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
WHERE json_overlaps(f2, ?)';
SET @a='["xx", "cc"]';
EXECUTE stmt USING @a;
f1 f2 i id
bar ["xx", "yy"] 1 xx
bar ["xx", "yy"] 2 yy
DROP VIEW v1;
DROP TABLE t1;
# restart:
103 changes: 102 additions & 1 deletion mysql-test/suite/json/t/array_index.test
Original file line number Diff line number Diff line change
Expand Up @@ -1385,7 +1385,9 @@ CREATE TABLE t1 (
);

CREATE VIEW v1 AS
SELECT * FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH '$')) AS ids;
SELECT *
FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
PATH '$')) AS ids;

INSERT INTO t1 VALUES ('foo', '["aa", "bb"]'), ('bar', '["xx", "yy"]');

Expand Down Expand Up @@ -1440,6 +1442,105 @@ FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
PATH '$')) AS ids
WHERE json_overlaps(f2, '["xx", "zz"]');

PREPARE stmt FROM 'EXPLAIN SELECT * FROM t1 WHERE ? MEMBER OF (f2)';
SET @a='xx';
EXECUTE stmt USING @a;

PREPARE stmt FROM 'EXPLAIN SELECT * FROM t1 WHERE json_contains(f2, ?)';
SET @a='"xx"';
EXECUTE stmt USING @a;

PREPARE stmt FROM 'EXPLAIN SELECT * FROM t1 WHERE json_overlaps(f2, ?)';
SET @a='["xx", "cc"]';
EXECUTE stmt USING @a;

PREPARE stmt FROM 'EXPLAIN SELECT * FROM v1 WHERE ? MEMBER OF (f2)';
SET @a='xx';
EXECUTE stmt USING @a;

PREPARE stmt FROM 'EXPLAIN SELECT * FROM v1 WHERE json_contains(f2, ?)';
SET @a='"xx"';
EXECUTE stmt USING @a;

PREPARE stmt FROM 'EXPLAIN SELECT * FROM v1 WHERE json_overlaps(f2, ?)';
SET @a='["xx", "cc"]';
EXECUTE stmt USING @a;

PREPARE stmt FROM '
EXPLAIN
SELECT *
FROM t1, JSON_TABLE(f2, \'$[*]\'
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
WHERE ? MEMBER OF (f2)';
SET @a='xx';
EXECUTE stmt USING @a;

PREPARE stmt FROM '
EXPLAIN
SELECT *
FROM t1, JSON_TABLE(f2, \'$[*]\'
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
WHERE json_contains(f2, ?)';
SET @a='"xx"';
EXECUTE stmt USING @a;

PREPARE stmt FROM '
EXPLAIN
SELECT *
FROM t1, JSON_TABLE(f2, \'$[*]\'
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
WHERE json_overlaps(f2, ?)';
SET @a='["xx", "cc"]';
EXECUTE stmt USING @a;

PREPARE stmt FROM 'SELECT * FROM t1 WHERE ? MEMBER OF (f2)';
SET @a='xx';
EXECUTE stmt USING @a;

PREPARE stmt FROM 'SELECT * FROM t1 WHERE json_contains(f2, ?)';
SET @a='"xx"';
EXECUTE stmt USING @a;

PREPARE stmt FROM 'SELECT * FROM t1 WHERE json_overlaps(f2, ?)';
SET @a='["xx", "cc"]';
EXECUTE stmt USING @a;

PREPARE stmt FROM 'SELECT * FROM v1 WHERE ? MEMBER OF (f2)';
SET @a='xx';
EXECUTE stmt USING @a;

PREPARE stmt FROM 'SELECT * FROM v1 WHERE json_contains(f2, ?)';
SET @a='"xx"';
EXECUTE stmt USING @a;

PREPARE stmt FROM 'SELECT * FROM v1 WHERE json_overlaps(f2, ?)';
SET @a='["xx", "cc"]';
EXECUTE stmt USING @a;

PREPARE stmt FROM '
SELECT *
FROM t1, JSON_TABLE(f2, \'$[*]\'
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
WHERE ? MEMBER OF (f2)';
SET @a='xx';
EXECUTE stmt USING @a;

PREPARE stmt FROM '
SELECT *
FROM t1, JSON_TABLE(f2, \'$[*]\'
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
WHERE json_contains(f2, ?)';
SET @a='"xx"';
EXECUTE stmt USING @a;

PREPARE stmt FROM '
SELECT *
FROM t1, JSON_TABLE(f2, \'$[*]\'
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
WHERE json_overlaps(f2, ?)';
SET @a='["xx", "cc"]';
EXECUTE stmt USING @a;

DROP VIEW v1;
DROP TABLE t1;

Expand Down
14 changes: 7 additions & 7 deletions sql/item_func.cc
Original file line number Diff line number Diff line change
Expand Up @@ -1315,11 +1315,11 @@ Item *Item_func::gc_subst_transformer(uchar *arg) {
Item_result type = args[0]->result_type();
/*
Check whether MEMBER OF is applicable for optimization:
1) 1st arg is a constant
1) 1st arg is constant for execution
2) .. and it isn't NULL, as MEMBER OF can't be used to lookup NULLs
3) 2nd arg can be substituted for a GC
*/
if (args[0]->const_item() && // 1
if (args[0]->const_for_execution() && // 1
!args[0]->is_null() && // 2
args[1]->can_be_substituted_for_gc(/*array=*/true)) { // 3
if (substitute_gc_expression(args + 1, args, gc_fields, type, this))
Expand All @@ -1333,12 +1333,12 @@ Item *Item_func::gc_subst_transformer(uchar *arg) {
/*
Check whether JSON_CONTAINS is applicable for optimization:
1) 1st arg can be substituted with a generated column
2) value to lookup is a constant
2) value to lookup is constant for execution
3) value to lookup is a proper JSON doc
4) value to lookup is an array or scalar
*/
if (!args[0]->can_be_substituted_for_gc(/*array=*/true) || // 1
!args[1]->real_item()->const_item()) // 2
!args[1]->const_for_execution()) // 2
break;
if (get_json_wrapper(args, 1, &str, func_name(), &vals_wr) || // 3
args[1]->null_value ||
Expand All @@ -1353,17 +1353,17 @@ Item *Item_func::gc_subst_transformer(uchar *arg) {

/*
Check whether JSON_OVERLAPS is applicable for optimization:
1) One argument is a constant
1) One argument is constant for execution
2) The other argument can be substituted with a generated column
3) value to lookup is a proper JSON doc
4) value to lookup is an array or scalar
*/
if (args[0]->can_be_substituted_for_gc(/*array=*/true) && // 2
args[1]->const_item()) { // 1
args[1]->const_for_execution()) { // 1
func = args;
vals = 1;
} else if (args[1]->can_be_substituted_for_gc(/*array=*/true) && // 2
args[0]->const_item()) { // 1
args[0]->const_for_execution()) { // 1
func = args + 1;
vals = 0;
} else {
Expand Down

0 comments on commit 1c73559

Please sign in to comment.