Skip to content

Commit 1c2a831

Browse files
committed
MDEV-35616: Add basic optimizer support for virtual column
(Review input addressed) After this patch, the optimizer can handle virtual column expressions in WHERE/ON clauses. If the table has an indexed virtual column: ALTER TABLE t1 ADD COLUMN vcol INT AS (col1+1), ADD INDEX idx1(vcol); and the query uses the exact virtual column expression: SELECT * FROM t1 WHERE col1+1 <= 100 then the optimizer will be able use index idx1 for it. This is achieved by walking the WHERE/ON clauses and replacing instances of virtual column expression (like "col1+1" above) with virtual column's Item_field (like "vcol"). The latter can be processed by the optimizer. Replacement is considered (and done) only in items that are potentially usable to the range optimizer.
1 parent 759df4c commit 1c2a831

17 files changed

+1057
-18
lines changed

libmysqld/CMakeLists.txt

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -75,6 +75,7 @@ SET(SQL_EMBEDDED_SOURCES emb_qcache.cc libmysqld.c lib_sql.cc
7575
../sql/opt_rewrite_remove_casefold.cc
7676
../sql/opt_sargable_left.cc
7777
../sql/opt_sum.cc
78+
../sql/opt_vcol_substitution.cc
7879
../sql/parse_file.cc ../sql/procedure.cc ../sql/protocol.cc
7980
../sql/records.cc ../sql/repl_failsafe.cc ../sql/rpl_filter.cc
8081
../sql/rpl_record.cc ../sql/des_key_file.cc

mysql-test/suite/gcol/r/gcol_keys_innodb.result

Lines changed: 11 additions & 9 deletions
Original file line numberDiff line numberDiff line change
@@ -354,28 +354,28 @@ f1 gc
354354
9 10
355355
EXPLAIN SELECT * FROM t1 WHERE f1 + 1 > 7;
356356
id select_type table type possible_keys key key_len ref rows Extra
357-
1 SIMPLE t1 ALL NULL NULL NULL NULL 10 Using where
357+
1 SIMPLE t1 range gc gc 5 NULL 3 Using index condition
358358
SELECT * FROM t1 WHERE f1 + 1 = 7;
359359
f1 gc
360360
6 7
361361
EXPLAIN SELECT * FROM t1 WHERE f1 + 1 = 7;
362362
id select_type table type possible_keys key key_len ref rows Extra
363-
1 SIMPLE t1 ALL NULL NULL NULL NULL 10 Using where
363+
1 SIMPLE t1 const gc gc 5 const 1
364364
SELECT * FROM t1 WHERE f1 + 1 IN (7,5);
365365
f1 gc
366366
4 5
367367
6 7
368368
EXPLAIN SELECT * FROM t1 WHERE f1 + 1 IN(7,5);
369369
id select_type table type possible_keys key key_len ref rows Extra
370-
1 SIMPLE t1 ALL NULL NULL NULL NULL 10 Using where
370+
1 SIMPLE t1 range gc gc 5 NULL 2 Using index condition
371371
SELECT * FROM t1 WHERE f1 + 1 BETWEEN 5 AND 7;
372372
f1 gc
373373
4 5
374374
5 6
375375
6 7
376376
EXPLAIN SELECT * FROM t1 WHERE f1 + 1 BETWEEN 5 AND 7;
377377
id select_type table type possible_keys key key_len ref rows Extra
378-
1 SIMPLE t1 ALL NULL NULL NULL NULL 10 Using where
378+
1 SIMPLE t1 range gc gc 5 NULL 3 Using index condition
379379
# Check that expression isn't transformed for a disabled key
380380
SELECT * FROM t1 IGNORE KEY (gc) WHERE f1 + 1 BETWEEN 5 AND 7;
381381
f1 gc
@@ -432,7 +432,7 @@ f1 gc
432432
9 10
433433
EXPLAIN SELECT * FROM t1 WHERE f1 + 1 > 7.0;
434434
id select_type table type possible_keys key key_len ref rows Extra
435-
1 SIMPLE t1 ALL NULL NULL NULL NULL 10 Using where
435+
1 SIMPLE t1 range gc gc 5 NULL 3 Using index condition
436436
DROP TABLE t1;
437437
# Pick index with proper type
438438
CREATE TABLE t1 (f1 int,
@@ -463,7 +463,7 @@ f1 gc_int gc_date
463463
# INT column & index should be picked
464464
EXPLAIN SELECT * FROM t1 WHERE f1 + 1 > 070707;
465465
id select_type table type possible_keys key key_len ref rows Extra
466-
1 SIMPLE t1 ALL NULL NULL NULL NULL 18 Using where
466+
1 SIMPLE t1 range gc_int_idx gc_int_idx 5 NULL 4 Using index condition
467467
SELECT * FROM t1 WHERE f1 + 1 > CAST(070707 AS DATE);
468468
f1 gc_int gc_date
469469
101010 101011 2010-10-11
@@ -473,7 +473,9 @@ f1 gc_int gc_date
473473
# DATE column & index should be picked
474474
EXPLAIN SELECT * FROM t1 WHERE f1 + 1 > CAST(070707 AS DATE);
475475
id select_type table type possible_keys key key_len ref rows Extra
476-
1 SIMPLE t1 ALL NULL NULL NULL NULL 18 Using where
476+
1 SIMPLE t1 ALL gc_int_idx NULL NULL NULL 18 Using where
477+
Warnings:
478+
Note 1105 Cannot use key `gc_int_idx` part[0] for lookup: `test`.`t1`.`gc_int` of type `int` > "cast(70707 as date)" of type `date`
477479
DROP TABLE t1;
478480
#
479481
# BUG#21229846: WL8170: SIGNAL 11 IN JOIN::MAKE_SUM_FUNC_LIST
@@ -764,14 +766,14 @@ a b
764766
1 1
765767
EXPLAIN SELECT a, b FROM t WHERE (a XOR b) = 1;
766768
id select_type table type possible_keys key key_len ref rows Extra
767-
1 SIMPLE t ALL NULL NULL NULL NULL 4 Using where
769+
1 SIMPLE t ref gc_xor gc_xor 5 const 2
768770
SELECT a, b FROM t WHERE (a XOR b) = 1;
769771
a b
770772
0 1
771773
1 0
772774
EXPLAIN SELECT a FROM t WHERE (NOT a) = 1;
773775
id select_type table type possible_keys key key_len ref rows Extra
774-
1 SIMPLE t ALL NULL NULL NULL NULL 4 Using where
776+
1 SIMPLE t ref gc_not gc_not 5 const 2
775777
SELECT a FROM t WHERE (NOT a) = 1;
776778
a
777779
0

mysql-test/suite/gcol/r/gcol_keys_myisam.result

Lines changed: 11 additions & 9 deletions
Original file line numberDiff line numberDiff line change
@@ -354,28 +354,28 @@ f1 gc
354354
9 10
355355
EXPLAIN SELECT * FROM t1 WHERE f1 + 1 > 7;
356356
id select_type table type possible_keys key key_len ref rows Extra
357-
1 SIMPLE t1 ALL NULL NULL NULL NULL 10 Using where
357+
1 SIMPLE t1 range gc gc 5 NULL 3 Using index condition
358358
SELECT * FROM t1 WHERE f1 + 1 = 7;
359359
f1 gc
360360
6 7
361361
EXPLAIN SELECT * FROM t1 WHERE f1 + 1 = 7;
362362
id select_type table type possible_keys key key_len ref rows Extra
363-
1 SIMPLE t1 ALL NULL NULL NULL NULL 10 Using where
363+
1 SIMPLE t1 const gc gc 5 const 1
364364
SELECT * FROM t1 WHERE f1 + 1 IN (7,5);
365365
f1 gc
366366
4 5
367367
6 7
368368
EXPLAIN SELECT * FROM t1 WHERE f1 + 1 IN(7,5);
369369
id select_type table type possible_keys key key_len ref rows Extra
370-
1 SIMPLE t1 ALL NULL NULL NULL NULL 10 Using where
370+
1 SIMPLE t1 range gc gc 5 NULL 2 Using index condition
371371
SELECT * FROM t1 WHERE f1 + 1 BETWEEN 5 AND 7;
372372
f1 gc
373373
4 5
374374
5 6
375375
6 7
376376
EXPLAIN SELECT * FROM t1 WHERE f1 + 1 BETWEEN 5 AND 7;
377377
id select_type table type possible_keys key key_len ref rows Extra
378-
1 SIMPLE t1 ALL NULL NULL NULL NULL 10 Using where
378+
1 SIMPLE t1 range gc gc 5 NULL 3 Using index condition
379379
# Check that expression isn't transformed for a disabled key
380380
SELECT * FROM t1 IGNORE KEY (gc) WHERE f1 + 1 BETWEEN 5 AND 7;
381381
f1 gc
@@ -432,7 +432,7 @@ f1 gc
432432
9 10
433433
EXPLAIN SELECT * FROM t1 WHERE f1 + 1 > 7.0;
434434
id select_type table type possible_keys key key_len ref rows Extra
435-
1 SIMPLE t1 ALL NULL NULL NULL NULL 10 Using where
435+
1 SIMPLE t1 range gc gc 5 NULL 3 Using index condition
436436
DROP TABLE t1;
437437
# Pick index with proper type
438438
CREATE TABLE t1 (f1 int,
@@ -463,7 +463,7 @@ f1 gc_int gc_date
463463
# INT column & index should be picked
464464
EXPLAIN SELECT * FROM t1 WHERE f1 + 1 > 070707;
465465
id select_type table type possible_keys key key_len ref rows Extra
466-
1 SIMPLE t1 ALL NULL NULL NULL NULL 18 Using where
466+
1 SIMPLE t1 range gc_int_idx gc_int_idx 5 NULL 4 Using index condition
467467
SELECT * FROM t1 WHERE f1 + 1 > CAST(070707 AS DATE);
468468
f1 gc_int gc_date
469469
101010 101011 2010-10-11
@@ -473,7 +473,9 @@ f1 gc_int gc_date
473473
# DATE column & index should be picked
474474
EXPLAIN SELECT * FROM t1 WHERE f1 + 1 > CAST(070707 AS DATE);
475475
id select_type table type possible_keys key key_len ref rows Extra
476-
1 SIMPLE t1 ALL NULL NULL NULL NULL 18 Using where
476+
1 SIMPLE t1 ALL gc_int_idx NULL NULL NULL 18 Using where
477+
Warnings:
478+
Note 1105 Cannot use key `gc_int_idx` part[0] for lookup: `test`.`t1`.`gc_int` of type `int` > "cast(70707 as date)" of type `date`
477479
DROP TABLE t1;
478480
#
479481
# BUG#21229846: WL8170: SIGNAL 11 IN JOIN::MAKE_SUM_FUNC_LIST
@@ -764,14 +766,14 @@ a b
764766
1 1
765767
EXPLAIN SELECT a, b FROM t WHERE (a XOR b) = 1;
766768
id select_type table type possible_keys key key_len ref rows Extra
767-
1 SIMPLE t ALL NULL NULL NULL NULL 4 Using where
769+
1 SIMPLE t ref gc_xor gc_xor 5 const 2
768770
SELECT a, b FROM t WHERE (a XOR b) = 1;
769771
a b
770772
0 1
771773
1 0
772774
EXPLAIN SELECT a FROM t WHERE (NOT a) = 1;
773775
id select_type table type possible_keys key key_len ref rows Extra
774-
1 SIMPLE t ALL NULL NULL NULL NULL 4 Using where
776+
1 SIMPLE t ref gc_not gc_not 5 const 2
775777
SELECT a FROM t WHERE (NOT a) = 1;
776778
a
777779
0

0 commit comments

Comments
 (0)