Skip to content

Commit e021770

Browse files
MDEV-34911 Sargable substr(col, 1, n) = str
Make Item_func_eq of the following forms sargable by updating the relevant range analysis methods: 1. substr(col, 1, n) = str 2. str = substr(col, 1, n) 3. left(col, n) = str 4. str = left(col, n) where col is a indexed column and str is a const and inexpensive item of length n. We do this by factoring out Item_func_like::get_mm_leaf() and apply it to a string obtained from escaping str and then appending a wildcard "%" to it. The addition of the two Functype enums, LEFT_FUNC and SUBSTR_FUNC, requires changes in the spider group by handler to continue handling LEFT and SUBSTR correctly. Co-authored-by: Yuchen Pei <ycp@mariadb.com> Co-authored-by: Sergei Petrunia <sergey@mariadb.com>
1 parent ae998c2 commit e021770

File tree

13 files changed

+666
-100
lines changed

13 files changed

+666
-100
lines changed

libmysqld/CMakeLists.txt

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -73,6 +73,7 @@ SET(SQL_EMBEDDED_SOURCES emb_qcache.cc libmysqld.c lib_sql.cc
7373
../sql/net_serv.cc ../sql/opt_range.cc
7474
../sql/opt_rewrite_date_cmp.cc
7575
../sql/opt_rewrite_remove_casefold.cc
76+
../sql/opt_sargable_left.cc
7677
../sql/opt_sum.cc
7778
../sql/parse_file.cc ../sql/procedure.cc ../sql/protocol.cc
7879
../sql/records.cc ../sql/repl_failsafe.cc ../sql/rpl_filter.cc

mysql-test/main/func_str.result

Lines changed: 150 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -5806,4 +5806,154 @@ coercibility(database()) 3
58065806
#
58075807
# End of 11.5 tests
58085808
#
5809+
#
5810+
# MDEV-34911 Make conditions SUBSTR(col, 1, n) = const_str sargable
5811+
#
5812+
create table t (c varchar(5), key (c));
5813+
insert into t values ('ddd'), ('bbcd'), ('bba'), ('b%_cd'), ('aaa');
5814+
explain select * from t where substr(c, 1, 2) = 'bb';
5815+
id select_type table type possible_keys key key_len ref rows Extra
5816+
1 SIMPLE t range c c 8 NULL 2 Using where; Using index
5817+
select * from t where substr(c, 1, 2) = 'bb';
5818+
c
5819+
bba
5820+
bbcd
5821+
explain select * from t where 'bb' = substr(c, 1, 2);
5822+
id select_type table type possible_keys key key_len ref rows Extra
5823+
1 SIMPLE t range c c 8 NULL 2 Using where; Using index
5824+
select * from t where 'bb' = substr(c, 1, 2);
5825+
c
5826+
bba
5827+
bbcd
5828+
explain select * from t where left(c, 2) = 'bb';
5829+
id select_type table type possible_keys key key_len ref rows Extra
5830+
1 SIMPLE t range c c 8 NULL 2 Using where; Using index
5831+
select * from t where left(c, 2) = 'bb';
5832+
c
5833+
bba
5834+
bbcd
5835+
explain select * from t where 'bb' = left(c, 2);
5836+
id select_type table type possible_keys key key_len ref rows Extra
5837+
1 SIMPLE t range c c 8 NULL 2 Using where; Using index
5838+
select * from t where 'bb' = left(c, 2);
5839+
c
5840+
bba
5841+
bbcd
5842+
explain select * from t where substr(c, 1, 4) = 'b%_c';
5843+
id select_type table type possible_keys key key_len ref rows Extra
5844+
1 SIMPLE t range c c 8 NULL 1 Using where; Using index
5845+
select * from t where substr(c, 1, 4) = 'b%_c';
5846+
c
5847+
b%_cd
5848+
explain select * from t where substr(c, 1, 2) = concat('b', 'b');
5849+
id select_type table type possible_keys key key_len ref rows Extra
5850+
1 SIMPLE t range c c 8 NULL 2 Using where; Using index
5851+
select * from t where substr(c, 1, 2) = concat('b', 'b');
5852+
c
5853+
bba
5854+
bbcd
5855+
explain select * from t where substr(c, 1, 2) = substr('bb1', 1, 2);
5856+
id select_type table type possible_keys key key_len ref rows Extra
5857+
1 SIMPLE t range c c 8 NULL 2 Using where; Using index
5858+
select * from t where substr(c, 1, 2) = substr('bb1', 1, 2);
5859+
c
5860+
bba
5861+
bbcd
5862+
create table t1 (a varchar(32), b int, index(a));
5863+
insert into t1 select seq, seq / 33 from seq_1_to_100;
5864+
explain select * from t1 where substr(a, 1, 2)='80';
5865+
id select_type table type possible_keys key key_len ref rows Extra
5866+
1 SIMPLE t1 range a a 35 NULL 1 Using index condition
5867+
explain select * from t1 where substr(a, 1, b)='80';
5868+
id select_type table type possible_keys key key_len ref rows Extra
5869+
1 SIMPLE t1 range a a 35 NULL 1 Using where
5870+
create view v1 as select a,b from t1;
5871+
explain select * from v1 where substr(a, 1, 2)='80';
5872+
id select_type table type possible_keys key key_len ref rows Extra
5873+
1 SIMPLE t1 range a a 35 NULL 1 Using index condition
5874+
drop view v1;
5875+
drop table t1;
5876+
explain select * from t where substr(c, 1, 1) = 'bb';
5877+
id select_type table type possible_keys key key_len ref rows Extra
5878+
1 SIMPLE t range c c 8 NULL 2 Using where; Using index
5879+
select * from t where substr(c, 1, 1) = 'bb';
5880+
c
5881+
explain select * from t where substr(c, 1, 3) = 'bb';
5882+
id select_type table type possible_keys key key_len ref rows Extra
5883+
1 SIMPLE t range c c 8 NULL 2 Using where; Using index
5884+
select * from t where substr(c, 1, 3) = 'bb';
5885+
c
5886+
explain select * from t where substr(c, 1) = 'bb';
5887+
id select_type table type possible_keys key key_len ref rows Extra
5888+
1 SIMPLE t range c c 8 NULL 2 Using where; Using index
5889+
select * from t where substr(c, 1) = 'bb';
5890+
c
5891+
explain select * from t where substr(c, 1, 2) = substr(c, 2, 3);
5892+
id select_type table type possible_keys key key_len ref rows Extra
5893+
1 SIMPLE t index NULL c 8 NULL 5 Using where; Using index
5894+
select * from t where substr(c, 1, 2) = substr(c, 2, 3);
5895+
c
5896+
aaa
5897+
ddd
5898+
drop index c on t;
5899+
explain select * from t where substr(c, 1, 2) = 'bb';
5900+
id select_type table type possible_keys key key_len ref rows Extra
5901+
1 SIMPLE t ALL NULL NULL NULL NULL 5 Using where
5902+
select * from t where substr(c, 1, 2) = 'bb';
5903+
c
5904+
bbcd
5905+
bba
5906+
drop table t;
5907+
set @old_collation_connection=@@collation_connection;
5908+
SET collation_connection=utf32_czech_ci;
5909+
CREATE TABLE t1 AS SELECT REPEAT(' ', 10) AS s1 LIMIT 0;
5910+
INSERT INTO t1 VALUES ('%c'),('%ce'),('%cé'),('%ch'), ('c'), ('d'), ('c%'), ('c\\g');
5911+
SELECT * FROM t1 WHERE s1 LIKE '\\%c%';
5912+
s1
5913+
%c
5914+
%ce
5915+
%cé
5916+
%ch
5917+
SELECT * FROM t1 WHERE substr(s1, 1, 2) = '%c';
5918+
s1
5919+
%c
5920+
%ce
5921+
%cé
5922+
%ch
5923+
SELECT * FROM t1 WHERE s1 LIKE 'c\\\\%';
5924+
s1
5925+
c\g
5926+
SELECT * FROM t1 WHERE substr(s1, 1, 2) = 'c\\';
5927+
s1
5928+
c\g
5929+
ALTER TABLE t1 ADD KEY s1 (s1);
5930+
SELECT * FROM t1 WHERE s1 LIKE '\\%c%';
5931+
s1
5932+
%c
5933+
%ce
5934+
%cé
5935+
%ch
5936+
SELECT * FROM t1 WHERE substr(s1, 1, 2) = '%c';
5937+
s1
5938+
%c
5939+
%ce
5940+
%cé
5941+
%ch
5942+
SELECT * FROM t1 WHERE s1 LIKE 'c\\\\%';
5943+
s1
5944+
c\g
5945+
SELECT * FROM t1 WHERE substr(s1, 1, 2) = 'c\\';
5946+
s1
5947+
c\g
5948+
DROP TABLE t1;
5949+
set collation_connection=@old_collation_connection;
5950+
create table t1 (a varchar(100), b varchar(100), key(a));
5951+
insert into t1 select seq, seq from seq_1_to_1000;
5952+
explain select * from t1 where LEFT(a, 20) ='%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%';
5953+
id select_type table type possible_keys key key_len ref rows Extra
5954+
1 SIMPLE t1 ALL a NULL NULL NULL 1000 Using where
5955+
drop table t1;
5956+
#
5957+
# End of 11.8 tests
5958+
#
58095959
ALTER DATABASE test CHARACTER SET utf8mb4 COLLATE utf8mb4_uca1400_ai_ci;

mysql-test/main/func_str.test

Lines changed: 116 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2712,4 +2712,120 @@ SELECT
27122712
--echo # End of 11.5 tests
27132713
--echo #
27142714

2715+
--echo #
2716+
--echo # MDEV-34911 Make conditions SUBSTR(col, 1, n) = const_str sargable
2717+
--echo #
2718+
2719+
create table t (c varchar(5), key (c));
2720+
insert into t values ('ddd'), ('bbcd'), ('bba'), ('b%_cd'), ('aaa');
2721+
2722+
# positive cases
2723+
2724+
let $query=
2725+
select * from t where substr(c, 1, 2) = 'bb';
2726+
eval explain $query;
2727+
eval $query;
2728+
2729+
let $query=
2730+
select * from t where 'bb' = substr(c, 1, 2);
2731+
eval explain $query;
2732+
eval $query;
2733+
2734+
let $query=
2735+
select * from t where left(c, 2) = 'bb';
2736+
eval explain $query;
2737+
eval $query;
2738+
2739+
let $query=
2740+
select * from t where 'bb' = left(c, 2);
2741+
eval explain $query;
2742+
eval $query;
2743+
2744+
let $query=
2745+
select * from t where substr(c, 1, 4) = 'b%_c';
2746+
eval explain $query;
2747+
eval $query;
2748+
2749+
# RHS can_eval_in_optimize()
2750+
let $query=
2751+
select * from t where substr(c, 1, 2) = concat('b', 'b');
2752+
eval explain $query;
2753+
eval $query;
2754+
2755+
# RHS can_eval_in_optimize()
2756+
let $query=
2757+
select * from t where substr(c, 1, 2) = substr('bb1', 1, 2);
2758+
eval explain $query;
2759+
eval $query;
2760+
2761+
# works with view
2762+
create table t1 (a varchar(32), b int, index(a));
2763+
insert into t1 select seq, seq / 33 from seq_1_to_100;
2764+
explain select * from t1 where substr(a, 1, 2)='80';
2765+
# The range is a necessary condition, and further filtering happens in
2766+
# the exec stage
2767+
explain select * from t1 where substr(a, 1, b)='80';
2768+
create view v1 as select a,b from t1;
2769+
explain select * from v1 where substr(a, 1, 2)='80';
2770+
drop view v1;
2771+
drop table t1;
2772+
2773+
# negative cases
2774+
2775+
let $query=
2776+
select * from t where substr(c, 1, 1) = 'bb';
2777+
eval explain $query;
2778+
eval $query;
2779+
2780+
let $query=
2781+
select * from t where substr(c, 1, 3) = 'bb';
2782+
eval explain $query;
2783+
eval $query;
2784+
2785+
let $query=
2786+
select * from t where substr(c, 1) = 'bb';
2787+
eval explain $query;
2788+
eval $query;
2789+
2790+
let $query=
2791+
select * from t where substr(c, 1, 2) = substr(c, 2, 3);
2792+
eval explain $query;
2793+
eval $query;
2794+
2795+
# full table scan when no index on sargable substr
2796+
drop index c on t;
2797+
2798+
let $query=
2799+
select * from t where substr(c, 1, 2) = 'bb';
2800+
eval explain $query;
2801+
eval $query;
2802+
2803+
drop table t;
2804+
2805+
# czech has the same behaviour as in LIKE
2806+
set @old_collation_connection=@@collation_connection;
2807+
SET collation_connection=utf32_czech_ci;
2808+
CREATE TABLE t1 AS SELECT REPEAT(' ', 10) AS s1 LIMIT 0;
2809+
INSERT INTO t1 VALUES ('%c'),('%ce'),('%cé'),('%ch'), ('c'), ('d'), ('c%'), ('c\\g');
2810+
SELECT * FROM t1 WHERE s1 LIKE '\\%c%';
2811+
SELECT * FROM t1 WHERE substr(s1, 1, 2) = '%c';
2812+
SELECT * FROM t1 WHERE s1 LIKE 'c\\\\%';
2813+
SELECT * FROM t1 WHERE substr(s1, 1, 2) = 'c\\';
2814+
ALTER TABLE t1 ADD KEY s1 (s1);
2815+
SELECT * FROM t1 WHERE s1 LIKE '\\%c%';
2816+
SELECT * FROM t1 WHERE substr(s1, 1, 2) = '%c';
2817+
SELECT * FROM t1 WHERE s1 LIKE 'c\\\\%';
2818+
SELECT * FROM t1 WHERE substr(s1, 1, 2) = 'c\\';
2819+
DROP TABLE t1;
2820+
set collation_connection=@old_collation_connection;
2821+
2822+
# no stack overrun escaping long string
2823+
create table t1 (a varchar(100), b varchar(100), key(a));
2824+
insert into t1 select seq, seq from seq_1_to_1000;
2825+
explain select * from t1 where LEFT(a, 20) ='%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%%';
2826+
drop table t1;
2827+
2828+
--echo #
2829+
--echo # End of 11.8 tests
2830+
--echo #
27152831
--source include/test_db_charset_restore.inc

sql/CMakeLists.txt

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -116,6 +116,7 @@ SET (SQL_SOURCE
116116
opt_range.cc vector_mhnsw.cc
117117
opt_rewrite_date_cmp.cc
118118
opt_rewrite_remove_casefold.cc
119+
opt_sargable_left.cc
119120
opt_sum.cc
120121
../sql-common/pack.c parse_file.cc password.c procedure.cc
121122
protocol.cc records.cc repl_failsafe.cc rpl_filter.cc

sql/item_cmpfunc.h

Lines changed: 9 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -248,6 +248,7 @@ class Item_bool_func :public Item_int_func,
248248
bool fix_length_and_dec(THD *thd) override { decimals=0; max_length=1; return FALSE; }
249249
decimal_digits_t decimal_precision() const override { return 1; }
250250
bool need_parentheses_in_default() override { return true; }
251+
bool with_sargable_substr(Item_field **field = NULL, int *value_idx = NULL) const;
251252
};
252253

253254

@@ -540,8 +541,14 @@ class Item_bool_func2_with_rev :public Item_bool_func2
540541
may succeed.
541542
*/
542543
if (!(ftree= get_full_func_mm_tree_for_args(param, args[0], args[1])) &&
543-
!(ftree= get_full_func_mm_tree_for_args(param, args[1], args[0])))
544-
ftree= Item_func::get_mm_tree(param, cond_ptr);
544+
!(ftree= get_full_func_mm_tree_for_args(param, args[1], args[0])) &&
545+
!(ftree= Item_func::get_mm_tree(param, cond_ptr)))
546+
{
547+
Item_field *field= NULL;
548+
int value_idx= -1;
549+
if (with_sargable_substr(&field, &value_idx))
550+
DBUG_RETURN(get_full_func_mm_tree_for_args(param, field, args[value_idx]));
551+
}
545552
DBUG_RETURN(ftree);
546553
}
547554
};

