diff --git a/mysql-test/main/type_binary.result b/mysql-test/main/type_binary.result index d1aa4ada5af..32593cb728b 100644 --- a/mysql-test/main/type_binary.result +++ b/mysql-test/main/type_binary.result @@ -397,3 +397,61 @@ indexed_col not_indexed_col DROP TABLE t2; DROP TABLE t1; SET note_verbosity=DEFAULT; +# +# MDEV-36235 Incorrect result for BETWEEN over unique blob prefix +# +CREATE TABLE t1 (c1 BINARY(16), UNIQUE (c1)); +INSERT INTO t1 (c1) VALUES (-2),(-1),(1),(2); +SELECT HEX(c1) FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +HEX(c1) +31000000000000000000000000000000 +32000000000000000000000000000000 +Warnings: +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: '-1\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: '-2\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: '1\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: '2\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00' +SELECT HEX(c1) FROM t1 IGNORE KEY(c1) WHERE 'a' BETWEEN 0 AND (c1); +HEX(c1) +31000000000000000000000000000000 +32000000000000000000000000000000 +Warnings: +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: '-2\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: '-1\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: '1\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: '2\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00' +SELECT HEX(c1) FROM t1 WHERE '#' BETWEEN c1 AND 0; +HEX(c1) +2D310000000000000000000000000000 +2D320000000000000000000000000000 +Warnings: +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '-1\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '-2\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '1\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '2\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00' +SELECT HEX(c1) FROM t1 IGNORE KEY(c1) WHERE '#' BETWEEN c1 AND 0; +HEX(c1) +2D320000000000000000000000000000 +2D310000000000000000000000000000 +Warnings: +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '-2\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '-1\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '1\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '2\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00' +DROP TABLE t1; diff --git a/mysql-test/main/type_binary.test b/mysql-test/main/type_binary.test index 495c776cc75..916d6402b63 100644 --- a/mysql-test/main/type_binary.test +++ b/mysql-test/main/type_binary.test @@ -178,3 +178,14 @@ DELIMITER ;$$ --source unusable_keys_joins.inc DROP TABLE t1; SET note_verbosity=DEFAULT; + +--echo # +--echo # MDEV-36235 Incorrect result for BETWEEN over unique blob prefix +--echo # +CREATE TABLE t1 (c1 BINARY(16), UNIQUE (c1)); +INSERT INTO t1 (c1) VALUES (-2),(-1),(1),(2); +SELECT HEX(c1) FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +SELECT HEX(c1) FROM t1 IGNORE KEY(c1) WHERE 'a' BETWEEN 0 AND (c1); +SELECT HEX(c1) FROM t1 WHERE '#' BETWEEN c1 AND 0; +SELECT HEX(c1) FROM t1 IGNORE KEY(c1) WHERE '#' BETWEEN c1 AND 0; +DROP TABLE t1; diff --git a/mysql-test/main/type_blob.result b/mysql-test/main/type_blob.result index b9d1f2cae31..14685bcf149 100644 --- a/mysql-test/main/type_blob.result +++ b/mysql-test/main/type_blob.result @@ -1419,3 +1419,193 @@ Note 1105 Cannot use key parts with `test`.`t1`.`indexed_col` in the rewritten c DROP TABLE t2; DROP TABLE t1; SET note_verbosity=DEFAULT; +# +# MDEV-36235 Incorrect result for BETWEEN over unique blob prefix +# +CREATE TABLE t1 (c1 TINYBLOB, UNIQUE (c1(2))) engine=myisam; +INSERT INTO t1 (c1) VALUES (1); +SELECT c1 FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +c1 +1 +Warnings: +Warning 1292 Truncated incorrect DOUBLE value: 'a' +DROP TABLE t1; +CREATE TABLE t1 (c1 TINYBLOB, UNIQUE (c1(2))); +INSERT INTO t1 (c1) VALUES (1),(2),(3),(4),(5); +SELECT c1 FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +c1 +1 +2 +3 +4 +5 +Warnings: +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +SELECT c1 FROM t1 WHERE 3 BETWEEN 10*POW(-1,c1) AND (c1); +c1 +3 +5 +SELECT c1 FROM t1 WHERE 'a' BETWEEN 10*POW(-1,c1) AND (c1); +c1 +1 +3 +5 +Warnings: +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +DROP TABLE t1; +CREATE TABLE t1 (c1 TINYBLOB, UNIQUE (c1(2))) engine=myisam; +INSERT INTO t1 (c1) VALUES (-2),(-1),(1),(2),(3),(4),(5); +SELECT c1 FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +c1 +1 +2 +3 +4 +5 +Warnings: +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +SELECT c1 FROM t1 WHERE '#' BETWEEN c1 AND 0; +c1 +-2 +-1 +Warnings: +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +DROP TABLE t1; +CREATE TABLE t1 (c1 TINYBLOB NOT NULL); +INSERT INTO t1 (c1) VALUES (-2),(-1),(1),(2),(3),(4),(5); +SELECT c1 FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +c1 +1 +2 +3 +4 +5 +Warnings: +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +SELECT c1 FROM t1 WHERE '#' BETWEEN c1 AND 0; +c1 +-2 +-1 +Warnings: +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +DROP TABLE t1; +CREATE TABLE t1 (c1 TINYBLOB, UNIQUE (c1(2))) engine=innodb; +INSERT INTO t1 (c1) VALUES (-2),(-1),(1),(2),(3),(4),(5); +SELECT c1 FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +c1 +1 +2 +3 +4 +5 +Warnings: +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +SELECT c1 FROM t1 WHERE '#' BETWEEN c1 AND 0; +c1 +-2 +-1 +Warnings: +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +ALTER TABLE t1 engine=myisam; +SELECT c1 FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +c1 +1 +2 +3 +4 +5 +Warnings: +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +SELECT c1 FROM t1 WHERE '#' BETWEEN c1 AND 0; +c1 +-2 +-1 +Warnings: +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +DROP TABLE t1; +CREATE TABLE t1 (c1 TINYBLOB, UNIQUE (c1)) engine=innodb; +INSERT INTO t1 (c1) VALUES (-2),(-1),(1),(2),(3),(4),(5); +SELECT c1 FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +c1 +1 +2 +3 +4 +5 +Warnings: +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +SELECT c1 FROM t1 WHERE '#' BETWEEN c1 AND 0; +c1 +-2 +-1 +Warnings: +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +DROP TABLE t1; diff --git a/mysql-test/main/type_blob.test b/mysql-test/main/type_blob.test index ad58946afea..bb90e7434d6 100644 --- a/mysql-test/main/type_blob.test +++ b/mysql-test/main/type_blob.test @@ -808,3 +808,48 @@ DELIMITER ;$$ --source unusable_keys_joins.inc DROP TABLE t1; SET note_verbosity=DEFAULT; + +--echo # +--echo # MDEV-36235 Incorrect result for BETWEEN over unique blob prefix +--echo # +# myisam has a special optimization for tables with one row +CREATE TABLE t1 (c1 TINYBLOB, UNIQUE (c1(2))) engine=myisam; +INSERT INTO t1 (c1) VALUES (1); +SELECT c1 FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +DROP TABLE t1; + +# This case shows that we don't transform the entire WHERE clause +# into a range condition. +CREATE TABLE t1 (c1 TINYBLOB, UNIQUE (c1(2))); +INSERT INTO t1 (c1) VALUES (1),(2),(3),(4),(5); +SELECT c1 FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +SELECT c1 FROM t1 WHERE 3 BETWEEN 10*POW(-1,c1) AND (c1); +SELECT c1 FROM t1 WHERE 'a' BETWEEN 10*POW(-1,c1) AND (c1); +DROP TABLE t1; + +CREATE TABLE t1 (c1 TINYBLOB, UNIQUE (c1(2))) engine=myisam; +INSERT INTO t1 (c1) VALUES (-2),(-1),(1),(2),(3),(4),(5); +SELECT c1 FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +SELECT c1 FROM t1 WHERE '#' BETWEEN c1 AND 0; +DROP TABLE t1; + +CREATE TABLE t1 (c1 TINYBLOB NOT NULL); +INSERT INTO t1 (c1) VALUES (-2),(-1),(1),(2),(3),(4),(5); +SELECT c1 FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +SELECT c1 FROM t1 WHERE '#' BETWEEN c1 AND 0; +DROP TABLE t1; + +CREATE TABLE t1 (c1 TINYBLOB, UNIQUE (c1(2))) engine=innodb; +INSERT INTO t1 (c1) VALUES (-2),(-1),(1),(2),(3),(4),(5); +SELECT c1 FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +SELECT c1 FROM t1 WHERE '#' BETWEEN c1 AND 0; +ALTER TABLE t1 engine=myisam; +SELECT c1 FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +SELECT c1 FROM t1 WHERE '#' BETWEEN c1 AND 0; +DROP TABLE t1; + +CREATE TABLE t1 (c1 TINYBLOB, UNIQUE (c1)) engine=innodb; +INSERT INTO t1 (c1) VALUES (-2),(-1),(1),(2),(3),(4),(5); +SELECT c1 FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +SELECT c1 FROM t1 WHERE '#' BETWEEN c1 AND 0; +DROP TABLE t1; diff --git a/mysql-test/main/type_varbinary.result b/mysql-test/main/type_varbinary.result new file mode 100644 index 00000000000..41f7403a24f --- /dev/null +++ b/mysql-test/main/type_varbinary.result @@ -0,0 +1,42 @@ +# +# MDEV-36235 Incorrect result for BETWEEN over unique blob prefix +# +CREATE TABLE t1 (c1 VARBINARY(10), UNIQUE (c1)); +INSERT INTO t1 (c1) VALUES (-2),(-1),(1),(2); +SELECT c1 FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +c1 +1 +2 +Warnings: +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +SELECT c1 FROM t1 IGNORE KEY(c1) WHERE 'a' BETWEEN 0 AND (c1); +c1 +1 +2 +Warnings: +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +Warning 1292 Truncated incorrect DOUBLE value: 'a' +SELECT c1 FROM t1 WHERE '#' BETWEEN c1 AND 0; +c1 +-1 +-2 +Warnings: +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +SELECT c1 FROM t1 IGNORE KEY(c1) WHERE '#' BETWEEN c1 AND 0; +c1 +-2 +-1 +Warnings: +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +Warning 1292 Truncated incorrect DECIMAL value: '#' +DROP TABLE t1; diff --git a/mysql-test/main/type_varbinary.test b/mysql-test/main/type_varbinary.test new file mode 100644 index 00000000000..2bb35dfd195 --- /dev/null +++ b/mysql-test/main/type_varbinary.test @@ -0,0 +1,10 @@ +--echo # +--echo # MDEV-36235 Incorrect result for BETWEEN over unique blob prefix +--echo # +CREATE TABLE t1 (c1 VARBINARY(10), UNIQUE (c1)); +INSERT INTO t1 (c1) VALUES (-2),(-1),(1),(2); +SELECT c1 FROM t1 WHERE 'a' BETWEEN 0 AND (c1); +SELECT c1 FROM t1 IGNORE KEY(c1) WHERE 'a' BETWEEN 0 AND (c1); +SELECT c1 FROM t1 WHERE '#' BETWEEN c1 AND 0; +SELECT c1 FROM t1 IGNORE KEY(c1) WHERE '#' BETWEEN c1 AND 0; +DROP TABLE t1; diff --git a/plugin/type_inet/mysql-test/type_inet/type_inet6.result b/plugin/type_inet/mysql-test/type_inet/type_inet6.result index d43352dfff2..c8ebcf5be98 100644 --- a/plugin/type_inet/mysql-test/type_inet/type_inet6.result +++ b/plugin/type_inet/mysql-test/type_inet/type_inet6.result @@ -2407,3 +2407,26 @@ f::f DROP TABLE t1; SET max_sort_length=DEFAULT; # End of 10.8 tests +# +# MDEV-36235 Incorrect result for BETWEEN over unique blob prefix +# +CREATE OR REPLACE TABLE t1 (c1 BINARY(16), UNIQUE (c1)); +INSERT INTO t1 (c1) VALUES (0x00000000000000000000000000000001); +INSERT INTO t1 (c1) VALUES (0x00000000000000000000000000000002); +SELECT CAST(c1 AS INET6) FROM t1 WHERE '::1' BETWEEN CAST('::1' AS INET6) AND c1; +CAST(c1 AS INET6) +::1 +::2 +SELECT CAST(c1 AS INET6) FROM t1 IGNORE KEY(c1) WHERE '::1' BETWEEN CAST('::1' AS INET6) AND c1; +CAST(c1 AS INET6) +::1 +::2 +SELECT CAST(c1 AS INET6) FROM t1 WHERE '::2' BETWEEN c1 AND CAST('::2' AS INET6); +CAST(c1 AS INET6) +::1 +::2 +SELECT CAST(c1 AS INET6) FROM t1 IGNORE KEY(c1) WHERE '::2' BETWEEN c1 AND CAST('::2' AS INET6); +CAST(c1 AS INET6) +::1 +::2 +DROP TABLE t1; diff --git a/plugin/type_inet/mysql-test/type_inet/type_inet6.test b/plugin/type_inet/mysql-test/type_inet/type_inet6.test index c3128140b71..1fd5feea004 100644 --- a/plugin/type_inet/mysql-test/type_inet/type_inet6.test +++ b/plugin/type_inet/mysql-test/type_inet/type_inet6.test @@ -1741,3 +1741,15 @@ DROP TABLE t1; SET max_sort_length=DEFAULT; --echo # End of 10.8 tests + +--echo # +--echo # MDEV-36235 Incorrect result for BETWEEN over unique blob prefix +--echo # +CREATE OR REPLACE TABLE t1 (c1 BINARY(16), UNIQUE (c1)); +INSERT INTO t1 (c1) VALUES (0x00000000000000000000000000000001); +INSERT INTO t1 (c1) VALUES (0x00000000000000000000000000000002); +SELECT CAST(c1 AS INET6) FROM t1 WHERE '::1' BETWEEN CAST('::1' AS INET6) AND c1; +SELECT CAST(c1 AS INET6) FROM t1 IGNORE KEY(c1) WHERE '::1' BETWEEN CAST('::1' AS INET6) AND c1; +SELECT CAST(c1 AS INET6) FROM t1 WHERE '::2' BETWEEN c1 AND CAST('::2' AS INET6); +SELECT CAST(c1 AS INET6) FROM t1 IGNORE KEY(c1) WHERE '::2' BETWEEN c1 AND CAST('::2' AS INET6); +DROP TABLE t1; diff --git a/sql/item_cmpfunc.h b/sql/item_cmpfunc.h index f9d9b18a70d..a896e461bf5 100644 --- a/sql/item_cmpfunc.h +++ b/sql/item_cmpfunc.h @@ -1003,6 +1003,23 @@ public: class Item_func_between :public Item_func_opt_neg { + /* + If the types of the arguments to BETWEEN permit, then: + + WHERE const1 BETWEEN expr2 AND field1 + can be optimized as if it was just: + WHERE const1 <= field1 + + as expr2 could be an arbitrary expression. More generally, + this optimization is permitted if aggregation for comparison + for three expressions (const1,const2,field1) and for two + expressions (const1,field1) return the same type handler. + + @param [IN] field_item - This is a field from the right side + of the BETWEEN operator. + */ + bool can_optimize_range_const(Item_field *field_item) const; + protected: SEL_TREE *get_func_mm_tree(RANGE_OPT_PARAM *param, Field *field, Item *value) override; diff --git a/sql/opt_range.cc b/sql/opt_range.cc index 3f9c5663b26..7f3fece735f 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -8351,56 +8351,58 @@ SEL_TREE *Item_func_in::get_func_row_mm_tree(RANGE_OPT_PARAM *param, /* Build conjunction of all SEL_TREEs for a simple predicate applying equalities - + SYNOPSIS get_full_func_mm_tree() param PARAM from SQL_SELECT::test_quick_select field_item field in the predicate - value constant in the predicate (or a field already read from + value constant in the predicate (or a field already read from a table in the case of dynamic range access) (for BETWEEN it contains the number of the field argument, - for IN it's always 0) + for IN it's always 0) inv TRUE <> NOT cond_func is considered (makes sense only when cond_func is BETWEEN or IN) DESCRIPTION - For a simple SARGable predicate of the form (f op c), where f is a field and - c is a constant, the function builds a conjunction of all SEL_TREES that can - be obtained by the substitution of f for all different fields equal to f. + For a simple SARGable predicate of the form (f op c), where f is a field + and c is a constant, the function builds a conjunction of all SEL_TREES that + can be obtained by the substitution of f for all different fields equal to f. - NOTES + NOTES If the WHERE condition contains a predicate (fi op c), then not only SELL_TREE for this predicate is built, but the trees for the results of substitution of fi for each fj belonging to the same multiple equality as fi are built as well. - E.g. for WHERE t1.a=t2.a AND t2.a > 10 + E.g. for WHERE t1.a=t2.a AND t2.a > 10 a SEL_TREE for t2.a > 10 will be built for quick select from t2 - and + and a SEL_TREE for t1.a > 10 will be built for quick select from t1. - A BETWEEN predicate of the form (fi [NOT] BETWEEN c1 AND c2) is treated - in a similar way: we build a conjuction of trees for the results - of all substitutions of fi for equal fj. + A BETWEEN predicate of the form (fi [NOT] BETWEEN c1 AND c2), where fi + is some field, is treated in a similar way: we build a conjuction of + trees for the results of all substitutions of fi equal fj. + Yet a predicate of the form (c BETWEEN f1i AND f2i) is processed differently. It is considered as a conjuction of two SARGable - predicates (f1i <= c) and (f2i <=c) and the function get_full_func_mm_tree - is called for each of them separately producing trees for - AND j (f1j <=c ) and AND j (f2j <= c) + predicates (f1i <= c) and (c <= f2i) and the function get_full_func_mm_tree + is called for each of them separately producing trees for + AND j (f1j <= c) and AND j (c <= f2j) After this these two trees are united in one conjunctive tree. It's easy to see that the same tree is obtained for - AND j,k (f1j <=c AND f2k<=c) - which is equivalent to + AND j,k (f1j <= c AND c <= f2k) + which is equivalent to AND j,k (c BETWEEN f1j AND f2k). + The validity of the processing of the predicate (c NOT BETWEEN f1i AND f2i) which equivalent to (f1i > c OR f2i < c) is not so obvious. Here the - function get_full_func_mm_tree is called for (f1i > c) and (f2i < c) - producing trees for AND j (f1j > c) and AND j (f2j < c). Then this two - trees are united in one OR-tree. The expression + function get_full_func_mm_tree is called for (f1i > c) and called for + (f2i < c) producing trees for AND j (f1j > c) and AND j (f2j < c). Then + this two trees are united in one OR-tree. The expression (AND j (f1j > c) OR AND j (f2j < c) is equivalent to the expression - AND j,k (f1j > c OR f2k < c) - which is just a translation of + AND j,k (f1j > c OR f2k < c) + which is just a translation of AND j,k (c NOT BETWEEN f1j AND f2k) In the cases when one of the items f1, f2 is a constant c1 we do not create @@ -8413,9 +8415,9 @@ SEL_TREE *Item_func_in::get_func_row_mm_tree(RANGE_OPT_PARAM *param, As to IN predicates only ones of the form (f IN (c1,...,cn)), where f1 is a field and c1,...,cn are constant, are considered as SARGable. We never try to narrow the index scan using predicates of - the form (c IN (c1,...,f,...,cn)). - - RETURN + the form (c IN (c1,...,f,...,cn)). + + RETURN Pointer to the tree representing the built conjunction of SEL_TREEs */ @@ -8623,6 +8625,19 @@ SEL_TREE *Item::get_mm_tree(RANGE_OPT_PARAM *param, Item **cond_ptr) } +bool +Item_func_between::can_optimize_range_const(Item_field *field_item) const +{ + const Type_handler *fi_handler= field_item->type_handler_for_comparison(); + Type_handler_hybrid_field_type cmp(fi_handler); + if (cmp.aggregate_for_comparison(args[0]->type_handler_for_comparison()) || + cmp.type_handler() != m_comparator.type_handler()) + return false; // Cannot optimize range because of type mismatch. + + return true; +} + + SEL_TREE * Item_func_between::get_mm_tree(RANGE_OPT_PARAM *param, Item **cond_ptr) { @@ -8648,6 +8663,8 @@ Item_func_between::get_mm_tree(RANGE_OPT_PARAM *param, Item **cond_ptr) if (arguments()[i]->real_item()->type() == Item::FIELD_ITEM) { Item_field *field_item= (Item_field*) (arguments()[i]->real_item()); + if (!can_optimize_range_const(field_item)) + continue; SEL_TREE *tmp= get_full_func_mm_tree(param, field_item, (Item*)(intptr) i); if (negated)