Skip to content

Commit 236a31e

Browse files
committed
Bug#33275457: Fix multi-valued index
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
1 parent aea2d71 commit 236a31e

File tree

3 files changed

+259
-9
lines changed

3 files changed

+259
-9
lines changed

mysql-test/suite/json/r/array_index.result

Lines changed: 150 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -2462,7 +2462,9 @@ f2 JSON NOT NULL,
24622462
INDEX idx2 ( (CAST(f2 AS CHAR(50) ARRAY)) )
24632463
);
24642464
CREATE VIEW v1 AS
2465-
SELECT * FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH '$')) AS ids;
2465+
SELECT *
2466+
FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
2467+
PATH '$')) AS ids;
24662468
INSERT INTO t1 VALUES ('foo', '["aa", "bb"]'), ('bar', '["xx", "yy"]');
24672469
ANALYZE TABLE t1;
24682470
Table Op Msg_type Msg_text
@@ -2572,6 +2574,153 @@ WHERE json_overlaps(f2, '["xx", "zz"]');
25722574
f1 f2 i id
25732575
bar ["xx", "yy"] 1 xx
25742576
bar ["xx", "yy"] 2 yy
2577+
PREPARE stmt FROM 'EXPLAIN SELECT * FROM t1 WHERE ? MEMBER OF (f2)';
2578+
SET @a='xx';
2579+
EXECUTE stmt USING @a;
2580+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2581+
1 SIMPLE t1 NULL ref idx2 idx2 203 const 1 100.00 Using where
2582+
Warnings:
2583+
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))
2584+
PREPARE stmt FROM 'EXPLAIN SELECT * FROM t1 WHERE json_contains(f2, ?)';
2585+
SET @a='"xx"';
2586+
EXECUTE stmt USING @a;
2587+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2588+
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 1 100.00 Using where; Using MRR
2589+
Warnings:
2590+
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"]')
2591+
PREPARE stmt FROM 'EXPLAIN SELECT * FROM t1 WHERE json_overlaps(f2, ?)';
2592+
SET @a='["xx", "cc"]';
2593+
EXECUTE stmt USING @a;
2594+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2595+
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 2 100.00 Using where; Using MRR
2596+
Warnings:
2597+
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"]')
2598+
PREPARE stmt FROM 'EXPLAIN SELECT * FROM v1 WHERE ? MEMBER OF (f2)';
2599+
SET @a='xx';
2600+
EXECUTE stmt USING @a;
2601+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2602+
1 SIMPLE t1 NULL ref idx2 idx2 203 const 1 100.00 Using where
2603+
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
2604+
Warnings:
2605+
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))
2606+
PREPARE stmt FROM 'EXPLAIN SELECT * FROM v1 WHERE json_contains(f2, ?)';
2607+
SET @a='"xx"';
2608+
EXECUTE stmt USING @a;
2609+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2610+
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 1 100.00 Using where; Using MRR
2611+
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
2612+
Warnings:
2613+
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"]')
2614+
PREPARE stmt FROM 'EXPLAIN SELECT * FROM v1 WHERE json_overlaps(f2, ?)';
2615+
SET @a='["xx", "cc"]';
2616+
EXECUTE stmt USING @a;
2617+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2618+
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 2 100.00 Using where; Using MRR
2619+
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
2620+
Warnings:
2621+
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"]')
2622+
PREPARE stmt FROM '
2623+
EXPLAIN
2624+
SELECT *
2625+
FROM t1, JSON_TABLE(f2, \'$[*]\'
2626+
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
2627+
WHERE ? MEMBER OF (f2)';
2628+
SET @a='xx';
2629+
EXECUTE stmt USING @a;
2630+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2631+
1 SIMPLE t1 NULL ref idx2 idx2 203 const 1 100.00 Using where
2632+
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
2633+
Warnings:
2634+
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))
2635+
PREPARE stmt FROM '
2636+
EXPLAIN
2637+
SELECT *
2638+
FROM t1, JSON_TABLE(f2, \'$[*]\'
2639+
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
2640+
WHERE json_contains(f2, ?)';
2641+
SET @a='"xx"';
2642+
EXECUTE stmt USING @a;
2643+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2644+
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 1 100.00 Using where; Using MRR
2645+
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
2646+
Warnings:
2647+
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"]')
2648+
PREPARE stmt FROM '
2649+
EXPLAIN
2650+
SELECT *
2651+
FROM t1, JSON_TABLE(f2, \'$[*]\'
2652+
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
2653+
WHERE json_overlaps(f2, ?)';
2654+
SET @a='["xx", "cc"]';
2655+
EXECUTE stmt USING @a;
2656+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2657+
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 2 100.00 Using where; Using MRR
2658+
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
2659+
Warnings:
2660+
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"]')
2661+
PREPARE stmt FROM 'SELECT * FROM t1 WHERE ? MEMBER OF (f2)';
2662+
SET @a='xx';
2663+
EXECUTE stmt USING @a;
2664+
f1 f2
2665+
bar ["xx", "yy"]
2666+
PREPARE stmt FROM 'SELECT * FROM t1 WHERE json_contains(f2, ?)';
2667+
SET @a='"xx"';
2668+
EXECUTE stmt USING @a;
2669+
f1 f2
2670+
bar ["xx", "yy"]
2671+
PREPARE stmt FROM 'SELECT * FROM t1 WHERE json_overlaps(f2, ?)';
2672+
SET @a='["xx", "cc"]';
2673+
EXECUTE stmt USING @a;
2674+
f1 f2
2675+
bar ["xx", "yy"]
2676+
PREPARE stmt FROM 'SELECT * FROM v1 WHERE ? MEMBER OF (f2)';
2677+
SET @a='xx';
2678+
EXECUTE stmt USING @a;
2679+
f1 f2 i id
2680+
bar ["xx", "yy"] 1 xx
2681+
bar ["xx", "yy"] 2 yy
2682+
PREPARE stmt FROM 'SELECT * FROM v1 WHERE json_contains(f2, ?)';
2683+
SET @a='"xx"';
2684+
EXECUTE stmt USING @a;
2685+
f1 f2 i id
2686+
bar ["xx", "yy"] 1 xx
2687+
bar ["xx", "yy"] 2 yy
2688+
PREPARE stmt FROM 'SELECT * FROM v1 WHERE json_overlaps(f2, ?)';
2689+
SET @a='["xx", "cc"]';
2690+
EXECUTE stmt USING @a;
2691+
f1 f2 i id
2692+
bar ["xx", "yy"] 1 xx
2693+
bar ["xx", "yy"] 2 yy
2694+
PREPARE stmt FROM '
2695+
SELECT *
2696+
FROM t1, JSON_TABLE(f2, \'$[*]\'
2697+
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
2698+
WHERE ? MEMBER OF (f2)';
2699+
SET @a='xx';
2700+
EXECUTE stmt USING @a;
2701+
f1 f2 i id
2702+
bar ["xx", "yy"] 1 xx
2703+
bar ["xx", "yy"] 2 yy
2704+
PREPARE stmt FROM '
2705+
SELECT *
2706+
FROM t1, JSON_TABLE(f2, \'$[*]\'
2707+
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
2708+
WHERE json_contains(f2, ?)';
2709+
SET @a='"xx"';
2710+
EXECUTE stmt USING @a;
2711+
f1 f2 i id
2712+
bar ["xx", "yy"] 1 xx
2713+
bar ["xx", "yy"] 2 yy
2714+
PREPARE stmt FROM '
2715+
SELECT *
2716+
FROM t1, JSON_TABLE(f2, \'$[*]\'
2717+
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
2718+
WHERE json_overlaps(f2, ?)';
2719+
SET @a='["xx", "cc"]';
2720+
EXECUTE stmt USING @a;
2721+
f1 f2 i id
2722+
bar ["xx", "yy"] 1 xx
2723+
bar ["xx", "yy"] 2 yy
25752724
DROP VIEW v1;
25762725
DROP TABLE t1;
25772726
# restart:

mysql-test/suite/json/t/array_index.test

Lines changed: 102 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1385,7 +1385,9 @@ CREATE TABLE t1 (
13851385
);
13861386

13871387
CREATE VIEW v1 AS
1388-
SELECT * FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH '$')) AS ids;
1388+
SELECT *
1389+
FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
1390+
PATH '$')) AS ids;
13891391

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

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

1445+
PREPARE stmt FROM 'EXPLAIN SELECT * FROM t1 WHERE ? MEMBER OF (f2)';
1446+
SET @a='xx';
1447+
EXECUTE stmt USING @a;
1448+
1449+
PREPARE stmt FROM 'EXPLAIN SELECT * FROM t1 WHERE json_contains(f2, ?)';
1450+
SET @a='"xx"';
1451+
EXECUTE stmt USING @a;
1452+
1453+
PREPARE stmt FROM 'EXPLAIN SELECT * FROM t1 WHERE json_overlaps(f2, ?)';
1454+
SET @a='["xx", "cc"]';
1455+
EXECUTE stmt USING @a;
1456+
1457+
PREPARE stmt FROM 'EXPLAIN SELECT * FROM v1 WHERE ? MEMBER OF (f2)';
1458+
SET @a='xx';
1459+
EXECUTE stmt USING @a;
1460+
1461+
PREPARE stmt FROM 'EXPLAIN SELECT * FROM v1 WHERE json_contains(f2, ?)';
1462+
SET @a='"xx"';
1463+
EXECUTE stmt USING @a;
1464+
1465+
PREPARE stmt FROM 'EXPLAIN SELECT * FROM v1 WHERE json_overlaps(f2, ?)';
1466+
SET @a='["xx", "cc"]';
1467+
EXECUTE stmt USING @a;
1468+
1469+
PREPARE stmt FROM '
1470+
EXPLAIN
1471+
SELECT *
1472+
FROM t1, JSON_TABLE(f2, \'$[*]\'
1473+
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
1474+
WHERE ? MEMBER OF (f2)';
1475+
SET @a='xx';
1476+
EXECUTE stmt USING @a;
1477+
1478+
PREPARE stmt FROM '
1479+
EXPLAIN
1480+
SELECT *
1481+
FROM t1, JSON_TABLE(f2, \'$[*]\'
1482+
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
1483+
WHERE json_contains(f2, ?)';
1484+
SET @a='"xx"';
1485+
EXECUTE stmt USING @a;
1486+
1487+
PREPARE stmt FROM '
1488+
EXPLAIN
1489+
SELECT *
1490+
FROM t1, JSON_TABLE(f2, \'$[*]\'
1491+
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
1492+
WHERE json_overlaps(f2, ?)';
1493+
SET @a='["xx", "cc"]';
1494+
EXECUTE stmt USING @a;
1495+
1496+
PREPARE stmt FROM 'SELECT * FROM t1 WHERE ? MEMBER OF (f2)';
1497+
SET @a='xx';
1498+
EXECUTE stmt USING @a;
1499+
1500+
PREPARE stmt FROM 'SELECT * FROM t1 WHERE json_contains(f2, ?)';
1501+
SET @a='"xx"';
1502+
EXECUTE stmt USING @a;
1503+
1504+
PREPARE stmt FROM 'SELECT * FROM t1 WHERE json_overlaps(f2, ?)';
1505+
SET @a='["xx", "cc"]';
1506+
EXECUTE stmt USING @a;
1507+
1508+
PREPARE stmt FROM 'SELECT * FROM v1 WHERE ? MEMBER OF (f2)';
1509+
SET @a='xx';
1510+
EXECUTE stmt USING @a;
1511+
1512+
PREPARE stmt FROM 'SELECT * FROM v1 WHERE json_contains(f2, ?)';
1513+
SET @a='"xx"';
1514+
EXECUTE stmt USING @a;
1515+
1516+
PREPARE stmt FROM 'SELECT * FROM v1 WHERE json_overlaps(f2, ?)';
1517+
SET @a='["xx", "cc"]';
1518+
EXECUTE stmt USING @a;
1519+
1520+
PREPARE stmt FROM '
1521+
SELECT *
1522+
FROM t1, JSON_TABLE(f2, \'$[*]\'
1523+
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
1524+
WHERE ? MEMBER OF (f2)';
1525+
SET @a='xx';
1526+
EXECUTE stmt USING @a;
1527+
1528+
PREPARE stmt FROM '
1529+
SELECT *
1530+
FROM t1, JSON_TABLE(f2, \'$[*]\'
1531+
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
1532+
WHERE json_contains(f2, ?)';
1533+
SET @a='"xx"';
1534+
EXECUTE stmt USING @a;
1535+
1536+
PREPARE stmt FROM '
1537+
SELECT *
1538+
FROM t1, JSON_TABLE(f2, \'$[*]\'
1539+
COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH \'$\')) AS ids
1540+
WHERE json_overlaps(f2, ?)';
1541+
SET @a='["xx", "cc"]';
1542+
EXECUTE stmt USING @a;
1543+
14431544
DROP VIEW v1;
14441545
DROP TABLE t1;
14451546

sql/item_func.cc

Lines changed: 7 additions & 7 deletions
Original file line numberDiff line numberDiff line change
@@ -1315,11 +1315,11 @@ Item *Item_func::gc_subst_transformer(uchar *arg) {
13151315
Item_result type = args[0]->result_type();
13161316
/*
13171317
Check whether MEMBER OF is applicable for optimization:
1318-
1) 1st arg is a constant
1318+
1) 1st arg is constant for execution
13191319
2) .. and it isn't NULL, as MEMBER OF can't be used to lookup NULLs
13201320
3) 2nd arg can be substituted for a GC
13211321
*/
1322-
if (args[0]->const_item() && // 1
1322+
if (args[0]->const_for_execution() && // 1
13231323
!args[0]->is_null() && // 2
13241324
args[1]->can_be_substituted_for_gc(/*array=*/true)) { // 3
13251325
if (substitute_gc_expression(args + 1, args, gc_fields, type, this))
@@ -1333,12 +1333,12 @@ Item *Item_func::gc_subst_transformer(uchar *arg) {
13331333
/*
13341334
Check whether JSON_CONTAINS is applicable for optimization:
13351335
1) 1st arg can be substituted with a generated column
1336-
2) value to lookup is a constant
1336+
2) value to lookup is constant for execution
13371337
3) value to lookup is a proper JSON doc
13381338
4) value to lookup is an array or scalar
13391339
*/
13401340
if (!args[0]->can_be_substituted_for_gc(/*array=*/true) || // 1
1341-
!args[1]->real_item()->const_item()) // 2
1341+
!args[1]->const_for_execution()) // 2
13421342
break;
13431343
if (get_json_wrapper(args, 1, &str, func_name(), &vals_wr) || // 3
13441344
args[1]->null_value ||
@@ -1353,17 +1353,17 @@ Item *Item_func::gc_subst_transformer(uchar *arg) {
13531353

13541354
/*
13551355
Check whether JSON_OVERLAPS is applicable for optimization:
1356-
1) One argument is a constant
1356+
1) One argument is constant for execution
13571357
2) The other argument can be substituted with a generated column
13581358
3) value to lookup is a proper JSON doc
13591359
4) value to lookup is an array or scalar
13601360
*/
13611361
if (args[0]->can_be_substituted_for_gc(/*array=*/true) && // 2
1362-
args[1]->const_item()) { // 1
1362+
args[1]->const_for_execution()) { // 1
13631363
func = args;
13641364
vals = 1;
13651365
} else if (args[1]->can_be_substituted_for_gc(/*array=*/true) && // 2
1366-
args[0]->const_item()) { // 1
1366+
args[0]->const_for_execution()) { // 1
13671367
func = args + 1;
13681368
vals = 0;
13691369
} else {

0 commit comments

Comments
 (0)