sql/item_func.h

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -106,7 +106,7 @@ class Item_func :public Item_func_or_sum
106106
JSON_EXTRACT_FUNC, JSON_VALID_FUNC, ROWNUM_FUNC,
107107
CASE_SEARCHED_FUNC, // Used by ColumnStore/Spider
108108
CASE_SIMPLE_FUNC, // Used by ColumnStore/spider,
109-
DATE_FUNC, YEAR_FUNC
109+
DATE_FUNC, YEAR_FUNC, SUBSTR_FUNC, LEFT_FUNC
110110
};
111111

112112
/*

sql/item_strfunc.h

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -693,6 +693,7 @@ class Item_func_left :public Item_str_func
693693
bool hash_not_null(Hasher *hasher) override;
694694
String *val_str(String *) override;
695695
bool fix_length_and_dec(THD *thd) override;
696+
enum Functype functype() const override { return LEFT_FUNC; }
696697
LEX_CSTRING func_name_cstring() const override
697698
{
698699
static LEX_CSTRING name= {STRING_WITH_LEN("left") };
@@ -739,6 +740,7 @@ class Item_func_substr :public Item_str_func
739740
print_sql_mode_qualified_name(str, query_type);
740741
print_args_parenthesized(str, query_type);
741742
}
743+
enum Functype functype() const override { return SUBSTR_FUNC; }
742744
LEX_CSTRING func_name_cstring() const override
743745
{
744746
static LEX_CSTRING name= {STRING_WITH_LEN("substr") };

0 commit comments

Comments
 (0)