MDEV-36132 Substitute vcol expressions with indexed vcol fields in ORDER BY

Also expand vcol field index coverings to include indexes covering all
the fields in the expression. The reasoning goes as follows: let f(c1,
c2, ..., cn) be a function on applied to columns c1, c2, ..., cn, if
f(...) is covered by an index, so should vc whose expression is
f(...).

For example, if t.vf = t.c1 + t.c2, and t has three indexes (vf), (c1,
c2), (c1).

Before this change, vf's index covering is a singleton {(vf)}. Let's call
that the "conventional" index covering.

After this change vf's index covering is now {(vf), (c1, c2)}, since
(c1, c2) covers both c1 and c2. Let's call (c1, c2) in this case the
"extra" covering.

With the coverings updated, when an index in the "extra" covering is
chosen for keyread, the vcol also needs to be calculated. In this case
we mark vcol in the table read_set, and ensure it is computed.

With these changes, we see various improvements, including from using
full table scan + filesort to full index scan + filesort when ORDER BY
an indexed vcol (here vc = c + 1 is a vcol and both c and vc are
indexes):

 explain select c + 1 from t order by vc;
 id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
-1	SIMPLE	t	ALL	NULL	NULL	NULL	NULL	10000	Using filesort
+1	SIMPLE	t	index	NULL	c	5	NULL	10000	Using index; Using filesort
This commit is contained in:
Yuchen Pei 2025-05-14 18:08:54 +10:00 committed by Sergei Golubchik
parent 206cabed3c
commit c8f527a5dd
17 changed files with 360 additions and 57 deletions

View File

@ -3662,13 +3662,13 @@ count(*)
# Test for type 'range|filter'
EXPLAIN SELECT count(*) FROM t1 WHERE a<100 and b <100;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range|filter b,a b|a 5|5 NULL 49 (10%) Using where; Using rowid filter
1 SIMPLE t1 range b,a a 5 NULL 99 Using where; Using index
SELECT count(*) FROM t1 WHERE a<100 and b <100;
count(*)
49
EXPLAIN SELECT count(*) FROM t1 WHERE a<100 and b <100 FOR UPDATE;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range|filter b,a b|a 5|5 NULL 49 (10%) Using where; Using rowid filter
1 SIMPLE t1 range b,a a 5 NULL 99 Using where; Using index
SELECT count(*) FROM t1 WHERE a<100 and b <100 FOR UPDATE;
count(*)
49
@ -3706,13 +3706,13 @@ count(*)
# Test for type 'range|filter'
EXPLAIN SELECT count(*) FROM t1 WHERE a<100 and b <100;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range|filter b,a b|a 5|5 NULL 49 (10%) Using where; Using rowid filter
1 SIMPLE t1 range b,a a 5 NULL 99 Using where; Using index
SELECT count(*) FROM t1 WHERE a<100 and b <100;
count(*)
49
EXPLAIN SELECT count(*) FROM t1 WHERE a<100 and b <100 FOR UPDATE;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range|filter b,a b|a 5|5 NULL 49 (10%) Using where; Using rowid filter
1 SIMPLE t1 range b,a a 5 NULL 99 Using where; Using index
SELECT count(*) FROM t1 WHERE a<100 and b <100 FOR UPDATE;
count(*)
49

View File

