Skip to content

Commit aea2d71

Browse files
committed
Bug#33275457: Fix multi-valued index
Patch #1: Support view references in generated column substitution. REF_ITEM was not considered in Item::can_be_substituted_for_gc() and get_gc_for_expr(), so optimizer failed to use multi-valued index from a view. The patch is also applicable to view references in general, thus not restricted to multi-valued indexes. This is a contribution by Yubao Liu. Change-Id: Iaa82a1245c80641fab0ed3a2d0f459e4e9bc26c1
1 parent 4c4d97d commit aea2d71

File tree

4 files changed

+188
-1
lines changed

4 files changed

+188
-1
lines changed

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

Lines changed: 119 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2455,4 +2455,123 @@ vc j
24552455
[2,3,4] [2, 3, 4]
24562456
[3,4,5] [3, 4, 5]
24572457
DROP TABLE t;
2458+
# Bug#33275457: Fix multi-valued index
2459+
CREATE TABLE t1 (
2460+
f1 VARCHAR(50) NOT NULL PRIMARY KEY,
2461+
f2 JSON NOT NULL,
2462+
INDEX idx2 ( (CAST(f2 AS CHAR(50) ARRAY)) )
2463+
);
2464+
CREATE VIEW v1 AS
2465+
SELECT * FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH '$')) AS ids;
2466+
INSERT INTO t1 VALUES ('foo', '["aa", "bb"]'), ('bar', '["xx", "yy"]');
2467+
ANALYZE TABLE t1;
2468+
Table Op Msg_type Msg_text
2469+
test.t1 analyze status OK
2470+
EXPLAIN SELECT * FROM t1 WHERE 'xx' MEMBER OF (f2);
2471+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2472+
1 SIMPLE t1 NULL ref idx2 idx2 203 const 1 100.00 Using where
2473+
Warnings:
2474+
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))
2475+
EXPLAIN SELECT * FROM t1 WHERE json_contains(f2, '"xx"');
2476+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2477+
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 1 100.00 Using where; Using MRR
2478+
Warnings:
2479+
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"]')
2480+
EXPLAIN SELECT * FROM t1 WHERE json_overlaps(f2, '["xx", "zz"]');
2481+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2482+
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 2 100.00 Using where; Using MRR
2483+
Warnings:
2484+
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", "zz"]')
2485+
EXPLAIN SELECT * FROM v1 WHERE 'xx' MEMBER OF (f2);
2486+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2487+
1 SIMPLE t1 NULL ref idx2 idx2 203 const 1 100.00 Using where
2488+
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
2489+
Warnings:
2490+
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))
2491+
EXPLAIN SELECT * FROM v1 WHERE json_contains(f2, '"xx"');
2492+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2493+
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 1 100.00 Using where; Using MRR
2494+
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
2495+
Warnings:
2496+
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"]')
2497+
EXPLAIN SELECT * FROM v1 WHERE json_overlaps(f2, '["xx", "zz"]');
2498+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2499+
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 2 100.00 Using where; Using MRR
2500+
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
2501+
Warnings:
2502+
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", "zz"]')
2503+
EXPLAIN
2504+
SELECT *
2505+
FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
2506+
PATH '$')) AS ids
2507+
WHERE 'xx' MEMBER OF (f2);
2508+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2509+
1 SIMPLE t1 NULL ref idx2 idx2 203 const 1 100.00 Using where
2510+
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
2511+
Warnings:
2512+
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))
2513+
EXPLAIN
2514+
SELECT *
2515+
FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
2516+
PATH '$')) AS ids
2517+
WHERE json_contains(f2, '"xx"');
2518+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2519+
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 1 100.00 Using where; Using MRR
2520+
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
2521+
Warnings:
2522+
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"]')
2523+
EXPLAIN
2524+
SELECT *
2525+
FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
2526+
PATH '$')) AS ids
2527+
WHERE json_overlaps(f2, '["xx", "zz"]');
2528+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
2529+
1 SIMPLE t1 NULL range idx2 idx2 203 NULL 2 100.00 Using where; Using MRR
2530+
1 SIMPLE ids NULL ALL NULL NULL NULL NULL 2 100.00 Table function: json_table; Using temporary
2531+
Warnings:
2532+
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", "zz"]')
2533+
SELECT * FROM t1 WHERE 'xx' MEMBER OF (f2);
2534+
f1 f2
2535+
bar ["xx", "yy"]
2536+
SELECT * FROM t1 WHERE json_contains(f2, '"xx"');
2537+
f1 f2
2538+
bar ["xx", "yy"]
2539+
SELECT * FROM t1 WHERE json_overlaps(f2, '["xx", "zz"]');
2540+
f1 f2
2541+
bar ["xx", "yy"]
2542+
SELECT * FROM v1 WHERE 'xx' MEMBER OF (f2);
2543+
f1 f2 i id
2544+
bar ["xx", "yy"] 1 xx
2545+
bar ["xx", "yy"] 2 yy
2546+
SELECT * FROM v1 WHERE json_contains(f2, '"xx"');
2547+
f1 f2 i id
2548+
bar ["xx", "yy"] 1 xx
2549+
bar ["xx", "yy"] 2 yy
2550+
SELECT * FROM v1 WHERE json_overlaps(f2, '["xx", "zz"]');
2551+
f1 f2 i id
2552+
bar ["xx", "yy"] 1 xx
2553+
bar ["xx", "yy"] 2 yy
2554+
SELECT *
2555+
FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
2556+
PATH '$')) AS ids
2557+
WHERE 'xx' MEMBER OF (f2);
2558+
f1 f2 i id
2559+
bar ["xx", "yy"] 1 xx
2560+
bar ["xx", "yy"] 2 yy
2561+
SELECT *
2562+
FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
2563+
PATH '$')) AS ids
2564+
WHERE json_contains(f2, '"xx"');
2565+
f1 f2 i id
2566+
bar ["xx", "yy"] 1 xx
2567+
bar ["xx", "yy"] 2 yy
2568+
SELECT *
2569+
FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
2570+
PATH '$')) AS ids
2571+
WHERE json_overlaps(f2, '["xx", "zz"]');
2572+
f1 f2 i id
2573+
bar ["xx", "yy"] 1 xx
2574+
bar ["xx", "yy"] 2 yy
2575+
DROP VIEW v1;
2576+
DROP TABLE t1;
24582577
# restart:

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

Lines changed: 67 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1376,6 +1376,73 @@ SELECT * FROM t WHERE 3 MEMBER OF (vc);
13761376

13771377
DROP TABLE t;
13781378

1379+
--echo # Bug#33275457: Fix multi-valued index
1380+
1381+
CREATE TABLE t1 (
1382+
f1 VARCHAR(50) NOT NULL PRIMARY KEY,
1383+
f2 JSON NOT NULL,
1384+
INDEX idx2 ( (CAST(f2 AS CHAR(50) ARRAY)) )
1385+
);
1386+
1387+
CREATE VIEW v1 AS
1388+
SELECT * FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50) PATH '$')) AS ids;
1389+
1390+
INSERT INTO t1 VALUES ('foo', '["aa", "bb"]'), ('bar', '["xx", "yy"]');
1391+
1392+
ANALYZE TABLE t1;
1393+
1394+
EXPLAIN SELECT * FROM t1 WHERE 'xx' MEMBER OF (f2);
1395+
EXPLAIN SELECT * FROM t1 WHERE json_contains(f2, '"xx"');
1396+
EXPLAIN SELECT * FROM t1 WHERE json_overlaps(f2, '["xx", "zz"]');
1397+
1398+
EXPLAIN SELECT * FROM v1 WHERE 'xx' MEMBER OF (f2);
1399+
EXPLAIN SELECT * FROM v1 WHERE json_contains(f2, '"xx"');
1400+
EXPLAIN SELECT * FROM v1 WHERE json_overlaps(f2, '["xx", "zz"]');
1401+
1402+
EXPLAIN
1403+
SELECT *
1404+
FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
1405+
PATH '$')) AS ids
1406+
WHERE 'xx' MEMBER OF (f2);
1407+
1408+
EXPLAIN
1409+
SELECT *
1410+
FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
1411+
PATH '$')) AS ids
1412+
WHERE json_contains(f2, '"xx"');
1413+
1414+
EXPLAIN
1415+
SELECT *
1416+
FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
1417+
PATH '$')) AS ids
1418+
WHERE json_overlaps(f2, '["xx", "zz"]');
1419+
1420+
SELECT * FROM t1 WHERE 'xx' MEMBER OF (f2);
1421+
SELECT * FROM t1 WHERE json_contains(f2, '"xx"');
1422+
SELECT * FROM t1 WHERE json_overlaps(f2, '["xx", "zz"]');
1423+
1424+
SELECT * FROM v1 WHERE 'xx' MEMBER OF (f2);
1425+
SELECT * FROM v1 WHERE json_contains(f2, '"xx"');
1426+
SELECT * FROM v1 WHERE json_overlaps(f2, '["xx", "zz"]');
1427+
1428+
SELECT *
1429+
FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
1430+
PATH '$')) AS ids
1431+
WHERE 'xx' MEMBER OF (f2);
1432+
1433+
SELECT *
1434+
FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
1435+
PATH '$')) AS ids
1436+
WHERE json_contains(f2, '"xx"');
1437+
1438+
SELECT *
1439+
FROM t1, JSON_TABLE(f2, '$[*]' COLUMNS(i FOR ORDINALITY, id VARCHAR(50)
1440+
PATH '$')) AS ids
1441+
WHERE json_overlaps(f2, '["xx", "zz"]');
1442+
1443+
DROP VIEW v1;
1444+
DROP TABLE t1;
1445+
13791446
# If the unique record filter is not properly closed by any of queries above,
13801447
# then the TempTable plugin will have ref_count > 0 on restart. This should be
13811448
# at the very end of the test.

sql/item.cc

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -7090,7 +7090,7 @@ bool Item::cache_const_expr_analyzer(uchar **arg) {
70907090
}
70917091

70927092
bool Item::can_be_substituted_for_gc(bool array) const {
7093-
switch (type()) {
7093+
switch (real_item()->type()) {
70947094
case FUNC_ITEM:
70957095
case COND_ITEM:
70967096
return true;

sql/item_func.cc

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1018,6 +1018,7 @@ static bool is_function_of_type(const Item *item, Item_func::Functype type) {
10181018

10191019
Item_field *get_gc_for_expr(const Item *func, Field *fld, Item_result type,
10201020
Field **found) {
1021+
func = func->real_item();
10211022
Item *expr = fld->gcol_info->expr_item;
10221023

10231024
/*

0 commit comments

Comments
 (0)