@ -61,7 +61,7 @@ a b c
1 -1 -1
explain select * from t3 where c>=-1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range c c 5 NULL 1 Using index condition
1 SIMPLE t3 range c c 5 NULL 1 Using where; Using index
# select_type=SIMPLE, type=ref
select * from t1,t3 where t1.c=t3.c and t3.c=-1;
a b c a b c
@ -69,7 +69,7 @@ a b c a b c
1 -1 -1 1 -1 -1
explain select * from t1,t3 where t1.c=t3.c and t3.c=-1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 const c c 5 const 1
1 SIMPLE t3 const c c 5 const 1 Using index
1 SIMPLE t1 ref c c 5 const 2
# select_type=PRIMARY, type=index,ALL
select * from t1 where b in (select c from t3);
@ -158,7 +158,7 @@ a b c
2 -2 -2
explain select * from t3 where c >= -2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range c c 5 NULL 2 Using index condition
1 SIMPLE t3 range c c 5 NULL 2 Using where; Using index
# SELECT * FROM tbl_name WHERE <non-gcol expr>
select * from t3 where a between 1 and 2;
a b c
@ -174,7 +174,7 @@ a b c
2 -2 -2
explain select * from t3 where b between -2 and -1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 ALL NULL NULL NULL NULL 6 Using where
1 SIMPLE t3 index NULL c 5 NULL 6 Using where; Using index
# SELECT * FROM tbl_name WHERE <indexed gcol expr>
select * from t3 where c between -2 and -1;
a b c
@ -182,7 +182,7 @@ a b c
2 -2 -2
explain select * from t3 where c between -2 and -1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range c c 5 NULL 2 Using index condition
1 SIMPLE t3 range c c 5 NULL 2 Using where; Using index
# SELECT * FROM tbl_name WHERE <non-gcol expr> ORDER BY <non-indexed gcol>
select * from t3 where a between 1 and 2 order by b;
a b c
@ -199,7 +199,7 @@ a b c
1 -1 -1
explain select * from t3 where a between 1 and 2 order by c;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range PRIMARY PRIMARY 4 NULL 2 Using where; Using filesort
1 SIMPLE t3 index PRIMARY c 5 NULL 6 Using where; Using index
# bug#20022189: WL411:DEBUG ASSERT AT FIELD_LONG::VAL_INT IN SQL/FIELD.CC
CREATE TABLE t4 (
`pk` int(11) NOT NULL ,
@ -229,7 +229,7 @@ a b c
1 -1 -1
explain select * from t3 where a between 1 and 2 order by c;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range PRIMARY PRIMARY 4 NULL 2 Using where; Using filesort
1 SIMPLE t3 index PRIMARY c 5 NULL 6 Using where; Using index
# SELECT * FROM tbl_name WHERE <non-indexed gcol expr> ORDER BY <non-gcol>
select * from t3 where b between -2 and -1 order by a;
a b c
@ -245,7 +245,7 @@ a b c
1 -1 -1
explain select * from t3 where b between -2 and -1 order by b;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 ALL NULL NULL NULL NULL 6 Using where; Using filesort
1 SIMPLE t3 index NULL c 5 NULL 6 Using where; Using index; Using filesort
# SELECT * FROM tbl_name WHERE <indexed gcol expr> ORDER BY <non-indexed gcol>
select * from t3 where c between -2 and -1 order by b;
a b c
@ -253,7 +253,7 @@ a b c
1 -1 -1
explain select * from t3 where c between -2 and -1 order by b;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range c c 5 NULL 2 Using index condition; Using filesort
1 SIMPLE t3 range c c 5 NULL 2 Using where; Using index; Using filesort
# SELECT * FROM tbl_name WHERE <non-indexed gcol expr> ORDER BY <indexed gcol>
select * from t3 where b between -2 and -1 order by c;
a b c
@ -261,7 +261,7 @@ a b c
1 -1 -1
explain select * from t3 where b between -2 and -1 order by c;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 ALL NULL NULL NULL NULL 6 Using where; Using filesort
1 SIMPLE t3 index NULL c 5 NULL 6 Using where; Using index
# SELECT * FROM tbl_name WHERE <indexed gcol expr> ORDER BY <indexed gcol>
select * from t3 where c between -2 and -1 order by c;
a b c
@ -269,7 +269,7 @@ a b c
1 -1 -1
explain select * from t3 where c between -2 and -1 order by c;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range c c 5 NULL 2 Using index condition
1 SIMPLE t3 range c c 5 NULL 2 Using where; Using index
# SELECT sum(<non-indexed gcol>) FROM tbl_name GROUP BY <non-indexed gcol>
select sum(b) from t1 group by b;
sum(b)

View File

@ -54,7 +54,7 @@ a b c
1 -1 -1
explain select * from t3 where a=1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 const PRIMARY PRIMARY 4 const 1
1 SIMPLE t3 const PRIMARY PRIMARY 4 const 1 Using index
# select_type=SIMPLE, type=range
select * from t3 where c>=-1;
a b c
@ -166,7 +166,7 @@ a b c
2 -2 -2
explain select * from t3 where a between 1 and 2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range PRIMARY PRIMARY 4 NULL 2 Using index condition
1 SIMPLE t3 range PRIMARY PRIMARY 4 NULL 2 Using where; Using index
# SELECT * FROM tbl_name WHERE <non-indexed gcol expr>
select * from t3 where b between -2 and -1;
a b c
@ -174,7 +174,7 @@ a b c
2 -2 -2
explain select * from t3 where b between -2 and -1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 ALL NULL NULL NULL NULL 6 Using where
1 SIMPLE t3 index NULL PRIMARY 4 NULL 6 Using where; Using index
# SELECT * FROM tbl_name WHERE <indexed gcol expr>
select * from t3 where c between -2 and -1;
a b c
@ -212,7 +212,7 @@ a b c
1 -1 -1
explain select * from t3 where a between 1 and 2 order by c;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range PRIMARY PRIMARY 4 NULL 2 Using index condition; Using filesort
1 SIMPLE t3 range PRIMARY PRIMARY 4 NULL 2 Using where; Using index; Using filesort
# SELECT * FROM tbl_name WHERE <non-indexed gcol expr> ORDER BY <non-gcol>
select * from t3 where b between -2 and -1 order by a;
a b c
@ -220,7 +220,7 @@ a b c
2 -2 -2
explain select * from t3 where b between -2 and -1 order by a;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 ALL NULL NULL NULL NULL 6 Using where; Using filesort
1 SIMPLE t3 index NULL PRIMARY 4 NULL 6 Using where; Using index
# SELECT * FROM tbl_name WHERE <indexed gcol expr> ORDER BY <non-gcol>
select * from t3 where c between -2 and -1 order by a;
a b c
@ -228,7 +228,7 @@ a b c
2 -2 -2
explain select * from t3 where c between -2 and -1 order by a;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range c c 5 NULL 2 Using index condition; Using filesort
1 SIMPLE t3 index c PRIMARY 4 NULL 6 Using where; Using index
# SELECT * FROM tbl_name WHERE <non-indexed gcol expr> ORDER BY <non-indexed gcol>
select * from t3 where b between -2 and -1 order by b;
a b c
@ -236,7 +236,7 @@ a b c
1 -1 -1
explain select * from t3 where b between -2 and -1 order by b;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 ALL NULL NULL NULL NULL 6 Using where; Using filesort
1 SIMPLE t3 index NULL PRIMARY 4 NULL 6 Using where; Using index; Using filesort
# SELECT * FROM tbl_name WHERE <indexed gcol expr> ORDER BY <non-indexed gcol>
select * from t3 where c between -2 and -1 order by b;
a b c
@ -252,7 +252,7 @@ a b c
1 -1 -1
explain select * from t3 where b between -2 and -1 order by c;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 ALL NULL NULL NULL NULL 6 Using where; Using filesort
1 SIMPLE t3 index NULL PRIMARY 4 NULL 6 Using where; Using index; Using filesort
# SELECT * FROM tbl_name WHERE <indexed gcol expr> ORDER BY <indexed gcol>
select * from t3 where c between -2 and -1 order by c;
a b c

View File

@ -338,8 +338,8 @@ NULL
100
SELECT fld2 FROM t FORCE INDEX(fld1);
fld2
100
NULL
100
Warnings:
Warning 1365 Division by 0
disconnect stop_purge;

View File

@ -0,0 +1,91 @@
#
# MDEV-36132 Optimizer support for functional indexes: handle GROUP/ORDER BY
#
create table t (c int, key (c));
insert into t select seq from seq_1_to_10000;
alter table t
add column vc int as (c + 1),
add index(vc);
explain select c from t order by c;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t index NULL c 5 NULL 10000 Using index
explain select vc from t order by vc;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t index NULL vc 5 NULL 10000 Using index
explain select vc from t order by vc limit 10;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t index NULL vc 5 NULL 10 Using index
explain select c + 1 from t order by c + 1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t index NULL c 5 NULL 10000 Using index; Using filesort
explain select c + 1 from t order by vc;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t index NULL c 5 NULL 10000 Using index; Using filesort
explain select vc from t order by c + 1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t index NULL c 5 NULL 10000 Using index; Using filesort
explain select vc from t order by c;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t index NULL c 5 NULL 10000 Using index
explain select c from t order by vc;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t index NULL c 5 NULL 10000 Using index; Using filesort
explain select c from t order by c + 1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t index NULL c 5 NULL 10000 Using index; Using filesort
explain select vc from t order by c + 1 limit 2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t index NULL vc 5 NULL 2
explain select c + 1 from t order by c + 1 limit 2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t index NULL vc 5 NULL 2
explain select c + 1 from t order by vc limit 2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t index NULL vc 5 NULL 2
set @old_optimizer_trace=@@optimizer_trace;
set optimizer_trace=1;
explain select c + 1 from t order by c + 1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t index NULL c 5 NULL 10000 Using index; Using filesort
select
json_detailed(json_extract(trace, '$**.virtual_column_substitution'))
from
information_schema.optimizer_trace;
json_detailed(json_extract(trace, '$**.virtual_column_substitution'))
[
{
"location": "ORDER BY",
"from": "t.c + 1",
"to": "t.vc"
}
]
set optimizer_trace=@old_optimizer_trace;
drop table t;
create table t (c int, key (c));
insert into t select seq from seq_1_to_10000;
alter table t
add column vc1 int as (c + 1),
add index(vc1);
alter table t
add column vc2 int as (vc1 * 2),
add index(vc2);
explain select c from t order by vc2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t index NULL c 5 NULL 10000 Using index; Using filesort
explain select vc2 from t order by vc1 * 2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t index NULL c 5 NULL 10000 Using index; Using filesort
explain select vc2 from t order by vc1 * 2 limit 2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t index NULL vc2 5 NULL 2
drop table t;
create table t (c int, vc int generated always as (1 + 1) virtual, key (c));
insert into t values (42, default), (83, default);
explain select vc from t order by vc;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t ALL NULL NULL NULL NULL 2 Using filesort
select vc from t order by vc;
vc
2
2
drop table t;

View File

@ -287,10 +287,10 @@ insert into t1 (a) select seq from seq_1_to_100;
# Sargable_casefold is applied before vcol substitution:
explain select * from t1 where UPPER(a)='abc';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ref a a 303 const 1 Using index condition
1 SIMPLE t1 ref a a 303 const 1 Using where; Using index
explain select * from t1 ignore index(vcol) where UPPER(a)='abc';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ref a a 303 const 1 Using index condition
1 SIMPLE t1 ref a a 303 const 1 Using where; Using index
explain select * from t1 ignore index(a) where UPPER(a)='abc';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 100 Using where
@ -317,7 +317,7 @@ EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": 0.002574553,
"cost": 0.001478954,
"nested_loop": [
{
"table": {
@ -329,9 +329,10 @@ EXPLAIN
"used_key_parts": ["a"],
"loops": 1,
"rows": 1,
"cost": 0.002574553,
"cost": 0.001478954,
"filtered": 100,
"index_condition": "t1.a between '2025-01-01' and '2025-12-31'"
"attached_condition": "t1.a between '2025-01-01' and '2025-12-31'",
"using_index": true
}
}
]

View File

@ -46,7 +46,7 @@ a b c
1 -1 -1
explain select * from t3 where c>=-1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range c c 5 NULL 1 Using index condition
1 SIMPLE t3 range c c 5 NULL 1 Using where; Using index
# select_type=SIMPLE, type=ref
select * from t1,t3 where t1.c=t3.c and t3.c=-1;
a b c a b c
@ -54,7 +54,7 @@ a b c a b c
1 -1 -1 1 -1 -1
explain select * from t1,t3 where t1.c=t3.c and t3.c=-1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 const c c 5 const 1
1 SIMPLE t3 const c c 5 const 1 Using index
1 SIMPLE t1 ref c c 5 const 2
# select_type=PRIMARY, type=index,ALL
select * from t1 where b in (select c from t3);
@ -146,7 +146,7 @@ a b c
1 -1 -1
explain select * from t3 where c >= -2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range c c 5 NULL 2 Using index condition
1 SIMPLE t3 range c c 5 NULL 2 Using where; Using index
# SELECT * FROM tbl_name WHERE <non-vcol expr>
select * from t3 where a between 1 and 2;
a b c
@ -158,11 +158,11 @@ id select_type table type possible_keys key key_len ref rows Extra
# SELECT * FROM tbl_name WHERE <non-indexed vcol expr>
select * from t3 where b between -2 and -1;
a b c
1 -1 -1
2 -2 -2
1 -1 -1
explain select * from t3 where b between -2 and -1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 ALL NULL NULL NULL NULL 6 Using where
1 SIMPLE t3 index NULL c 5 NULL 6 Using where; Using index
# SELECT * FROM tbl_name WHERE <indexed vcol expr>
select * from t3 where c between -2 and -1;
a b c
@ -170,7 +170,7 @@ a b c
1 -1 -1
explain select * from t3 where c between -2 and -1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range c c 5 NULL 2 Using index condition
1 SIMPLE t3 range c c 5 NULL 2 Using where; Using index
# SELECT * FROM tbl_name WHERE <non-vcol expr> ORDER BY <non-indexed vcol>
select * from t3 where a between 1 and 2 order by b;
a b c
@ -186,7 +186,7 @@ a b c
1 -1 -1
explain select * from t3 where a between 1 and 2 order by c;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range PRIMARY PRIMARY 4 NULL 2 Using where; Using filesort
1 SIMPLE t3 index PRIMARY c 5 NULL 6 Using where; Using index
# SELECT * FROM tbl_name WHERE <non-indexed vcol expr> ORDER BY <non-vcol>
select * from t3 where b between -2 and -1 order by a;
a b c
@ -202,7 +202,7 @@ a b c
1 -1 -1
explain select * from t3 where b between -2 and -1 order by b;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 ALL NULL NULL NULL NULL 6 Using where; Using filesort
1 SIMPLE t3 index NULL c 5 NULL 6 Using where; Using index; Using filesort
# SELECT * FROM tbl_name WHERE <indexed vcol expr> ORDER BY <non-indexed vcol>
select * from t3 where c between -2 and -1 order by b;
a b c
@ -210,7 +210,7 @@ a b c
1 -1 -1
explain select * from t3 where c between -2 and -1 order by b;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range c c 5 NULL 2 Using index condition; Using filesort
1 SIMPLE t3 range c c 5 NULL 2 Using where; Using index; Using filesort
# SELECT * FROM tbl_name WHERE <non-indexed vcol expr> ORDER BY <indexed vcol>
select * from t3 where b between -2 and -1 order by c;
a b c
@ -218,7 +218,7 @@ a b c
1 -1 -1
explain select * from t3 where b between -2 and -1 order by c;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 ALL NULL NULL NULL NULL 6 Using where; Using filesort
1 SIMPLE t3 index NULL c 5 NULL 6 Using where; Using index
# SELECT * FROM tbl_name WHERE <indexed vcol expr> ORDER BY <indexed vcol>
select * from t3 where c between -2 and -1 order by c;
a b c
@ -226,7 +226,7 @@ a b c
1 -1 -1
explain select * from t3 where c between -2 and -1 order by c;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range c c 5 NULL 2 Using index condition
1 SIMPLE t3 range c c 5 NULL 2 Using where; Using index
# SELECT sum(<non-indexed vcol>) FROM tbl_name GROUP BY <non-indexed vcol>
select sum(b) from t1 group by b;
sum(b)

View File

@ -37,7 +37,7 @@ a b c
1 -1 -1
explain select * from t3 where a=1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 const PRIMARY PRIMARY 4 const 1
1 SIMPLE t3 const PRIMARY PRIMARY 4 const 1 Using index
# select_type=SIMPLE, type=range
select * from t3 where c>=-1;
a b c
@ -152,15 +152,15 @@ a b c
2 -2 -2
explain select * from t3 where a between 1 and 2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range PRIMARY PRIMARY 4 NULL 2 Using index condition
1 SIMPLE t3 range PRIMARY PRIMARY 4 NULL 2 Using where; Using index
# SELECT * FROM tbl_name WHERE <non-indexed vcol expr>
select * from t3 where b between -2 and -1;
a b c
2 -2 -2
1 -1 -1
2 -2 -2
explain select * from t3 where b between -2 and -1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 ALL NULL NULL NULL NULL 6 Using where
1 SIMPLE t3 index NULL PRIMARY 4 NULL 6 Using where; Using index
# SELECT * FROM tbl_name WHERE <indexed vcol expr>
select * from t3 where c between -2 and -1;
a b c
@ -176,7 +176,7 @@ a b c
1 -1 -1
explain select * from t3 where a between 1 and 2 order by c;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range PRIMARY PRIMARY 4 NULL 2 Using index condition; Using filesort
1 SIMPLE t3 range PRIMARY PRIMARY 4 NULL 2 Using where; Using index; Using filesort
# SELECT * FROM tbl_name WHERE <non-indexed vcol expr> ORDER BY <non-vcol>
select * from t3 where b between -2 and -1 order by a;
a b c
@ -184,7 +184,7 @@ a b c
2 -2 -2
explain select * from t3 where b between -2 and -1 order by a;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 ALL NULL NULL NULL NULL 6 Using where; Using filesort
1 SIMPLE t3 index NULL PRIMARY 4 NULL 6 Using where; Using index
# SELECT * FROM tbl_name WHERE <indexed vcol expr> ORDER BY <non-vcol>
select * from t3 where c between -2 and -1 order by a;
a b c
@ -192,7 +192,7 @@ a b c
2 -2 -2
explain select * from t3 where c between -2 and -1 order by a;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 range c c 5 NULL 2 Using index condition; Using filesort
1 SIMPLE t3 index c PRIMARY 4 NULL 6 Using where; Using index
# SELECT * FROM tbl_name WHERE <non-indexed vcol expr> ORDER BY <non-indexed vcol>
select * from t3 where b between -2 and -1 order by b;
a b c
@ -200,7 +200,7 @@ a b c
1 -1 -1
explain select * from t3 where b between -2 and -1 order by b;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 ALL NULL NULL NULL NULL 6 Using where; Using filesort
1 SIMPLE t3 index NULL PRIMARY 4 NULL 6 Using where; Using index; Using filesort
# SELECT * FROM tbl_name WHERE <indexed vcol expr> ORDER BY <non-indexed vcol>
select * from t3 where c between -2 and -1 order by b;
a b c
@ -216,7 +216,7 @@ a b c
1 -1 -1
explain select * from t3 where b between -2 and -1 order by c;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 ALL NULL NULL NULL NULL 6 Using where; Using filesort
1 SIMPLE t3 index NULL PRIMARY 4 NULL 6 Using where; Using index; Using filesort
# SELECT * FROM tbl_name WHERE <indexed vcol expr> ORDER BY <indexed vcol>
select * from t3 where c between -2 and -1 order by c;
a b c

View File

@ -0,0 +1,95 @@
--echo #
--echo # MDEV-36132 Optimizer support for functional indexes: handle GROUP/ORDER BY
--echo #
--source include/have_sequence.inc
create table t (c int, key (c));
insert into t select seq from seq_1_to_10000;
alter table t
add column vc int as (c + 1),
add index(vc);
explain select c from t order by c;
explain select vc from t order by vc;
explain select vc from t order by vc limit 10;
explain select c + 1 from t order by c + 1;
explain select c + 1 from t order by vc;
explain select vc from t order by c + 1;
explain select vc from t order by c;
explain select c from t order by vc;
explain select c from t order by c + 1;
explain select vc from t order by c + 1 limit 2;
explain select c + 1 from t order by c + 1 limit 2;
explain select c + 1 from t order by vc limit 2;
## optimizer trace
set @old_optimizer_trace=@@optimizer_trace;
set optimizer_trace=1;
explain select c + 1 from t order by c + 1;
select
json_detailed(json_extract(trace, '$**.virtual_column_substitution'))
from
information_schema.optimizer_trace;
set optimizer_trace=@old_optimizer_trace;
drop table t;
# vcol on vcol
create table t (c int, key (c));
insert into t select seq from seq_1_to_10000;
alter table t
add column vc1 int as (c + 1),
add index(vc1);
alter table t
add column vc2 int as (vc1 * 2),
add index(vc2);
explain select c from t order by vc2;
explain select vc2 from t order by vc1 * 2;
explain select vc2 from t order by vc1 * 2 limit 2;
drop table t;
# vcol not depending on other col
create table t (c int, vc int generated always as (1 + 1) virtual, key (c));
insert into t values (42, default), (83, default);
explain select vc from t order by vc;
select vc from t order by vc;
drop table t;
# multiple indexes
create table t (c int);
insert into t select seq from seq_1_to_10000;
alter table t
add column vc1 int as (c + 1);
alter table t
add column vc2 int as (1 - c),
add index(vc1, vc2);
explain select vc1, vc2 from t order by c + 1, 1 - c;
drop table t;
# multiple items in order by
create table t (c int, key (c));
insert into t select seq from seq_1_to_10000;
alter table t
add column vc1 int as (c + 1),
add index(vc1);
alter table t
add column vc2 int as (1 - c),
add index(vc2);
set @old_optimizer_trace=@@optimizer_trace;
set optimizer_trace=1;
explain select * from t order by c + 1, 1 - c;
select
json_detailed(json_extract(trace, '$**.virtual_column_substitution'))
from
information_schema.optimizer_trace;
set optimizer_trace=@old_optimizer_trace;
drop table t;

View File

@ -1932,7 +1932,7 @@ Field::Field(uchar *ptr_arg,uint32 length_arg,uchar *null_ptr_arg,
null_ptr(null_ptr_arg), table(0), orig_table(0),
table_name(0), field_name(*field_name_arg), option_list(0),
option_struct(0), key_start(0), part_of_key(0),
part_of_key_not_clustered(0), part_of_sortkey(0),
part_of_key_not_clustered(0), vcol_part_of_key(0), part_of_sortkey(0),
unireg_check(unireg_check_arg), invisible(VISIBLE), field_length(length_arg),
null_bit(null_bit_arg), is_created_from_null_item(FALSE),
read_stats(NULL), collected_stats(0), vcol_info(0), check_constraint(0),
@ -2601,6 +2601,7 @@ Field *Field::make_new_field(MEM_ROOT *root, TABLE *new_table,
tmp->table= new_table;
tmp->key_start.init(0);
tmp->part_of_key.init(0);
tmp->vcol_part_of_key.init(0);
tmp->part_of_sortkey.init(0);
tmp->read_stats= NULL;
/*

View File

@ -824,6 +824,14 @@ public:
ha_field_option_struct *option_struct; /* structure with parsed options */
/* Field is part of the following keys */
key_map key_start, part_of_key, part_of_key_not_clustered;
/*
If the field is a vcol, its part_of_key not only contain keys that
have vcol as parts ("conventional"), but also keys with vcol
expression fields as parts ("extra"), computed from
`intersect_field_part_of_key'. The field `vcol_part_of_key' is
the "conventional" part_of_key.
*/
key_map vcol_part_of_key;
/*
Bitmap of indexes that have records ordered by col1, ... this_field, ...

View File

@ -5667,6 +5667,8 @@ bool ha_partition::init_record_priority_queue()
blob_storage+= table->s->blob_fields;
}
int2store(ptr + sizeof(String **), i);
DBUG_ASSERT(m_rec_length == table->s->reclength);
memcpy(ptr + ORDERED_REC_OFFSET, table->s->default_values, m_rec_length);
ptr+= m_priority_queue_rec_len;
}
m_start_key.key= (const uchar*)ptr;

View File

@ -1023,6 +1023,18 @@ bool Item_field::update_vcol_processor(void *arg)
return 0;
}
/*
If Item_field itself is a vcol, the underlying field would have
already had its part_of_key fixed, so there is no need to recurse
further
*/
bool Item_field::intersect_field_part_of_key(void *arg)
{
key_map *part_of_key= (key_map *) arg;
part_of_key->intersect(field->part_of_key);
return 0;
}
bool Item::check_cols(uint c)
{

View File

@ -2255,6 +2255,11 @@ public:
virtual bool register_field_in_write_map(void *arg) { return 0; }
virtual bool register_field_in_bitmap(void *arg) { return 0; }
virtual bool update_table_bitmaps_processor(void *arg) { return 0; }
/*
Compute the intersection of index coverings of all fields in the
tree. Used for updating the index coverings of vcols.
*/
virtual bool intersect_field_part_of_key(void *arg) { return 0; }
virtual bool enumerate_field_refs_processor(void *arg) { return 0; }
virtual bool mark_as_eliminated_processor(void *arg) { return 0; }
@ -3894,6 +3899,7 @@ public:
bool register_field_in_read_map(void *arg) override;
bool register_field_in_write_map(void *arg) override;
bool register_field_in_bitmap(void *arg) override;
bool intersect_field_part_of_key(void *arg) override;
bool check_partition_func_processor(void *) override {return false;}
bool post_fix_fields_part_expr_processor(void *bool_arg) override;
bool check_valid_arguments_processor(void *bool_arg) override;

View File

@ -115,6 +115,12 @@ class Vcol_subst_context
Vcol_subst_context(THD *thd_arg) : thd(thd_arg) {}
};
static Field *is_vcol_expr(Vcol_subst_context *ctx, const Item *item);
static
void subst_vcol_if_compatible(Vcol_subst_context *ctx,
Item_bool_func *cond,
Item **vcol_expr_ref,
Field *vcol_field);
static
bool collect_indexed_vcols_for_table(TABLE *table, List<Field> *vcol_fields)
@ -192,6 +198,30 @@ void subst_vcols_in_join_list(Vcol_subst_context *ctx,
}
/* Substitute vcol expressions with vcol fields in ORDER BY */
static
void subst_vcols_in_order(Vcol_subst_context *ctx,
ORDER *order,
const char *location)
{
Field *vcol_field;
for (; order; order= order->next)
{
Item *item= *order->item;
ctx->subst_count= 0;
if ((vcol_field= is_vcol_expr(ctx, item)))
subst_vcol_if_compatible(ctx, NULL, order->item, vcol_field);
if (ctx->subst_count && unlikely(ctx->thd->trace_started()))
{
Json_writer_object trace_wrapper(ctx->thd);
Json_writer_object trace_order_by(ctx->thd, "virtual_column_substitution");
trace_order_by.add("location", location);
trace_order_by.add("from", item);
trace_order_by.add("to", *order->item);
}
}
}
/*
@brief
Do substitution for all condition in a JOIN. This is the primary entry
@ -211,6 +241,9 @@ bool substitute_indexed_vcols_for_join(JOIN *join)
subst_vcols_in_item(&ctx, join->conds, "WHERE");
if (join->join_list)
subst_vcols_in_join_list(&ctx, join->join_list);
/* TODO: third arg is dummy for now. Also add GROUP BY. */
if (join->order)
subst_vcols_in_order(&ctx, join->order, "ORDER BY");
if (join->thd->is_error())
return true; // Out of memory
@ -345,9 +378,12 @@ void subst_vcol_if_compatible(Vcol_subst_context *ctx,
(vcol_expr->maybe_null() && !vcol_field->maybe_null()))
fail_cause="type mismatch";
else
if (vcol_expr->collation.collation != vcol_field->charset() &&
cond->compare_collation() != vcol_field->charset())
fail_cause="collation mismatch";
{
CHARSET_INFO *cs= cond ? cond->compare_collation() : NULL;
if (vcol_expr->collation.collation != vcol_field->charset() &&
cs != vcol_field->charset())
fail_cause="collation mismatch";
}
if (fail_cause)
{

View File

@ -34121,6 +34121,21 @@ void JOIN::init_join_cache_and_keyread()
tuple.
*/
table->mark_index_columns(table->file->keyread, table->read_set);
/*
Also mark in the read_set vcol fields whose "extra" index
coverings contain the keyread key, so that they are included
in filesort and satisfy an assertion later.
*/
if (table->vfield)
{
for (Field **vfield_ptr= table->vfield; *vfield_ptr; vfield_ptr++)
{
Field *vf= *vfield_ptr;
if (!vf->vcol_part_of_key.is_set(table->file->keyread) &&
vf->part_of_key.is_set(table->file->keyread))
bitmap_set_bit(table->read_set, vf->field_index);
}
}
}
bool init_for_explain= false;

View File

@ -1129,6 +1129,32 @@ Item_func_hash *TABLE_SHARE::make_long_hash_func(THD *thd,
return new (mem_root) Item_func_hash(thd, *field_list);
}
/*
Update index covering for a vcol field, by merging its existing
index covering with the intersection of all index coverings of leaf
fields of the vcol expr
*/
static void update_vcol_key_covering(Field *vcol_field)
{
Item *item= vcol_field->vcol_info->expr;
key_map part_of_key;
part_of_key.set_all();
item->walk(&Item::intersect_field_part_of_key, 1, &part_of_key);
/*
If no intersection has happened it suggests that the vcol is not
dependent on any other field, and there is no need to update its
index covering.
*/
if (part_of_key.is_set(MAX_INDEXES - 1))
return;
/*
Make a "backup" of the "conventional" index covering, which will
be used to determine whether the vcol value needs to be computed
in keyread
*/
vcol_field->vcol_part_of_key= vcol_field->part_of_key;
vcol_field->part_of_key.merge(part_of_key);
}
/** Parse TABLE_SHARE::vcol_defs
@ -1268,6 +1294,8 @@ bool parse_vcol_defs(THD *thd, MEM_ROOT *mem_root, TABLE *table,
goto end;
}
table->map= 0;
if (vcol)
update_vcol_key_covering(*field_ptr);
break;
case VCOL_DEFAULT:
vcol= unpack_vcol_info_from_frm(thd, table, &expr_str,
@ -9230,8 +9258,6 @@ int TABLE::update_virtual_fields(handler *h, enum_vcol_update_mode update_mode)
bool handler_pushed= 0, update_all_columns= 1;
DBUG_ASSERT(vfield);
if (h->keyread_enabled())
DBUG_RETURN(0);
/*
TODO: this imposes memory leak until table flush when save_in_field()
does expr_arena allocation. F.ex. case in
@ -9274,8 +9300,18 @@ int TABLE::update_virtual_fields(handler *h, enum_vcol_update_mode update_mode)
bool update= 0, swap_values= 0;
switch (update_mode) {
case VCOL_UPDATE_FOR_READ:
update= (!vcol_info->is_stored() &&
bitmap_is_set(read_set, vf->field_index));
/*
Compute the vf value if doing keyread on one of its "extra"
covering keys, OR if not doing keyread and vf is not stored
and marked in the read_set.
*/
if (h->keyread_enabled() &&
!vf->vcol_part_of_key.is_set(h->keyread) &&
vf->part_of_key.is_set(h->keyread))
update= true;
else
update= (!h->keyread_enabled() && !vcol_info->is_stored() &&
bitmap_is_set(read_set, vf->field_index));
swap_values= 1;
break;
case VCOL_UPDATE_FOR_DELETE: