diff --git a/client/mysql.cc b/client/mysql.cc index 096410fd486..964f55f1e30 100644 --- a/client/mysql.cc +++ b/client/mysql.cc @@ -2730,8 +2730,10 @@ static bool add_line(String &buffer, char *line, size_t line_length, break; } - else if (!*in_string && inchar == '/' && *(pos+1) == '*' && - !(*(pos+2) == '!' || (*(pos+2) == 'M' && *(pos+3) == '!'))) + else if (!*in_string && inchar == '/' && pos[1] == '*' && + !(pos[2] == '!' || + (pos[2] == 'M' && pos[3] == '!') || + pos[2] == '+')) { if (preserve_comments) { @@ -2768,8 +2770,8 @@ static bool add_line(String &buffer, char *line, size_t line_length, } else { // Add found char to buffer - if (!*in_string && inchar == '/' && *(pos + 1) == '*' && - *(pos + 2) == '!') + if (!*in_string && inchar == '/' && pos[1] == '*' && + (pos[2] == '!' || pos[2] == '+')) ss_comment= 1; else if (!*in_string && ss_comment && inchar == '*' && *(pos + 1) == '/') ss_comment= 0; diff --git a/libmysqld/CMakeLists.txt b/libmysqld/CMakeLists.txt index a32e1673ce3..45eb477694a 100644 --- a/libmysqld/CMakeLists.txt +++ b/libmysqld/CMakeLists.txt @@ -158,6 +158,8 @@ SET(SQL_EMBEDDED_SOURCES emb_qcache.cc libmysqld.c lib_sql.cc ../sql/opt_histogram_json.cc ../sql/sp_instr.cc ../sql/sp_cursor.cc + ../sql/opt_hints_parser.cc ../sql/opt_hints_parser.h + ../sql/scan_char.h ${GEN_SOURCES} ${MYSYS_LIBWRAP_SOURCE} ) diff --git a/mysql-test/main/opt_hints.result b/mysql-test/main/opt_hints.result new file mode 100644 index 00000000000..a8b3d20fd9a --- /dev/null +++ b/mysql-test/main/opt_hints.result @@ -0,0 +1,1366 @@ +# WL#8017 Infrastructure for Optimizer Hints +CREATE TABLE t1(f1 INT, f2 INT); +INSERT INTO t1 VALUES +(1,1),(2,2),(3,3); +CREATE TABLE t2(f1 INT NOT NULL, f2 INT NOT NULL, f3 CHAR(200), KEY(f1, f2)); +INSERT INTO t2 VALUES +(1,1, 'qwerty'),(1,2, 'qwerty'),(1,3, 'qwerty'), +(2,1, 'qwerty'),(2,2, 'qwerty'),(2,3, 'qwerty'), (2,4, 'qwerty'),(2,5, 'qwerty'), +(3,1, 'qwerty'),(3,4, 'qwerty'), +(4,1, 'qwerty'),(4,2, 'qwerty'),(4,3, 'qwerty'), (4,4, 'qwerty'), +(1,1, 'qwerty'),(1,2, 'qwerty'),(1,3, 'qwerty'), +(2,1, 'qwerty'),(2,2, 'qwerty'),(2,3, 'qwerty'), (2,4, 'qwerty'),(2,5, 'qwerty'), +(3,1, 'qwerty'),(3,4, 'qwerty'), +(4,1, 'qwerty'),(4,2, 'qwerty'),(4,3, 'qwerty'), (4,4, 'qwerty'); +CREATE TABLE t3 (f1 INT NOT NULL, f2 INT, f3 VARCHAR(32), +PRIMARY KEY(f1), KEY f2_idx(f1), KEY f3_idx(f3)); +INSERT INTO t3 VALUES +(1, 1, 'qwerty'), (2, 1, 'ytrewq'), +(3, 2, 'uiop'), (4, 2, 'poiu'), (5, 2, 'lkjh'), +(6, 2, 'uiop'), (7, 2, 'poiu'), (8, 2, 'lkjh'), +(9, 2, 'uiop'), (10, 2, 'poiu'), (11, 2, 'lkjh'), +(12, 2, 'uiop'), (13, 2, 'poiu'), (14, 2, 'lkjh'); +INSERT INTO t3 SELECT f1 + 20, f2, f3 FROM t3; +INSERT INTO t3 SELECT f1 + 40, f2, f3 FROM t3; +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status Engine-independent statistics collected +test.t1 analyze status OK +ANALYZE TABLE t2; +Table Op Msg_type Msg_text +test.t2 analyze status Engine-independent statistics collected +test.t2 analyze status OK +ANALYZE TABLE t3; +Table Op Msg_type Msg_text +test.t3 analyze status Engine-independent statistics collected +test.t3 analyze status OK +# NO_RANGE_OPTIMIZATION hint testing +set optimizer_switch=default; +# Check statistics with no hint +FLUSH STATUS; +SELECT f1 FROM t3 WHERE f1 > 30 AND f1 < 33; +f1 +31 +32 +SHOW STATUS LIKE 'handler_read%'; +Variable_name Value +Handler_read_first 0 +Handler_read_key 1 +Handler_read_last 0 +Handler_read_next 2 +Handler_read_prev 0 +Handler_read_retry 0 +Handler_read_rnd 0 +Handler_read_rnd_deleted 0 +Handler_read_rnd_next 0 +# Check statistics with hint +FLUSH STATUS; +SELECT /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY, f2_idx) */ f1 FROM t3 WHERE f1 > 30 AND f1 < 33; +f1 +31 +32 +SHOW STATUS LIKE 'handler_read%'; +Variable_name Value +Handler_read_first 1 +Handler_read_key 0 +Handler_read_last 0 +Handler_read_next 56 +Handler_read_prev 0 +Handler_read_retry 0 +Handler_read_rnd 0 +Handler_read_rnd_deleted 0 +Handler_read_rnd_next 0 +EXPLAIN EXTENDED SELECT f1 FROM t3 WHERE f1 > 30 AND f1 < 33; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t3 range PRIMARY,f2_idx PRIMARY 4 NULL 2 100.00 Using where; Using index +Warnings: +Note 1003 select `test`.`t3`.`f1` AS `f1` from `test`.`t3` where `test`.`t3`.`f1` > 30 and `test`.`t3`.`f1` < 33 +# Turn off range access for PRIMARY key +# Should use range access by f2_idx key +EXPLAIN EXTENDED SELECT /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY) */ f1 FROM t3 WHERE f1 > 30 AND f1 < 33; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t3 range PRIMARY,f2_idx f2_idx 4 NULL 2 100.00 Using where; Using index +Warnings: +Note 1003 select /*+ NO_RANGE_OPTIMIZATION(`t3`@`select#1` `PRIMARY`) */ `test`.`t3`.`f1` AS `f1` from `test`.`t3` where `test`.`t3`.`f1` > 30 and `test`.`t3`.`f1` < 33 +# Turn off range access for PRIMARY & f2_idx keys +# Should use index access +EXPLAIN EXTENDED SELECT /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY, f2_idx) */ f1 FROM t3 WHERE f1 > 30 AND f1 < 33; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t3 index PRIMARY,f2_idx PRIMARY 4 NULL 56 4.11 Using where; Using index +Warnings: +Note 1003 select /*+ NO_RANGE_OPTIMIZATION(`t3`@`select#1` `PRIMARY`) NO_RANGE_OPTIMIZATION(`t3`@`select#1` `f2_idx`) */ `test`.`t3`.`f1` AS `f1` from `test`.`t3` where `test`.`t3`.`f1` > 30 and `test`.`t3`.`f1` < 33 +# Turn off range access for all keys +# Should use index access +EXPLAIN EXTENDED SELECT /*+ NO_RANGE_OPTIMIZATION(t3) */ f1 FROM t3 WHERE f1 > 30 AND f1 < 33; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t3 index PRIMARY,f2_idx PRIMARY 4 NULL 56 4.11 Using where; Using index +Warnings: +Note 1003 select /*+ NO_RANGE_OPTIMIZATION(`t3`@`select#1`) */ `test`.`t3`.`f1` AS `f1` from `test`.`t3` where `test`.`t3`.`f1` > 30 and `test`.`t3`.`f1` < 33 +# Turn off range access for PRIMARY & f2_idx keys +# Should use index access +EXPLAIN EXTENDED SELECT /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY) NO_RANGE_OPTIMIZATION(t3 f2_idx) */ f1 FROM t3 WHERE f1 > 30 AND f1 < 33; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t3 index PRIMARY,f2_idx PRIMARY 4 NULL 56 4.11 Using where; Using index +Warnings: +Note 1003 select /*+ NO_RANGE_OPTIMIZATION(`t3`@`select#1` `PRIMARY`) NO_RANGE_OPTIMIZATION(`t3`@`select#1` `f2_idx`) */ `test`.`t3`.`f1` AS `f1` from `test`.`t3` where `test`.`t3`.`f1` > 30 and `test`.`t3`.`f1` < 33 +# NO_ICP hint testing +set optimizer_switch='index_condition_pushdown=on'; +CREATE TABLE t4 (x INT, y INT, KEY x_idx(x), KEY y_idx(y)); +INSERT INTO t4 (x) VALUES (1),(2),(3),(4),(5),(6),(7),(8),(9),(10),(11),(12),(13); +UPDATE t4 SET y=x; +EXPLAIN EXTENDED SELECT * FROM +(SELECT t4.x, t5.y FROM t4, t4 t5 WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0) AS TD; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t4 ref y_idx y_idx 5 const 1 100.00 +1 SIMPLE t5 range x_idx x_idx 5 NULL 2 100.00 Using index condition; Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select `test`.`t4`.`x` AS `x`,`test`.`t5`.`y` AS `y` from `test`.`t4` join `test`.`t4` `t5` where `test`.`t4`.`y` = 8 and `test`.`t5`.`x` between 7 and (8 + 0) +EXPLAIN EXTENDED SELECT * FROM +(SELECT /*+ NO_ICP(t5 x_idx, y_idx) */ t4.x, t5.y FROM t4, t4 t5 +WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0) AS TD; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t4 ref y_idx y_idx 5 const 1 100.00 +1 SIMPLE t5 range x_idx x_idx 5 NULL 2 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select /*+ NO_ICP(`t5`@`select#2` `x_idx`) NO_ICP(`t5`@`select#2` `y_idx`) */ `test`.`t4`.`x` AS `x`,`test`.`t5`.`y` AS `y` from `test`.`t4` join `test`.`t4` `t5` where `test`.`t4`.`y` = 8 and `test`.`t5`.`x` between 7 and (8 + 0) +EXPLAIN EXTENDED SELECT /*+ NO_ICP(t5@qb1 x_idx) */ * FROM +(SELECT /*+ QB_NAME(QB1) */ t4.x, t5.y FROM t4, t4 t5 +WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0) AS TD; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t4 ref y_idx y_idx 5 const 1 100.00 +1 SIMPLE t5 range x_idx x_idx 5 NULL 2 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select /*+ NO_ICP(`t5`@`QB1` `x_idx`) */ `test`.`t4`.`x` AS `x`,`test`.`t5`.`y` AS `y` from `test`.`t4` join `test`.`t4` `t5` where `test`.`t4`.`y` = 8 and `test`.`t5`.`x` between 7 and (8 + 0) +# Expected warning for z_idx key, unresolved name. +EXPLAIN EXTENDED SELECT * FROM +(SELECT /*+ NO_ICP(t5 y_idx, x_idx, z_idx) */ t4.x, t5.y FROM t4, t4 t5 +WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0) AS TD; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t4 ref y_idx y_idx 5 const 1 100.00 +1 SIMPLE t5 range x_idx x_idx 5 NULL 2 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Warning 4199 Unresolved name `t5`@`select#2` `z_idx` for NO_ICP hint +Note 1003 select /*+ NO_ICP(`t5`@`select#2` `y_idx`) NO_ICP(`t5`@`select#2` `x_idx`) */ `test`.`t4`.`x` AS `x`,`test`.`t5`.`y` AS `y` from `test`.`t4` join `test`.`t4` `t5` where `test`.`t4`.`y` = 8 and `test`.`t5`.`x` between 7 and (8 + 0) +# ICP should still be used +EXPLAIN EXTENDED SELECT * FROM +(SELECT /*+ NO_ICP(t5 y_idx) */ t4.x, t5.y FROM t4, t4 t5 +WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0) AS TD; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t4 ref y_idx y_idx 5 const 1 100.00 +1 SIMPLE t5 range x_idx x_idx 5 NULL 2 100.00 Using index condition; Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select /*+ NO_ICP(`t5`@`select#2` `y_idx`) */ `test`.`t4`.`x` AS `x`,`test`.`t5`.`y` AS `y` from `test`.`t4` join `test`.`t4` `t5` where `test`.`t4`.`y` = 8 and `test`.`t5`.`x` between 7 and (8 + 0) +# BKA & NO_BKA hint testing +set optimizer_switch=default; +set optimizer_switch='mrr=on,mrr_cost_based=off'; +set join_cache_level=6; +CREATE TABLE t10(a INT); +INSERT INTO t10 VALUES (0),(1),(2),(3),(4),(5),(6),(7),(8),(9); +CREATE TABLE t11(a INT); +INSERT INTO t11 SELECT A.a + B.a* 10 + C.a * 100 from t10 A, t10 B, t10 C; +CREATE TABLE t12(a INT, b INT); +INSERT INTO t12 SELECT a,a from t10; +CREATE TABLE t13(a INT, b INT, c INT, filler CHAR(100), key (a,b)); +INSERT INTO t13 select a,a,a, 'filler-data' FROM t11; +# Make sure BKA is expected to be used when there are no hints +EXPLAIN +SELECT * FROM t12, t13 WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t12 ALL NULL NULL NULL NULL 10 Using where +1 SIMPLE t13 ref a a 5 test.t12.a 1 Using index condition; Using join buffer (flat, BKA join); Rowid-ordered scan +# Disable BKA +set optimizer_switch='join_cache_bka=off'; +EXPLAIN EXTENDED +SELECT * FROM t12, t13 WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t12 ALL NULL NULL NULL NULL 10 100.00 Using where +1 SIMPLE t13 hash_ALL a #hash#a 5 test.t12.a 1000 0.10 Using where; Using join buffer (flat, BNLH join) +Warnings: +Note 1003 select `test`.`t12`.`a` AS `a`,`test`.`t12`.`b` AS `b`,`test`.`t13`.`a` AS `a`,`test`.`t13`.`b` AS `b`,`test`.`t13`.`c` AS `c`,`test`.`t13`.`filler` AS `filler` from `test`.`t12` join `test`.`t13` where `test`.`t13`.`a` = `test`.`t12`.`a` and `test`.`t13`.`b` + 1 <= `test`.`t13`.`b` + 1 +# Check statistics without hint +FLUSH STATUS; +SELECT * FROM t12, t13 WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +a b a b c filler +0 0 0 0 0 filler-data +1 1 1 1 1 filler-data +2 2 2 2 2 filler-data +3 3 3 3 3 filler-data +4 4 4 4 4 filler-data +5 5 5 5 5 filler-data +6 6 6 6 6 filler-data +7 7 7 7 7 filler-data +8 8 8 8 8 filler-data +9 9 9 9 9 filler-data +SHOW STATUS LIKE 'handler_read%'; +Variable_name Value +Handler_read_first 0 +Handler_read_key 0 +Handler_read_last 0 +Handler_read_next 0 +Handler_read_prev 0 +Handler_read_retry 0 +Handler_read_rnd 0 +Handler_read_rnd_deleted 0 +Handler_read_rnd_next 1012 +# Check statistics with hint +FLUSH STATUS; +SELECT /*+ BKA() */ * FROM t12, t13 WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +a b a b c filler +0 0 0 0 0 filler-data +1 1 1 1 1 filler-data +2 2 2 2 2 filler-data +3 3 3 3 3 filler-data +4 4 4 4 4 filler-data +5 5 5 5 5 filler-data +6 6 6 6 6 filler-data +7 7 7 7 7 filler-data +8 8 8 8 8 filler-data +9 9 9 9 9 filler-data +SHOW STATUS LIKE 'handler_read%'; +Variable_name Value +Handler_read_first 0 +Handler_read_key 10 +Handler_read_last 0 +Handler_read_next 10 +Handler_read_prev 0 +Handler_read_retry 0 +Handler_read_rnd 10 +Handler_read_rnd_deleted 0 +Handler_read_rnd_next 11 +EXPLAIN EXTENDED SELECT /*+ BKA(t13) */ * FROM t12, t13 +WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t12 ALL NULL NULL NULL NULL 10 100.00 Using where +1 SIMPLE t13 ref a a 5 test.t12.a 1 100.00 Using index condition; Using join buffer (flat, BKA join); Rowid-ordered scan +Warnings: +Note 1003 select /*+ BKA(`t13`@`select#1`) */ `test`.`t12`.`a` AS `a`,`test`.`t12`.`b` AS `b`,`test`.`t13`.`a` AS `a`,`test`.`t13`.`b` AS `b`,`test`.`t13`.`c` AS `c`,`test`.`t13`.`filler` AS `filler` from `test`.`t12` join `test`.`t13` where `test`.`t13`.`a` = `test`.`t12`.`a` and `test`.`t13`.`b` + 1 <= `test`.`t13`.`b` + 1 +EXPLAIN EXTENDED SELECT /*+ BKA() */ * FROM t12, t13 +WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t12 ALL NULL NULL NULL NULL 10 100.00 Using where +1 SIMPLE t13 ref a a 5 test.t12.a 1 100.00 Using index condition; Using join buffer (flat, BKA join); Rowid-ordered scan +Warnings: +Note 1003 select /*+ BKA(@`select#1`) */ `test`.`t12`.`a` AS `a`,`test`.`t12`.`b` AS `b`,`test`.`t13`.`a` AS `a`,`test`.`t13`.`b` AS `b`,`test`.`t13`.`c` AS `c`,`test`.`t13`.`filler` AS `filler` from `test`.`t12` join `test`.`t13` where `test`.`t13`.`a` = `test`.`t12`.`a` and `test`.`t13`.`b` + 1 <= `test`.`t13`.`b` + 1 +EXPLAIN EXTENDED SELECT /*+ BKA(t12, t13) */ * FROM t12, t13 +WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t12 ALL NULL NULL NULL NULL 10 100.00 Using where +1 SIMPLE t13 ref a a 5 test.t12.a 1 100.00 Using index condition; Using join buffer (flat, BKA join); Rowid-ordered scan +Warnings: +Note 1003 select /*+ BKA(`t12`@`select#1`) BKA(`t13`@`select#1`) */ `test`.`t12`.`a` AS `a`,`test`.`t12`.`b` AS `b`,`test`.`t13`.`a` AS `a`,`test`.`t13`.`b` AS `b`,`test`.`t13`.`c` AS `c`,`test`.`t13`.`filler` AS `filler` from `test`.`t12` join `test`.`t13` where `test`.`t13`.`a` = `test`.`t12`.`a` and `test`.`t13`.`b` + 1 <= `test`.`t13`.`b` + 1 +EXPLAIN EXTENDED SELECT /*+ BKA(t12) */ * FROM t12, t13 +WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t12 ALL NULL NULL NULL NULL 10 100.00 Using where +1 SIMPLE t13 hash_ALL a #hash#a 5 test.t12.a 1000 0.10 Using where; Using join buffer (flat, BNLH join) +Warnings: +Note 1003 select /*+ BKA(`t12`@`select#1`) */ `test`.`t12`.`a` AS `a`,`test`.`t12`.`b` AS `b`,`test`.`t13`.`a` AS `a`,`test`.`t13`.`b` AS `b`,`test`.`t13`.`c` AS `c`,`test`.`t13`.`filler` AS `filler` from `test`.`t12` join `test`.`t13` where `test`.`t13`.`a` = `test`.`t12`.`a` and `test`.`t13`.`b` + 1 <= `test`.`t13`.`b` + 1 +EXPLAIN EXTENDED SELECT /*+ QB_NAME(QB1) BKA(t13@QB1) */ * FROM t12, t13 +WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t12 ALL NULL NULL NULL NULL 10 100.00 Using where +1 SIMPLE t13 ref a a 5 test.t12.a 1 100.00 Using index condition; Using join buffer (flat, BKA join); Rowid-ordered scan +Warnings: +Note 1003 select /*+ QB_NAME(`QB1`) BKA(`t13`@`QB1`) */ `test`.`t12`.`a` AS `a`,`test`.`t12`.`b` AS `b`,`test`.`t13`.`a` AS `a`,`test`.`t13`.`b` AS `b`,`test`.`t13`.`c` AS `c`,`test`.`t13`.`filler` AS `filler` from `test`.`t12` join `test`.`t13` where `test`.`t13`.`a` = `test`.`t12`.`a` and `test`.`t13`.`b` + 1 <= `test`.`t13`.`b` + 1 +# Enable BKA +set optimizer_switch='join_cache_bka=on'; +EXPLAIN EXTENDED SELECT /*+ NO_BKA(t13) */ * FROM t12, t13 +WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t12 ALL NULL NULL NULL NULL 10 100.00 Using where +1 SIMPLE t13 hash_ALL a #hash#a 5 test.t12.a 1000 0.10 Using where; Using join buffer (flat, BNLH join) +Warnings: +Note 1003 select /*+ NO_BKA(`t13`@`select#1`) */ `test`.`t12`.`a` AS `a`,`test`.`t12`.`b` AS `b`,`test`.`t13`.`a` AS `a`,`test`.`t13`.`b` AS `b`,`test`.`t13`.`c` AS `c`,`test`.`t13`.`filler` AS `filler` from `test`.`t12` join `test`.`t13` where `test`.`t13`.`a` = `test`.`t12`.`a` and `test`.`t13`.`b` + 1 <= `test`.`t13`.`b` + 1 +EXPLAIN EXTENDED SELECT /*+ NO_BKA() */ * FROM t12, t13 +WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t12 ALL NULL NULL NULL NULL 10 100.00 Using where +1 SIMPLE t13 hash_ALL a #hash#a 5 test.t12.a 1000 0.10 Using where; Using join buffer (flat, BNLH join) +Warnings: +Note 1003 select /*+ NO_BKA(@`select#1`) */ `test`.`t12`.`a` AS `a`,`test`.`t12`.`b` AS `b`,`test`.`t13`.`a` AS `a`,`test`.`t13`.`b` AS `b`,`test`.`t13`.`c` AS `c`,`test`.`t13`.`filler` AS `filler` from `test`.`t12` join `test`.`t13` where `test`.`t13`.`a` = `test`.`t12`.`a` and `test`.`t13`.`b` + 1 <= `test`.`t13`.`b` + 1 +EXPLAIN EXTENDED SELECT /*+ NO_BKA(t12, t13) */ * FROM t12, t13 +WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t12 ALL NULL NULL NULL NULL 10 100.00 Using where +1 SIMPLE t13 hash_ALL a #hash#a 5 test.t12.a 1000 0.10 Using where; Using join buffer (flat, BNLH join) +Warnings: +Note 1003 select /*+ NO_BKA(`t12`@`select#1`) NO_BKA(`t13`@`select#1`) */ `test`.`t12`.`a` AS `a`,`test`.`t12`.`b` AS `b`,`test`.`t13`.`a` AS `a`,`test`.`t13`.`b` AS `b`,`test`.`t13`.`c` AS `c`,`test`.`t13`.`filler` AS `filler` from `test`.`t12` join `test`.`t13` where `test`.`t13`.`a` = `test`.`t12`.`a` and `test`.`t13`.`b` + 1 <= `test`.`t13`.`b` + 1 +EXPLAIN EXTENDED SELECT /*+ NO_BKA(t12) */ * FROM t12, t13 +WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t12 ALL NULL NULL NULL NULL 10 100.00 Using where +1 SIMPLE t13 ref a a 5 test.t12.a 1 100.00 Using index condition; Using join buffer (flat, BKA join); Rowid-ordered scan +Warnings: +Note 1003 select /*+ NO_BKA(`t12`@`select#1`) */ `test`.`t12`.`a` AS `a`,`test`.`t12`.`b` AS `b`,`test`.`t13`.`a` AS `a`,`test`.`t13`.`b` AS `b`,`test`.`t13`.`c` AS `c`,`test`.`t13`.`filler` AS `filler` from `test`.`t12` join `test`.`t13` where `test`.`t13`.`a` = `test`.`t12`.`a` and `test`.`t13`.`b` + 1 <= `test`.`t13`.`b` + 1 +EXPLAIN EXTENDED SELECT /*+ QB_NAME(QB1) NO_BKA(t13@QB1) */ * FROM t12, t13 +WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t12 ALL NULL NULL NULL NULL 10 100.00 Using where +1 SIMPLE t13 hash_ALL a #hash#a 5 test.t12.a 1000 0.10 Using where; Using join buffer (flat, BNLH join) +Warnings: +Note 1003 select /*+ QB_NAME(`QB1`) NO_BKA(`t13`@`QB1`) */ `test`.`t12`.`a` AS `a`,`test`.`t12`.`b` AS `b`,`test`.`t13`.`a` AS `a`,`test`.`t13`.`b` AS `b`,`test`.`t13`.`c` AS `c`,`test`.`t13`.`filler` AS `filler` from `test`.`t12` join `test`.`t13` where `test`.`t13`.`a` = `test`.`t12`.`a` and `test`.`t13`.`b` + 1 <= `test`.`t13`.`b` + 1 +# UPDATE|DELETE|INSERT hint testing +EXPLAIN EXTENDED UPDATE t3 +SET f3 = 'mnbv' WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN +(SELECT t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND +t2.f2 BETWEEN t1.f1 AND t1.f2 AND t2.f2 + 1 >= t1.f1 + 1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t3 range PRIMARY,f2_idx,f3_idx PRIMARY 4 NULL 2 100.00 Using index condition; Using where +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 3.33 Using where +1 PRIMARY t2 ref f1 f1 8 test.t3.f1,test.t3.f2 2 50.00 Using where; FirstMatch(t3) +Warnings: +Note 1003 update `test`.`t3` semi join (`test`.`t1` join `test`.`t2`) set `test`.`t3`.`f3` = 'mnbv' where `test`.`t1`.`f1` = `test`.`t3`.`f1` and `test`.`t2`.`f1` = `test`.`t3`.`f1` and `test`.`t2`.`f2` = `test`.`t3`.`f2` and `test`.`t3`.`f1` > 30 and `test`.`t3`.`f1` < 33 and `test`.`t3`.`f2` between `test`.`t3`.`f1` and `test`.`t1`.`f2` and `test`.`t3`.`f2` + 1 >= `test`.`t3`.`f1` + 1 and `test`.`t3`.`f3` = `test`.`t2`.`f3` +# Turn off range access for PRIMARY key. +# Range access should be used for f2_idx key. +EXPLAIN EXTENDED UPDATE /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY) */ t3 +SET f3 = 'mnbv' WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN +(SELECT /*+ BKA(t2) NO_BNL(t1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND +t2.f2 BETWEEN t1.f1 AND t1.f2 AND t2.f2 + 1 >= t1.f1 + 1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t3 range PRIMARY,f2_idx,f3_idx f2_idx 4 NULL 2 100.00 Using index condition; Using where +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 3.33 Using where +1 PRIMARY t2 ref f1 f1 8 test.t3.f1,test.t3.f2 2 50.00 Using where; FirstMatch(t3) +Warnings: +Note 1003 update /*+ BKA(`t2`@`select#2`) NO_BNL(`t1`@`select#2`) NO_RANGE_OPTIMIZATION(`t3`@`select#1` `PRIMARY`) */ `test`.`t3` semi join (`test`.`t1` join `test`.`t2`) set `test`.`t3`.`f3` = 'mnbv' where `test`.`t1`.`f1` = `test`.`t3`.`f1` and `test`.`t2`.`f1` = `test`.`t3`.`f1` and `test`.`t2`.`f2` = `test`.`t3`.`f2` and `test`.`t3`.`f1` > 30 and `test`.`t3`.`f1` < 33 and `test`.`t3`.`f2` between `test`.`t3`.`f1` and `test`.`t1`.`f2` and `test`.`t3`.`f2` + 1 >= `test`.`t3`.`f1` + 1 and `test`.`t3`.`f3` = `test`.`t2`.`f3` +# Turn off range access for all keys. +EXPLAIN EXTENDED UPDATE /*+ NO_RANGE_OPTIMIZATION(t3) */ t3 +SET f3 = 'mnbv' WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN +(SELECT t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND +t2.f2 BETWEEN t1.f1 AND t1.f2 AND t2.f2 + 1 >= t1.f1 + 1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t2 range f1 f1 4 NULL 1 100.00 Using index condition; Start temporary +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 11.11 Using where +1 PRIMARY t3 eq_ref PRIMARY,f2_idx,f3_idx PRIMARY 4 test.t2.f1 1 100.00 Using where; End temporary +Warnings: +Note 1003 update /*+ NO_RANGE_OPTIMIZATION(`t3`@`select#1`) */ `test`.`t3` semi join (`test`.`t1` join `test`.`t2`) set `test`.`t3`.`f3` = 'mnbv' where `test`.`t1`.`f1` = `test`.`t2`.`f1` and `test`.`t3`.`f1` = `test`.`t2`.`f1` and `test`.`t3`.`f2` = `test`.`t2`.`f2` and `test`.`t2`.`f1` > 30 and `test`.`t2`.`f1` < 33 and `test`.`t2`.`f2` between `test`.`t2`.`f1` and `test`.`t1`.`f2` and `test`.`t2`.`f2` + 1 >= `test`.`t2`.`f1` + 1 and `test`.`t3`.`f3` = `test`.`t2`.`f3` +EXPLAIN EXTENDED DELETE FROM t3 +WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN +(SELECT /*+ QB_NAME(qb1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND +t2.f2 BETWEEN t1.f1 AND t1.f2 AND t2.f2 + 1 >= t1.f1 + 1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t3 range PRIMARY,f2_idx,f3_idx PRIMARY 4 NULL 2 100.00 Using index condition; Using where +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 3.33 Using where +1 PRIMARY t2 ref f1 f1 8 test.t3.f1,test.t3.f2 2 50.00 Using where; FirstMatch(t3) +Warnings: +Note 1003 delete from `test`.`t3` using (`test`.`t1` join `test`.`t2`) where `test`.`t1`.`f1` = `test`.`t3`.`f1` and `test`.`t2`.`f1` = `test`.`t3`.`f1` and `test`.`t2`.`f2` = `test`.`t3`.`f2` and `test`.`t3`.`f1` > 30 and `test`.`t3`.`f1` < 33 and `test`.`t3`.`f2` between `test`.`t3`.`f1` and `test`.`t1`.`f2` and `test`.`t3`.`f2` + 1 >= `test`.`t3`.`f1` + 1 and `test`.`t3`.`f3` = `test`.`t2`.`f3` +# Turn off range access. Range access should not be used. +EXPLAIN EXTENDED +DELETE /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY, f2_idx) NO_BNL(t1@QB1) */ FROM t3 +WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN +(SELECT /*+ QB_NAME(qb1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND +t2.f2 BETWEEN t1.f1 AND t1.f2 AND t2.f2 + 1 >= t1.f1 + 1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t2 range f1 f1 4 NULL 1 100.00 Using index condition; Start temporary +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 11.11 Using where +1 PRIMARY t3 eq_ref PRIMARY,f2_idx,f3_idx PRIMARY 4 test.t2.f1 1 100.00 Using where; End temporary +Warnings: +Note 1003 delete /*+ NO_BNL(`t1`@`qb1`) NO_RANGE_OPTIMIZATION(`t3`@`select#1` `PRIMARY`) NO_RANGE_OPTIMIZATION(`t3`@`select#1` `f2_idx`) */ from `test`.`t3` using (`test`.`t1` join `test`.`t2`) where `test`.`t1`.`f1` = `test`.`t2`.`f1` and `test`.`t3`.`f1` = `test`.`t2`.`f1` and `test`.`t3`.`f2` = `test`.`t2`.`f2` and `test`.`t2`.`f1` > 30 and `test`.`t2`.`f1` < 33 and `test`.`t2`.`f2` between `test`.`t2`.`f1` and `test`.`t1`.`f2` and `test`.`t2`.`f2` + 1 >= `test`.`t2`.`f1` + 1 and `test`.`t3`.`f3` = `test`.`t2`.`f3` +# Make sure ICP is expected to be used when there are no hints +EXPLAIN EXTENDED INSERT INTO t3(f1, f2, f3) +(SELECT t4.x, t5.y, 'filler' FROM t4, t4 t5 WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t4 ref y_idx y_idx 5 const 1 100.00 +1 SIMPLE t5 range x_idx x_idx 5 NULL 2 100.00 Using index condition; Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 (insert into `test`.`t3`(f1,f2,f3) select `test`.`t4`.`x` AS `x`,`test`.`t5`.`y` AS `y`,'filler' AS `filler` from `test`.`t4` join `test`.`t4` `t5` where `test`.`t4`.`y` = 8 and `test`.`t5`.`x` between 7 and (8 + 0)) +# Turn off ICP. ICP should not be used. +EXPLAIN EXTENDED INSERT INTO t3(f1, f2, f3) +(SELECT /*+ NO_ICP(t5) */t4.x, t5.y, 'filler' FROM t4, t4 t5 +WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t4 ref y_idx y_idx 5 const 1 100.00 +1 SIMPLE t5 range x_idx x_idx 5 NULL 2 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 (insert into `test`.`t3`(f1,f2,f3) select /*+ NO_ICP(`t5`@`select#2`) */ `test`.`t4`.`x` AS `x`,`test`.`t5`.`y` AS `y`,'filler' AS `filler` from `test`.`t4` join `test`.`t4` `t5` where `test`.`t4`.`y` = 8 and `test`.`t5`.`x` between 7 and (8 + 0)) +# Turn off ICP for a particular table +EXPLAIN EXTENDED INSERT /*+ NO_ICP(t5@QB1) */ INTO t3(f1, f2, f3) +(SELECT /*+ QB_NAME(qb1) */ t4.x, t5.y, 'filler' FROM t4, t4 t5 +WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t4 ref y_idx y_idx 5 const 1 100.00 +1 SIMPLE t5 range x_idx x_idx 5 NULL 2 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 (insert into `test`.`t3`(f1,f2,f3) select /*+ QB_NAME(`qb1`) NO_ICP(`t5`@`qb1`) */ `test`.`t4`.`x` AS `x`,`test`.`t5`.`y` AS `y`,'filler' AS `filler` from `test`.`t4` join `test`.`t4` `t5` where `test`.`t4`.`y` = 8 and `test`.`t5`.`x` between 7 and (8 + 0)) +# Turn off ICP for a particular table and a key +EXPLAIN EXTENDED INSERT /*+ NO_ICP(t5@QB1 x_idx) */ INTO t3(f1, f2, f3) +(SELECT /*+ QB_NAME(qb1) */ t4.x, t5.y, 'filler' FROM t4, t4 t5 +WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t4 ref y_idx y_idx 5 const 1 100.00 +1 SIMPLE t5 range x_idx x_idx 5 NULL 2 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 (insert into `test`.`t3`(f1,f2,f3) select /*+ QB_NAME(`qb1`) NO_ICP(`t5`@`qb1` `x_idx`) */ `test`.`t4`.`x` AS `x`,`test`.`t5`.`y` AS `y`,'filler' AS `filler` from `test`.`t4` join `test`.`t4` `t5` where `test`.`t4`.`y` = 8 and `test`.`t5`.`x` between 7 and (8 + 0)) +# Misc tests +# Should issue warning +EXPLAIN EXTENDED SELECT /*+ QB_NAME(qb1) QB_NAME(qb1 ) */ * FROM t2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t2 ALL NULL NULL NULL NULL 28 100.00 +Warnings: +Warning 4197 Hint QB_NAME(`qb1`) is ignored as conflicting/duplicated +Note 1003 select /*+ QB_NAME(`qb1`) */ `test`.`t2`.`f1` AS `f1`,`test`.`t2`.`f2` AS `f2`,`test`.`t2`.`f3` AS `f3` from `test`.`t2` +# Should issue warning +EXPLAIN EXTENDED SELECT /*+ BKA(@qb1) QB_NAME(qb1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 +WHERE t1.f1=t2.f1 AND t2.f2 BETWEEN t1.f1 and t1.f2 and t2.f2 + 1 >= t1.f1 + 1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 +1 SIMPLE t2 ALL f1 NULL NULL NULL 28 25.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Warning 4198 Query block name `qb1` is not found for BKA hint +Note 1003 select /*+ QB_NAME(`qb1`) */ `test`.`t2`.`f1` AS `f1`,`test`.`t2`.`f2` AS `f2`,`test`.`t2`.`f3` AS `f3` from `test`.`t1` join `test`.`t2` where `test`.`t2`.`f1` = `test`.`t1`.`f1` and `test`.`t2`.`f2` between `test`.`t1`.`f1` and `test`.`t1`.`f2` and `test`.`t2`.`f2` + 1 >= `test`.`t1`.`f1` + 1 +# Should not crash +PREPARE stmt1 FROM "SELECT /*+ BKA(t2) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 +WHERE t1.f1=t2.f1 AND t2.f2 BETWEEN t1.f1 and t1.f2 and t2.f2 + 1 >= t1.f1 + 1"; +EXECUTE stmt1; +f1 f2 f3 +1 1 qwerty +2 2 qwerty +1 1 qwerty +2 2 qwerty +EXECUTE stmt1; +f1 f2 f3 +1 1 qwerty +2 2 qwerty +1 1 qwerty +2 2 qwerty +DEALLOCATE PREPARE stmt1; +# Check use of alias +set optimizer_switch='join_cache_bka=off'; +EXPLAIN EXTENDED +SELECT * FROM t12, t13 WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t12 ALL NULL NULL NULL NULL 10 100.00 Using where +1 SIMPLE t13 hash_ALL a #hash#a 5 test.t12.a 1000 0.10 Using where; Using join buffer (flat, BNLH join) +Warnings: +Note 1003 select `test`.`t12`.`a` AS `a`,`test`.`t12`.`b` AS `b`,`test`.`t13`.`a` AS `a`,`test`.`t13`.`b` AS `b`,`test`.`t13`.`c` AS `c`,`test`.`t13`.`filler` AS `filler` from `test`.`t12` join `test`.`t13` where `test`.`t13`.`a` = `test`.`t12`.`a` and `test`.`t13`.`b` + 1 <= `test`.`t13`.`b` + 1 +# Turn on BKA for multiple tables. BKA should be used for tbl13. +EXPLAIN EXTENDED SELECT /*+ BKA(tbl12, tbl13) */ * FROM t12 tbl12, t13 tbl13 +WHERE tbl12.a=tbl13.a AND (tbl13.b+1 <= tbl13.b+1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE tbl12 ALL NULL NULL NULL NULL 10 100.00 Using where +1 SIMPLE tbl13 ref a a 5 test.tbl12.a 1 100.00 Using index condition; Using join buffer (flat, BKA join); Rowid-ordered scan +Warnings: +Note 1003 select /*+ BKA(`tbl12`@`select#1`) BKA(`tbl13`@`select#1`) */ `test`.`tbl12`.`a` AS `a`,`test`.`tbl12`.`b` AS `b`,`test`.`tbl13`.`a` AS `a`,`test`.`tbl13`.`b` AS `b`,`test`.`tbl13`.`c` AS `c`,`test`.`tbl13`.`filler` AS `filler` from `test`.`t12` `tbl12` join `test`.`t13` `tbl13` where `test`.`tbl13`.`a` = `test`.`tbl12`.`a` and `test`.`tbl13`.`b` + 1 <= `test`.`tbl13`.`b` + 1 +# Print warnings for nonexistent names +EXPLAIN EXTENDED +SELECT /*+ BKA(t2) NO_BNL(t1) BKA(t3) NO_RANGE_OPTIMIZATION(t3 idx1) NO_RANGE_OPTIMIZATION(t3) */ +t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND +t2.f2 BETWEEN t1.f1 AND t1.f2 AND t2.f2 + 1 >= t1.f1 + 1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 +1 SIMPLE t2 ALL f1 NULL NULL NULL 28 25.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Warning 4199 Unresolved name `t3`@`select#1` for BKA hint +Warning 4199 Unresolved name `t3`@`select#1` for NO_RANGE_OPTIMIZATION hint +Warning 4199 Unresolved name `t3`@`select#1` `idx1` for NO_RANGE_OPTIMIZATION hint +Note 1003 select /*+ BKA(`t2`@`select#1`) NO_BNL(`t1`@`select#1`) */ `test`.`t2`.`f1` AS `f1`,`test`.`t2`.`f2` AS `f2`,`test`.`t2`.`f3` AS `f3` from `test`.`t1` join `test`.`t2` where `test`.`t2`.`f1` = `test`.`t1`.`f1` and `test`.`t2`.`f2` between `test`.`t1`.`f1` and `test`.`t1`.`f2` and `test`.`t2`.`f2` + 1 >= `test`.`t1`.`f1` + 1 +# Check illegal syntax +EXPLAIN EXTENDED SELECT /*+ BKA(qb1 t3@qb1) */ f2 FROM +(SELECT /*+ QB_NAME(qb1) */ f2, f3, f1 FROM t3 WHERE f1 > 2 AND f3 = 'poiu') AS TD +WHERE TD.f1 > 2 AND TD.f3 = 'poiu'; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t3 ALL PRIMARY,f2_idx,f3_idx NULL NULL NULL 56 27.55 Using where +Warnings: +Warning 1064 Optimizer hint syntax error near 't3@qb1) */ f2 FROM +(SELECT /*+ QB_NAME(qb1) */ f2, f3, f1 FROM t3 WHERE f1 > ...' at line 1 +Note 1003 select `test`.`t3`.`f2` AS `f2` from `test`.`t3` where `test`.`t3`.`f3` = 'poiu' and `test`.`t3`.`f1` > 2 and `test`.`t3`.`f1` > 2 +# Check illegal syntax +EXPLAIN EXTENDED SELECT * FROM +(SELECT /*+ QB_NAME(qb1) BKA(@qb1 t1@qb1, t2@qb1, t3) */ t2.f1, t2.f2, t2.f3 FROM t1,t2,t3) tt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 28 100.00 Using join buffer (flat, BNL join) +1 SIMPLE t3 index NULL PRIMARY 4 NULL 56 100.00 Using index; Using join buffer (incremental, BNL join) +Warnings: +Warning 1064 Optimizer hint syntax error near 'qb1, t2@qb1, t3) */ t2.f1, t2.f2, t2.f3 FROM t1,t2,t3) tt' at line 2 +Note 1003 select `test`.`t2`.`f1` AS `f1`,`test`.`t2`.`f2` AS `f2`,`test`.`t2`.`f3` AS `f3` from `test`.`t1` join `test`.`t2` join `test`.`t3` +# Check '@qb_name table_name' syntax +EXPLAIN EXTENDED SELECT /*+ BKA(@qb1 t13) */ * FROM (SELECT /*+ QB_NAME(QB1) */ t12.a, t13.b FROM t12, t13 +WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1)) AS s1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t12 ALL NULL NULL NULL NULL 10 100.00 Using where +1 SIMPLE t13 ref a a 5 test.t12.a 1 100.00 Using where; Using index +Warnings: +Note 1003 select /*+ BKA(`t13`@`QB1`) */ `test`.`t12`.`a` AS `a`,`test`.`t13`.`b` AS `b` from `test`.`t12` join `test`.`t13` where `test`.`t13`.`a` = `test`.`t12`.`a` and `test`.`t13`.`b` + 1 <= `test`.`t13`.`b` + 1 +# Check that original table name is not recognized if alias is used. +EXPLAIN EXTENDED SELECT /*+ BKA(tbl2) */ * FROM t12 tbl12, t13 tbl13 +WHERE tbl12.a=tbl13.a AND (tbl13.b+1 <= tbl13.b+1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE tbl12 ALL NULL NULL NULL NULL 10 100.00 Using where +1 SIMPLE tbl13 hash_ALL a #hash#a 5 test.tbl12.a 1000 0.10 Using where; Using join buffer (flat, BNLH join) +Warnings: +Warning 4199 Unresolved name `tbl2`@`select#1` for BKA hint +Note 1003 select `test`.`tbl12`.`a` AS `a`,`test`.`tbl12`.`b` AS `b`,`test`.`tbl13`.`a` AS `a`,`test`.`tbl13`.`b` AS `b`,`test`.`tbl13`.`c` AS `c`,`test`.`tbl13`.`filler` AS `filler` from `test`.`t12` `tbl12` join `test`.`t13` `tbl13` where `test`.`tbl13`.`a` = `test`.`tbl12`.`a` and `test`.`tbl13`.`b` + 1 <= `test`.`tbl13`.`b` + 1 +# Check that PS and conventional statements give the same result. +FLUSH STATUS; +SELECT /*+ BKA(t13) */ * FROM t12, t13 WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +a b a b c filler +0 0 0 0 0 filler-data +1 1 1 1 1 filler-data +2 2 2 2 2 filler-data +3 3 3 3 3 filler-data +4 4 4 4 4 filler-data +5 5 5 5 5 filler-data +6 6 6 6 6 filler-data +7 7 7 7 7 filler-data +8 8 8 8 8 filler-data +9 9 9 9 9 filler-data +SHOW STATUS LIKE 'handler_read%'; +Variable_name Value +Handler_read_first 0 +Handler_read_key 10 +Handler_read_last 0 +Handler_read_next 10 +Handler_read_prev 0 +Handler_read_retry 0 +Handler_read_rnd 10 +Handler_read_rnd_deleted 0 +Handler_read_rnd_next 11 +PREPARE stmt1 FROM "SELECT /*+ BKA(t13) */ * FROM t12, t13 WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1)"; +FLUSH STATUS; +EXECUTE stmt1; +a b a b c filler +0 0 0 0 0 filler-data +1 1 1 1 1 filler-data +2 2 2 2 2 filler-data +3 3 3 3 3 filler-data +4 4 4 4 4 filler-data +5 5 5 5 5 filler-data +6 6 6 6 6 filler-data +7 7 7 7 7 filler-data +8 8 8 8 8 filler-data +9 9 9 9 9 filler-data +SHOW STATUS LIKE 'handler_read%'; +Variable_name Value +Handler_read_first 0 +Handler_read_key 10 +Handler_read_last 0 +Handler_read_next 10 +Handler_read_prev 0 +Handler_read_retry 0 +Handler_read_rnd 10 +Handler_read_rnd_deleted 0 +Handler_read_rnd_next 11 +FLUSH STATUS; +EXECUTE stmt1; +a b a b c filler +0 0 0 0 0 filler-data +1 1 1 1 1 filler-data +2 2 2 2 2 filler-data +3 3 3 3 3 filler-data +4 4 4 4 4 filler-data +5 5 5 5 5 filler-data +6 6 6 6 6 filler-data +7 7 7 7 7 filler-data +8 8 8 8 8 filler-data +9 9 9 9 9 filler-data +SHOW STATUS LIKE 'handler_read%'; +Variable_name Value +Handler_read_first 0 +Handler_read_key 10 +Handler_read_last 0 +Handler_read_next 10 +Handler_read_prev 0 +Handler_read_retry 0 +Handler_read_rnd 10 +Handler_read_rnd_deleted 0 +Handler_read_rnd_next 11 +DEALLOCATE PREPARE stmt1; +DROP TABLE t1, t2, t3, t10, t11, t12, t13; +# BNL & NO_BNL hint testing +set optimizer_switch=default; +CREATE TABLE t1 (a INT, b INT); +INSERT INTO t1 VALUES (1,1),(2,2); +CREATE TABLE t2 (a INT, b INT); +INSERT INTO t2 VALUES (1,1),(2,2); +CREATE TABLE t3 (a INT, b INT); +INSERT INTO t3 VALUES (1,1),(2,2); +# Check statistics without hint +FLUSH STATUS; +SELECT t1.* FROM t1,t2,t3; +a b +1 1 +2 2 +1 1 +2 2 +1 1 +2 2 +1 1 +2 2 +SHOW STATUS LIKE 'handler_read%'; +Variable_name Value +Handler_read_first 0 +Handler_read_key 0 +Handler_read_last 0 +Handler_read_next 0 +Handler_read_prev 0 +Handler_read_retry 0 +Handler_read_rnd 0 +Handler_read_rnd_deleted 0 +Handler_read_rnd_next 9 +# Check statistics with hint +FLUSH STATUS; +SELECT /*+ NO_BNL() */t1.* FROM t1,t2,t3; +a b +1 1 +1 1 +1 1 +1 1 +2 2 +2 2 +2 2 +2 2 +SHOW STATUS LIKE 'handler_read%'; +Variable_name Value +Handler_read_first 0 +Handler_read_key 0 +Handler_read_last 0 +Handler_read_next 0 +Handler_read_prev 0 +Handler_read_retry 0 +Handler_read_rnd 0 +Handler_read_rnd_deleted 0 +Handler_read_rnd_next 21 +EXPLAIN EXTENDED SELECT t1.* FROM t1,t2,t3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (incremental, BNL join) +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` join `test`.`t2` join `test`.`t3` +EXPLAIN EXTENDED SELECT /*+ NO_BNL() */t1.* FROM t1,t2,t3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE t3 ALL NULL NULL NULL NULL 2 100.00 +Warnings: +Note 1003 select /*+ NO_BNL(@`select#1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` join `test`.`t2` join `test`.`t3` +EXPLAIN EXTENDED SELECT /*+ NO_BNL(t2, t3) */t1.* FROM t1,t2,t3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE t3 ALL NULL NULL NULL NULL 2 100.00 +Warnings: +Note 1003 select /*+ NO_BNL(`t2`@`select#1`) NO_BNL(`t3`@`select#1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` join `test`.`t2` join `test`.`t3` +EXPLAIN EXTENDED SELECT /*+ NO_BNL(t1, t3) */t1.* FROM t1,t2,t3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 2 100.00 +Warnings: +Note 1003 select /*+ NO_BNL(`t1`@`select#1`) NO_BNL(`t3`@`select#1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` join `test`.`t2` join `test`.`t3` +# MariaDB does not have optimizer_switch='block_nested_loop=off' +# as MySQL does, so in fact we cannot disable BNL join. The cases below +# test the BNL() hint, although it does not affect the execution plan +EXPLAIN EXTENDED SELECT t1.* FROM t1,t2,t3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (incremental, BNL join) +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` join `test`.`t2` join `test`.`t3` +EXPLAIN EXTENDED SELECT /*+ BNL() */t1.* FROM t1,t2,t3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (incremental, BNL join) +Warnings: +Note 1003 select /*+ BNL(@`select#1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` join `test`.`t2` join `test`.`t3` +EXPLAIN EXTENDED SELECT /*+ BNL(t2, t3) */t1.* FROM t1,t2,t3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (incremental, BNL join) +Warnings: +Note 1003 select /*+ BNL(`t2`@`select#1`) BNL(`t3`@`select#1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` join `test`.`t2` join `test`.`t3` +EXPLAIN EXTENDED SELECT /*+ BNL(t1, t3) */t1.* FROM t1,t2,t3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (incremental, BNL join) +Warnings: +Note 1003 select /*+ BNL(`t1`@`select#1`) BNL(`t3`@`select#1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` join `test`.`t2` join `test`.`t3` +EXPLAIN EXTENDED SELECT /*+ BNL(t2) BNL(t3) */t1.* FROM t1,t2,t3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (incremental, BNL join) +Warnings: +Note 1003 select /*+ BNL(`t2`@`select#1`) BNL(`t3`@`select#1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` join `test`.`t2` join `test`.`t3` +DROP TABLE t1, t2, t3; +# BNL in subquery +set optimizer_switch = DEFAULT; +CREATE TABLE t1 (a INT, b INT, PRIMARY KEY (a)); +CREATE TABLE t2 (a INT); +CREATE TABLE t3 (a INT, b INT, INDEX a (a,b)); +INSERT INTO t1 VALUES (1,10), (2,20), (3,30), (4,40); +INSERT INTO t2 VALUES (2), (3), (4), (5); +INSERT INTO t3 VALUES (10,3), (20,4), (30,5); +ANALYZE TABLE t1, t2, t3; +Table Op Msg_type Msg_text +test.t1 analyze status Engine-independent statistics collected +test.t1 analyze status OK +test.t2 analyze status Engine-independent statistics collected +test.t2 analyze status OK +test.t3 analyze status Engine-independent statistics collected +test.t3 analyze status OK +EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) */ * FROM t1 JOIN t2 ON t1.b = t2.a WHERE +t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 4 100.00 Using where +1 PRIMARY t2 hash_ALL NULL #hash#$hj 5 test.t1.b 4 10.00 Using where; Using join buffer (flat, BNLH join) +1 PRIMARY t3 index NULL a 10 NULL 3 10.00 Using where; Using index; Using join buffer (incremental, BNL join) +1 PRIMARY t4 ALL NULL NULL NULL NULL 4 25.00 Using where; FirstMatch(t2); Using join buffer (incremental, BNL join) +Warnings: +Note 1003 select /*+ QB_NAME(`q`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a` from `test`.`t1` semi join (`test`.`t3` join `test`.`t1` `t4`) join `test`.`t2` where `test`.`t2`.`a` = `test`.`t1`.`b` and `test`.`t3`.`b` = `test`.`t1`.`b` and `test`.`t4`.`b` = `test`.`t1`.`b` +EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL() */ * FROM t1 JOIN t2 ON t1.b = t2.a WHERE +t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 4 100.00 Using where +1 PRIMARY t2 hash_ALL NULL #hash#$hj 5 test.t1.b 4 10.00 Using where; Using join buffer (flat, BNLH join) +1 PRIMARY t3 index NULL a 10 NULL 3 10.00 Using where; Using index; Using join buffer (incremental, BNL join) +1 PRIMARY t4 ALL NULL NULL NULL NULL 4 25.00 Using where; FirstMatch(t2); Using join buffer (incremental, BNL join) +Warnings: +Note 1003 select /*+ QB_NAME(`q`) NO_BNL(@`q`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a` from `test`.`t1` semi join (`test`.`t3` join `test`.`t1` `t4`) join `test`.`t2` where `test`.`t2`.`a` = `test`.`t1`.`b` and `test`.`t3`.`b` = `test`.`t1`.`b` and `test`.`t4`.`b` = `test`.`t1`.`b` +EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL(t1, t2) */ * FROM t1 JOIN t2 ON t1.b = t2.a WHERE +t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 4 100.00 Using where +1 PRIMARY t2 hash_ALL NULL #hash#$hj 5 test.t1.b 4 10.00 Using where; Using join buffer (flat, BNLH join) +1 PRIMARY t3 index NULL a 10 NULL 3 10.00 Using where; Using index; Using join buffer (incremental, BNL join) +1 PRIMARY t4 ALL NULL NULL NULL NULL 4 25.00 Using where; FirstMatch(t2); Using join buffer (incremental, BNL join) +Warnings: +Note 1003 select /*+ QB_NAME(`q`) NO_BNL(`t1`@`q`) NO_BNL(`t2`@`q`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a` from `test`.`t1` semi join (`test`.`t3` join `test`.`t1` `t4`) join `test`.`t2` where `test`.`t2`.`a` = `test`.`t1`.`b` and `test`.`t3`.`b` = `test`.`t1`.`b` and `test`.`t4`.`b` = `test`.`t1`.`b` +EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL(@subq1) */ * FROM t1 JOIN t2 ON t1.b = t2.a WHERE +t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 4 100.00 Using where +1 PRIMARY t2 hash_ALL NULL #hash#$hj 5 test.t1.b 4 10.00 Using where; Using join buffer (flat, BNLH join) +1 PRIMARY t3 index NULL a 10 NULL 3 10.00 Using where; Using index +1 PRIMARY t4 ALL NULL NULL NULL NULL 4 25.00 Using where; FirstMatch(t2) +Warnings: +Note 1003 select /*+ QB_NAME(`q`) NO_BNL(@`subq1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a` from `test`.`t1` semi join (`test`.`t3` join `test`.`t1` `t4`) join `test`.`t2` where `test`.`t2`.`a` = `test`.`t1`.`b` and `test`.`t3`.`b` = `test`.`t1`.`b` and `test`.`t4`.`b` = `test`.`t1`.`b` +EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL(t4@subq1) */ * FROM t1 JOIN t2 ON t1.b = t2.a WHERE +t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 4 100.00 Using where +1 PRIMARY t2 hash_ALL NULL #hash#$hj 5 test.t1.b 4 10.00 Using where; Using join buffer (flat, BNLH join) +1 PRIMARY t3 index NULL a 10 NULL 3 10.00 Using where; Using index +1 PRIMARY t4 ALL NULL NULL NULL NULL 4 25.00 Using where; FirstMatch(t2) +Warnings: +Note 1003 select /*+ QB_NAME(`q`) NO_BNL(`t4`@`subq1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a` from `test`.`t1` semi join (`test`.`t3` join `test`.`t1` `t4`) join `test`.`t2` where `test`.`t2`.`a` = `test`.`t1`.`b` and `test`.`t3`.`b` = `test`.`t1`.`b` and `test`.`t4`.`b` = `test`.`t1`.`b` +EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL(t3@subq1,t4@subq1) */ * FROM t1 JOIN t2 ON t1.b = t2.a WHERE +t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 4 100.00 Using where +1 PRIMARY t2 hash_ALL NULL #hash#$hj 5 test.t1.b 4 10.00 Using where; Using join buffer (flat, BNLH join) +1 PRIMARY t3 index NULL a 10 NULL 3 10.00 Using where; Using index +1 PRIMARY t4 ALL NULL NULL NULL NULL 4 25.00 Using where; FirstMatch(t2) +Warnings: +Note 1003 select /*+ QB_NAME(`q`) NO_BNL(`t3`@`subq1`) NO_BNL(`t4`@`subq1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a` from `test`.`t1` semi join (`test`.`t3` join `test`.`t1` `t4`) join `test`.`t2` where `test`.`t2`.`a` = `test`.`t1`.`b` and `test`.`t3`.`b` = `test`.`t1`.`b` and `test`.`t4`.`b` = `test`.`t1`.`b` +EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL(@subq1 t3, t4) */ * FROM t1 JOIN t2 ON t1.b = t2.a WHERE +t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 4 100.00 Using where +1 PRIMARY t2 hash_ALL NULL #hash#$hj 5 test.t1.b 4 10.00 Using where; Using join buffer (flat, BNLH join) +1 PRIMARY t3 index NULL a 10 NULL 3 10.00 Using where; Using index +1 PRIMARY t4 ALL NULL NULL NULL NULL 4 25.00 Using where; FirstMatch(t2) +Warnings: +Note 1003 select /*+ QB_NAME(`q`) NO_BNL(`t3`@`subq1`) NO_BNL(`t4`@`subq1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a` from `test`.`t1` semi join (`test`.`t3` join `test`.`t1` `t4`) join `test`.`t2` where `test`.`t2`.`a` = `test`.`t1`.`b` and `test`.`t3`.`b` = `test`.`t1`.`b` and `test`.`t4`.`b` = `test`.`t1`.`b` +EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) */ * FROM t1 JOIN t2 ON t1.b = t2.a WHERE +t2.a IN (SELECT /*+ QB_NAME(subq1) NO_BNL(t3, t4) */ t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 4 100.00 Using where +1 PRIMARY t2 hash_ALL NULL #hash#$hj 5 test.t1.b 4 10.00 Using where; Using join buffer (flat, BNLH join) +1 PRIMARY t3 index NULL a 10 NULL 3 10.00 Using where; Using index +1 PRIMARY t4 ALL NULL NULL NULL NULL 4 25.00 Using where; FirstMatch(t2) +Warnings: +Note 1003 select /*+ QB_NAME(`q`) NO_BNL(`t3`@`subq1`) NO_BNL(`t4`@`subq1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a` from `test`.`t1` semi join (`test`.`t3` join `test`.`t1` `t4`) join `test`.`t2` where `test`.`t2`.`a` = `test`.`t1`.`b` and `test`.`t3`.`b` = `test`.`t1`.`b` and `test`.`t4`.`b` = `test`.`t1`.`b` +DROP TABLE t1, t2, t3, t4; +# MRR & NO_MRR hint testing +set optimizer_switch=default; +CREATE TABLE t1 +( +f1 int NOT NULL DEFAULT '0', +f2 int NOT NULL DEFAULT '0', +f3 int NOT NULL DEFAULT '0', +INDEX idx1(f2, f3), INDEX idx2(f3) +); +INSERT INTO t1(f1) VALUES (1), (2), (3), (4), (5), (6), (7), (8); +INSERT INTO t1(f2, f3) VALUES (3,4), (3,4); +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status Engine-independent statistics collected +test.t1 analyze status OK +set optimizer_switch='mrr=on,mrr_cost_based=off'; +# Check statistics without hint +FLUSH STATUS; +SELECT * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +f1 f2 f3 +0 3 4 +0 3 4 +SHOW STATUS LIKE 'handler_read%'; +Variable_name Value +Handler_read_first 0 +Handler_read_key 1 +Handler_read_last 0 +Handler_read_next 2 +Handler_read_prev 0 +Handler_read_retry 0 +Handler_read_rnd 2 +Handler_read_rnd_deleted 0 +Handler_read_rnd_next 0 +# Check statistics with hint +FLUSH STATUS; +SELECT /*+ NO_MRR(t1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +f1 f2 f3 +0 3 4 +0 3 4 +SHOW STATUS LIKE 'handler_read%'; +Variable_name Value +Handler_read_first 0 +Handler_read_key 1 +Handler_read_last 0 +Handler_read_next 2 +Handler_read_prev 0 +Handler_read_retry 0 +Handler_read_rnd 0 +Handler_read_rnd_deleted 0 +Handler_read_rnd_next 0 +# Make sure hints are preserved in a stored procedure body +CREATE PROCEDURE p() SELECT /*+ NO_MRR(t1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +SHOW CREATE PROCEDURE p; +Procedure sql_mode Create Procedure character_set_client collation_connection Database Collation +p STRICT_TRANS_TABLES,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION CREATE DEFINER=`root`@`localhost` PROCEDURE `p`() +SELECT /*+ NO_MRR(t1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3 latin1 latin1_swedish_ci latin1_swedish_ci +FLUSH STATUS; +CALL p(); +f1 f2 f3 +0 3 4 +0 3 4 +SHOW STATUS LIKE 'handler_read%'; +Variable_name Value +Handler_read_first 0 +Handler_read_key 2 +Handler_read_last 0 +Handler_read_next 2 +Handler_read_prev 0 +Handler_read_retry 0 +Handler_read_rnd 0 +Handler_read_rnd_deleted 0 +Handler_read_rnd_next 0 +DROP PROCEDURE p; +EXPLAIN EXTENDED SELECT * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx1,idx2 idx2 4 NULL 2 100.00 Using index condition; Using where; Rowid-ordered scan +Warnings: +Note 1003 select `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`test`.`t1`.`f3` AS `f3` from `test`.`t1` where `test`.`t1`.`f2` <= 3 and 3 <= `test`.`t1`.`f3` +# Turn off MRR. MRR should not be used. +EXPLAIN EXTENDED SELECT /*+ NO_MRR(t1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx1,idx2 idx2 4 NULL 2 100.00 Using index condition; Using where +Warnings: +Note 1003 select /*+ NO_MRR(`t1`@`select#1`) */ `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`test`.`t1`.`f3` AS `f3` from `test`.`t1` where `test`.`t1`.`f2` <= 3 and 3 <= `test`.`t1`.`f3` +# Turn off MRR. MRR should not be used. +EXPLAIN EXTENDED SELECT /*+ NO_MRR(t1 idx2) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx1,idx2 idx2 4 NULL 2 100.00 Using index condition; Using where +Warnings: +Note 1003 select /*+ NO_MRR(`t1`@`select#1` `idx2`) */ `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`test`.`t1`.`f3` AS `f3` from `test`.`t1` where `test`.`t1`.`f2` <= 3 and 3 <= `test`.`t1`.`f3` +# Turn off MRR for unused key. MRR should be used. +EXPLAIN EXTENDED SELECT /*+ NO_MRR(t1 idx1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx1,idx2 idx2 4 NULL 2 100.00 Using index condition; Using where; Rowid-ordered scan +Warnings: +Note 1003 select /*+ NO_MRR(`t1`@`select#1` `idx1`) */ `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`test`.`t1`.`f3` AS `f3` from `test`.`t1` where `test`.`t1`.`f2` <= 3 and 3 <= `test`.`t1`.`f3` +set optimizer_switch='mrr=off,mrr_cost_based=off'; +EXPLAIN EXTENDED SELECT * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx1,idx2 idx2 4 NULL 2 100.00 Using index condition; Using where +Warnings: +Note 1003 select `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`test`.`t1`.`f3` AS `f3` from `test`.`t1` where `test`.`t1`.`f2` <= 3 and 3 <= `test`.`t1`.`f3` +# Turn on MRR. MRR should be used. +EXPLAIN EXTENDED SELECT /*+ MRR(t1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx1,idx2 idx2 4 NULL 2 100.00 Using index condition; Using where; Rowid-ordered scan +Warnings: +Note 1003 select /*+ MRR(`t1`@`select#1`) */ `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`test`.`t1`.`f3` AS `f3` from `test`.`t1` where `test`.`t1`.`f2` <= 3 and 3 <= `test`.`t1`.`f3` +# Turn on MRR. MRR should be used. +EXPLAIN EXTENDED SELECT /*+ MRR(t1 IDX2) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx1,idx2 idx2 4 NULL 2 100.00 Using index condition; Using where; Rowid-ordered scan +Warnings: +Note 1003 select /*+ MRR(`t1`@`select#1` `IDX2`) */ `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`test`.`t1`.`f3` AS `f3` from `test`.`t1` where `test`.`t1`.`f2` <= 3 and 3 <= `test`.`t1`.`f3` +# Turn on MRR for unused key. MRR should not be used. +EXPLAIN EXTENDED SELECT /*+ MRR(t1 idx1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx1,idx2 idx2 4 NULL 2 100.00 Using index condition; Using where +Warnings: +Note 1003 select /*+ MRR(`t1`@`select#1` `idx1`) */ `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`test`.`t1`.`f3` AS `f3` from `test`.`t1` where `test`.`t1`.`f2` <= 3 and 3 <= `test`.`t1`.`f3` +set optimizer_switch='mrr=off,mrr_cost_based=on'; +EXPLAIN EXTENDED SELECT * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx1,idx2 idx2 4 NULL 2 100.00 Using index condition; Using where +Warnings: +Note 1003 select `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`test`.`t1`.`f3` AS `f3` from `test`.`t1` where `test`.`t1`.`f2` <= 3 and 3 <= `test`.`t1`.`f3` +# Turn on MRR. MRR should be used. +EXPLAIN EXTENDED SELECT /*+ MRR(t1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx1,idx2 idx2 4 NULL 2 100.00 Using index condition; Using where; Rowid-ordered scan +Warnings: +Note 1003 select /*+ MRR(`t1`@`select#1`) */ `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`test`.`t1`.`f3` AS `f3` from `test`.`t1` where `test`.`t1`.`f2` <= 3 and 3 <= `test`.`t1`.`f3` +# Turn on MRR. MRR should be used. +EXPLAIN EXTENDED SELECT /*+ MRR(t1 idx2) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx1,idx2 idx2 4 NULL 2 100.00 Using index condition; Using where; Rowid-ordered scan +Warnings: +Note 1003 select /*+ MRR(`t1`@`select#1` `idx2`) */ `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`test`.`t1`.`f3` AS `f3` from `test`.`t1` where `test`.`t1`.`f2` <= 3 and 3 <= `test`.`t1`.`f3` +# Turn on MRR for unused key. MRR should not be used. +EXPLAIN EXTENDED SELECT /*+ MRR(t1 IDX1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx1,idx2 idx2 4 NULL 2 100.00 Using index condition; Using where +Warnings: +Note 1003 select /*+ MRR(`t1`@`select#1` `IDX1`) */ `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`test`.`t1`.`f3` AS `f3` from `test`.`t1` where `test`.`t1`.`f2` <= 3 and 3 <= `test`.`t1`.`f3` +DROP TABLE t1; +set optimizer_switch=default; +# +# Duplicate hints +# +CREATE TABLE t1 (i INT PRIMARY KEY); +SELECT /*+ BKA() BKA() */ 1; +1 +1 +Warnings: +Warning 4197 Hint BKA( ) is ignored as conflicting/duplicated +SELECT /*+ BKA(t1) BKA(t1) */ * FROM t1; +i +Warnings: +Warning 4197 Hint BKA(`t1` ) is ignored as conflicting/duplicated +SELECT /*+ QB_NAME(q1) BKA(t1@q1) BKA(t1@q1) */ * FROM t1; +i +Warnings: +Warning 4197 Hint BKA(`t1`@`q1` ) is ignored as conflicting/duplicated +SELECT /*+ QB_NAME(q1) NO_ICP(@q1 t1 PRIMARY) NO_ICP(@q1 t1 PRIMARY) */ * FROM t1; +i +Warnings: +Warning 4197 Hint NO_ICP(`t1`@`q1` `PRIMARY` ) is ignored as conflicting/duplicated +DROP TABLE t1; +# WL#8016 Parser for optimizer hints +CREATE TABLE t1 (i INT, j INT); +CREATE INDEX i1 ON t1(i); +CREATE INDEX i2 ON t1(j); + +# invalid hint sequences, must issue warnings: + +SELECT /*+*/ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near '*/' at line 1 +SELECT /*+ */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near '*/' at line 1 +SELECT /*+ * ** / // /* */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near '* ** / // /* */ 1' at line 1 +SELECT /*+ @ */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near '@ */ 1' at line 1 +SELECT /*+ @foo */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near '@foo */ 1' at line 1 +SELECT /*+ foo@bar */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near 'foo@bar */ 1' at line 1 +SELECT /*+ foo @bar */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near 'foo @bar */ 1' at line 1 +SELECT /*+ `@` */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near '@` */ 1' at line 1 +SELECT /*+ `@foo` */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near '@foo` */ 1' at line 1 +SELECT /*+ `foo@bar` */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near 'foo@bar` */ 1' at line 1 +SELECT /*+ `foo @bar` */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near 'foo @bar` */ 1' at line 1 +SELECT /*+ BKA( @) */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near ') */ 1' at line 1 +SELECT /*+ BKA( @) */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near ') */ 1' at line 1 +SELECT /*+ BKA(t1 @) */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near '@) */ 1' at line 1 + +# We don't support "*/" inside quoted identifiers (syntax error): + +SELECT /*+ BKA(`test*/`) */ 1; +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near '`) */ 1' at line 1 + +# invalid hint sequences, must issue warnings: + +SELECT /*+ NO_ICP() */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near ') */ 1' at line 1 +SELECT /*+NO_ICP()*/ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near ')*/ 1' at line 1 +SELECT /*+ NO_ICP () */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near ') */ 1' at line 1 +SELECT /*+ NO_ICP ( ) */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near ') */ 1' at line 1 +SELECT /*+ NO_ICP() */ 1 UNION SELECT 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near ') */ 1 UNION SELECT 1' at line 1 +(SELECT /*+ NO_ICP() */ 1) UNION (SELECT 1); +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near ') */ 1) UNION (SELECT 1)' at line 1 +# OLEGS: this one does not issue a warning although should: +((SELECT /* + NO_ICP() */ 1)); +1 +1 +UPDATE /*+ NO_ICP() */ t1 SET i = 10; +Warnings: +Warning 1064 Optimizer hint syntax error near ') */ t1 SET i = 10' at line 1 +INSERT /*+ NO_ICP() */ INTO t1 VALUES (); +Warnings: +Warning 1064 Optimizer hint syntax error near ') */ INTO t1 VALUES ()' at line 1 +DELETE /*+ NO_ICP() */ FROM t1 WHERE 1; +Warnings: +Warning 1064 Optimizer hint syntax error near ') */ FROM t1 WHERE 1' at line 1 +SELECT /*+ BKA(a b) */ 1 FROM t1 a, t1 b; +1 +Warnings: +Warning 1064 Optimizer hint syntax error near 'b) */ 1 FROM t1 a, t1 b' at line 1 +SELECT /*+ NO_ICP(i1) */ 1 FROM t1; +1 +Warnings: +Warning 4199 Unresolved name `i1`@`select#1` for NO_ICP hint +SELECT /*+ NO_ICP(i1 i2) */ 1 FROM t1; +1 +Warnings: +Warning 4199 Unresolved name `i1`@`select#1` `i2` for NO_ICP hint +SELECT /*+ NO_ICP(@qb ident) */ 1 FROM t1; +1 +Warnings: +Warning 4198 Query block name `qb` is not found for NO_ICP hint + +# valid hint sequences, no warnings expected: + +SELECT /*+ BKA(t1) */ 1 FROM t1; +1 +EXPLAIN EXTENDED SELECT /*+ QB_NAME(qb1) */ 1 UNION SELECT /*+ QB_NAME(qb2) */ 1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select /*+ QB_NAME(`qb1`) */ 1 AS `1` union /* select#2 */ select 1 AS `1` +EXPLAIN EXTENDED (SELECT /*+ QB_NAME(qb1) */ 1) UNION (SELECT /*+ QB_NAME(qb2) */ 1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 (/* select#1 */ select /*+ QB_NAME(`qb1`) */ 1 AS `1`) union (/* select#2 */ select /*+ QB_NAME(`qb2`) */ 1 AS `1`) +# +# test explainable statements for hint support: +# they should warn with a hint syntax error near "test */" +# +EXPLAIN EXTENDED SELECT /*+ test */ 1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL No tables used +Warnings: +Warning 1064 Optimizer hint syntax error near 'test */ 1' at line 1 +Note 1003 select 1 AS `1` +EXPLAIN EXTENDED INSERT /*+ test */ INTO t1 VALUES (10, 10); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 INSERT t1 ALL NULL NULL NULL NULL NULL 100.00 NULL +Warnings: +Warning 1064 Optimizer hint syntax error near 'test */ INTO t1 VALUES (10, 10)' at line 1 +Note 1003 insert into `test`.`t1` values (10,10) +EXPLAIN EXTENDED UPDATE /*+ test */ t1 SET i = 10 WHERE j = 10; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +Warnings: +Warning 1064 Optimizer hint syntax error near 'test */ t1 SET i = 10 WHERE j = 10' at line 1 +Note 1003 update `test`.`t1` set `test`.`t1`.`i` = 10 where `test`.`t1`.`j` = 10 +EXPLAIN EXTENDED DELETE /*+ test */ FROM t1 WHERE i = 10; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +Warnings: +Warning 1064 Optimizer hint syntax error near 'test */ FROM t1 WHERE i = 10' at line 1 +Note 1003 delete from `test`.`t1` using dual where `test`.`t1`.`i` = 10 + +# non-alphabetic and non-ASCII identifiers, should warn: + +CREATE INDEX 3rd_index ON t1(i, j); +SELECT /*+ NO_ICP(3rd_index) */ 1 FROM t1; +1 +Warnings: +Warning 4199 Unresolved name `3rd_index`@`select#1` for NO_ICP hint +CREATE INDEX $index ON t1(j, i); +SELECT /*+ NO_ICP($index) */ 1 FROM t1; +1 +Warnings: +Warning 4199 Unresolved name `$index`@`select#1` for NO_ICP hint +CREATE TABLE ` quoted name test` (i INT); +SELECT /*+ BKA(` quoted name test`) */ 1 FROM t1; +1 +Warnings: +Warning 4199 Unresolved name ` quoted name test`@`select#1` for BKA hint +SELECT /*+ BKA(` quoted name test`@`select#1`) */ 1 FROM t1; +1 +Warnings: +Warning 4198 Query block name `select#1` is not found for BKA hint +DROP TABLE ` quoted name test`; +SET SQL_MODE = 'ANSI_QUOTES'; +CREATE TABLE " quoted name test" (i INT); +SELECT /*+ BKA(" quoted name test") */ 1 FROM t1; +1 +Warnings: +Warning 4199 Unresolved name " quoted name test"@"select#1" for BKA hint +SELECT /*+ BKA(" quoted name test"@"select#1") */ 1 FROM t1; +1 +Warnings: +Warning 4198 Query block name "select#1" is not found for BKA hint +CREATE TABLE `test1``test2``` (i INT); +SELECT /*+ BKA(`test1``test2```) */ 1; +1 +1 +Warnings: +Warning 4199 Unresolved name "test1`test2`"@"select#1" for BKA hint +SELECT /*+ BKA("test1""test2""") */ 1; +1 +1 +Warnings: +Warning 4199 Unresolved name "test1""test2"""@"select#1" for BKA hint +SET SQL_MODE = ''; +# should warn: +SELECT /*+ BKA(" quoted name test") */ 1 FROM t1; +1 +Warnings: +Warning 1064 Optimizer hint syntax error near '" quoted name test") */ 1 FROM t1' at line 1 +DROP TABLE ` quoted name test`; +DROP TABLE `test1``test2```; +# Valid hints, no warning: +EXPLAIN EXTENDED SELECT /*+ QB_NAME(`*`) */ 1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL No tables used +Warnings: +Note 1003 select /*+ QB_NAME(`*`) */ 1 AS `1` +EXPLAIN EXTENDED SELECT /*+ QB_NAME(`a*`) */ 1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL No tables used +Warnings: +Note 1003 select /*+ QB_NAME(`a*`) */ 1 AS `1` +EXPLAIN EXTENDED SELECT /*+ QB_NAME(`*b`) */ 1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL No tables used +Warnings: +Note 1003 select /*+ QB_NAME(`*b`) */ 1 AS `1` +EXPLAIN EXTENDED SELECT /*+ QB_NAME(`a +b`) */ 1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL No tables used +Warnings: +Note 1003 select /*+ QB_NAME(`a +b`) */ 1 AS `1` +# hint syntax error: empty quoted identifier +EXPLAIN EXTENDED SELECT /*+ QB_NAME(``) */ 1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL No tables used +Warnings: +Warning 1064 Optimizer hint syntax error near '`) */ 1' at line 1 +Note 1003 select 1 AS `1` +SET NAMES utf8; +EXPLAIN EXTENDED SELECT /*+ QB_NAME(`\BF``\BF`) */ 1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL No tables used +Warnings: +Note 1003 select /*+ QB_NAME(`\BF``\BF`) */ 1 AS `1` +CREATE TABLE tableТ (i INT); +# invalid hints, should warn: +SELECT /*+ BKA(tableТ) */ 1 FROM t1; +1 +Warnings: +Warning 4199 Unresolved name `tableТ`@`select#1` for BKA hint +SELECT /*+ BKA(test@tableТ) */ 1 FROM t1; +1 +Warnings: +Warning 4198 Query block name `tableТ` is not found for BKA hint +DROP TABLE tableТ; +CREATE TABLE таблица (i INT); +SELECT /*+ BKA(`таблица`) */ 1 FROM t1; +1 +Warnings: +Warning 4199 Unresolved name `таблица`@`select#1` for BKA hint +SELECT /*+ BKA(таблица) */ 1 FROM t1; +1 +Warnings: +Warning 4199 Unresolved name `таблица`@`select#1` for BKA hint +SELECT /*+ BKA(test@таблица) */ 1 FROM t1; +1 +Warnings: +Warning 4198 Query block name `таблица` is not found for BKA hint +SELECT /*+ NO_ICP(`\D1`) */ 1 FROM t1; +1 +Warnings: +Warning 4199 Unresolved name `\D1`@`select#1` for NO_ICP hint +DROP TABLE таблица; + +# derived tables and other subqueries: + +SELECT * FROM (SELECT /*+ DEBUG_HINT3 */ 1) a; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near 'DEBUG_HINT3 */ 1) a' at line 1 +SELECT (SELECT /*+ DEBUG_HINT3 */ 1); +(SELECT /*+ DEBUG_HINT3 */ 1) +1 +Warnings: +Warning 1064 Optimizer hint syntax error near 'DEBUG_HINT3 */ 1)' at line 1 +SELECT 1 FROM DUAL WHERE 1 IN (SELECT /*+ DEBUG_HINT3 */ 1); +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near 'DEBUG_HINT3 */ 1)' at line 1 + +# invalid hint sequences (should warn): + +SELECT /*+ 10 */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near '10 */ 1' at line 1 +SELECT /*+ NO_ICP() */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near ') */ 1' at line 1 +SELECT /*+ NO_ICP(10) */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near '10) */ 1' at line 1 +SELECT /*+ NO_ICP( */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near '*/' at line 1 +SELECT /*+ NO_ICP) */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near ') */ 1' at line 1 +SELECT /*+ NO_ICP(t1 */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near '*/' at line 1 +SELECT /*+ NO_ICP(t1 ( */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near '( */ 1' at line 1 +(SELECT 1) UNION (SELECT /*+ NO_ICP() */ 1); +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near ') */ 1)' at line 1 +INSERT INTO t1 VALUES (1, 1), (2, 2); + +# wrong place for hint, so recognize that stuff as a regular commentary: + +SELECT 1 FROM /*+ regular commentary, not a hint! */ t1; +1 +1 +1 +SELECT 1 FROM /*+ #1 */ t1 WHERE /*+ #2 */ 1 /*+ #3 */; +1 +1 +1 +# Warnings expected: +SELECT /*+ NO_ICP() */ 1 +FROM /*+ regular commentary, not a hint! */ t1; +1 +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near ') */ 1 +FROM /*+ regular commentary, not a hint! */ t1' at line 1 +SELECT /*+ NO_ICP(t1) bad_hint */ 1 FROM t1; +1 +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near 'bad_hint */ 1 FROM t1' at line 1 +SELECT /*+ +NO_ICP(@qb ident) +*/ 1 FROM t1; +1 +1 +1 +Warnings: +Warning 4198 Query block name `qb` is not found for NO_ICP hint +SELECT /*+ +? bad syntax +*/ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near '? bad syntax +*/ 1' at line 2 +SELECT +/*+ ? bad syntax */ 1; +1 +1 +Warnings: +Warning 1064 Optimizer hint syntax error near '? bad syntax */ 1' at line 2 +DROP TABLE t1; +set optimizer_switch=default; diff --git a/mysql-test/main/opt_hints.test b/mysql-test/main/opt_hints.test new file mode 100644 index 00000000000..437b8dbbb17 --- /dev/null +++ b/mysql-test/main/opt_hints.test @@ -0,0 +1,619 @@ +--echo # WL#8017 Infrastructure for Optimizer Hints +--enable_prepare_warnings + +CREATE TABLE t1(f1 INT, f2 INT); +INSERT INTO t1 VALUES +(1,1),(2,2),(3,3); + +CREATE TABLE t2(f1 INT NOT NULL, f2 INT NOT NULL, f3 CHAR(200), KEY(f1, f2)); +INSERT INTO t2 VALUES +(1,1, 'qwerty'),(1,2, 'qwerty'),(1,3, 'qwerty'), +(2,1, 'qwerty'),(2,2, 'qwerty'),(2,3, 'qwerty'), (2,4, 'qwerty'),(2,5, 'qwerty'), +(3,1, 'qwerty'),(3,4, 'qwerty'), +(4,1, 'qwerty'),(4,2, 'qwerty'),(4,3, 'qwerty'), (4,4, 'qwerty'), +(1,1, 'qwerty'),(1,2, 'qwerty'),(1,3, 'qwerty'), +(2,1, 'qwerty'),(2,2, 'qwerty'),(2,3, 'qwerty'), (2,4, 'qwerty'),(2,5, 'qwerty'), +(3,1, 'qwerty'),(3,4, 'qwerty'), +(4,1, 'qwerty'),(4,2, 'qwerty'),(4,3, 'qwerty'), (4,4, 'qwerty'); + +CREATE TABLE t3 (f1 INT NOT NULL, f2 INT, f3 VARCHAR(32), + PRIMARY KEY(f1), KEY f2_idx(f1), KEY f3_idx(f3)); +INSERT INTO t3 VALUES +(1, 1, 'qwerty'), (2, 1, 'ytrewq'), +(3, 2, 'uiop'), (4, 2, 'poiu'), (5, 2, 'lkjh'), +(6, 2, 'uiop'), (7, 2, 'poiu'), (8, 2, 'lkjh'), +(9, 2, 'uiop'), (10, 2, 'poiu'), (11, 2, 'lkjh'), +(12, 2, 'uiop'), (13, 2, 'poiu'), (14, 2, 'lkjh'); +INSERT INTO t3 SELECT f1 + 20, f2, f3 FROM t3; +INSERT INTO t3 SELECT f1 + 40, f2, f3 FROM t3; + +ANALYZE TABLE t1; +ANALYZE TABLE t2; +ANALYZE TABLE t3; + + +--echo # NO_RANGE_OPTIMIZATION hint testing +set optimizer_switch=default; + +--disable_ps2_protocol +--echo # Check statistics with no hint +FLUSH STATUS; +SELECT f1 FROM t3 WHERE f1 > 30 AND f1 < 33; +SHOW STATUS LIKE 'handler_read%'; + +--echo # Check statistics with hint +FLUSH STATUS; +SELECT /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY, f2_idx) */ f1 FROM t3 WHERE f1 > 30 AND f1 < 33; +SHOW STATUS LIKE 'handler_read%'; +--enable_ps2_protocol + +EXPLAIN EXTENDED SELECT f1 FROM t3 WHERE f1 > 30 AND f1 < 33; +--echo # Turn off range access for PRIMARY key +--echo # Should use range access by f2_idx key +EXPLAIN EXTENDED SELECT /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY) */ f1 FROM t3 WHERE f1 > 30 AND f1 < 33; +--echo # Turn off range access for PRIMARY & f2_idx keys +--echo # Should use index access +EXPLAIN EXTENDED SELECT /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY, f2_idx) */ f1 FROM t3 WHERE f1 > 30 AND f1 < 33; +--echo # Turn off range access for all keys +--echo # Should use index access +EXPLAIN EXTENDED SELECT /*+ NO_RANGE_OPTIMIZATION(t3) */ f1 FROM t3 WHERE f1 > 30 AND f1 < 33; +--echo # Turn off range access for PRIMARY & f2_idx keys +--echo # Should use index access +EXPLAIN EXTENDED SELECT /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY) NO_RANGE_OPTIMIZATION(t3 f2_idx) */ f1 FROM t3 WHERE f1 > 30 AND f1 < 33; + +--echo # NO_ICP hint testing +set optimizer_switch='index_condition_pushdown=on'; + +CREATE TABLE t4 (x INT, y INT, KEY x_idx(x), KEY y_idx(y)); +INSERT INTO t4 (x) VALUES (1),(2),(3),(4),(5),(6),(7),(8),(9),(10),(11),(12),(13); +UPDATE t4 SET y=x; + +EXPLAIN EXTENDED SELECT * FROM + (SELECT t4.x, t5.y FROM t4, t4 t5 WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0) AS TD; + +EXPLAIN EXTENDED SELECT * FROM + (SELECT /*+ NO_ICP(t5 x_idx, y_idx) */ t4.x, t5.y FROM t4, t4 t5 + WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0) AS TD; + +EXPLAIN EXTENDED SELECT /*+ NO_ICP(t5@qb1 x_idx) */ * FROM + (SELECT /*+ QB_NAME(QB1) */ t4.x, t5.y FROM t4, t4 t5 + WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0) AS TD; + +--echo # Expected warning for z_idx key, unresolved name. +EXPLAIN EXTENDED SELECT * FROM + (SELECT /*+ NO_ICP(t5 y_idx, x_idx, z_idx) */ t4.x, t5.y FROM t4, t4 t5 + WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0) AS TD; + +--echo # ICP should still be used +EXPLAIN EXTENDED SELECT * FROM + (SELECT /*+ NO_ICP(t5 y_idx) */ t4.x, t5.y FROM t4, t4 t5 + WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0) AS TD; + +--echo # BKA & NO_BKA hint testing +set optimizer_switch=default; +set optimizer_switch='mrr=on,mrr_cost_based=off'; +set join_cache_level=6; + +CREATE TABLE t10(a INT); +INSERT INTO t10 VALUES (0),(1),(2),(3),(4),(5),(6),(7),(8),(9); +CREATE TABLE t11(a INT); +INSERT INTO t11 SELECT A.a + B.a* 10 + C.a * 100 from t10 A, t10 B, t10 C; +CREATE TABLE t12(a INT, b INT); +INSERT INTO t12 SELECT a,a from t10; +CREATE TABLE t13(a INT, b INT, c INT, filler CHAR(100), key (a,b)); +INSERT INTO t13 select a,a,a, 'filler-data' FROM t11; + +--echo # Make sure BKA is expected to be used when there are no hints +EXPLAIN +SELECT * FROM t12, t13 WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); + +--echo # Disable BKA +set optimizer_switch='join_cache_bka=off'; +EXPLAIN EXTENDED +SELECT * FROM t12, t13 WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); + +--disable_ps2_protocol +--echo # Check statistics without hint +FLUSH STATUS; +SELECT * FROM t12, t13 WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +SHOW STATUS LIKE 'handler_read%'; + +--echo # Check statistics with hint +FLUSH STATUS; +SELECT /*+ BKA() */ * FROM t12, t13 WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +SHOW STATUS LIKE 'handler_read%'; +--enable_ps2_protocol + +EXPLAIN EXTENDED SELECT /*+ BKA(t13) */ * FROM t12, t13 + WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); + +EXPLAIN EXTENDED SELECT /*+ BKA() */ * FROM t12, t13 + WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); + +EXPLAIN EXTENDED SELECT /*+ BKA(t12, t13) */ * FROM t12, t13 + WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); + +EXPLAIN EXTENDED SELECT /*+ BKA(t12) */ * FROM t12, t13 + WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); + +EXPLAIN EXTENDED SELECT /*+ QB_NAME(QB1) BKA(t13@QB1) */ * FROM t12, t13 + WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); + +--echo # Enable BKA +set optimizer_switch='join_cache_bka=on'; + +EXPLAIN EXTENDED SELECT /*+ NO_BKA(t13) */ * FROM t12, t13 + WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); + +EXPLAIN EXTENDED SELECT /*+ NO_BKA() */ * FROM t12, t13 + WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); + +EXPLAIN EXTENDED SELECT /*+ NO_BKA(t12, t13) */ * FROM t12, t13 + WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); + +EXPLAIN EXTENDED SELECT /*+ NO_BKA(t12) */ * FROM t12, t13 + WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); + +EXPLAIN EXTENDED SELECT /*+ QB_NAME(QB1) NO_BKA(t13@QB1) */ * FROM t12, t13 + WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); + +--echo # UPDATE|DELETE|INSERT hint testing +EXPLAIN EXTENDED UPDATE t3 +SET f3 = 'mnbv' WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN + (SELECT t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND + t2.f2 BETWEEN t1.f1 AND t1.f2 AND t2.f2 + 1 >= t1.f1 + 1); + +--echo # Turn off range access for PRIMARY key. +--echo # Range access should be used for f2_idx key. +EXPLAIN EXTENDED UPDATE /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY) */ t3 +SET f3 = 'mnbv' WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN + (SELECT /*+ BKA(t2) NO_BNL(t1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND + t2.f2 BETWEEN t1.f1 AND t1.f2 AND t2.f2 + 1 >= t1.f1 + 1); + +--echo # Turn off range access for all keys. +EXPLAIN EXTENDED UPDATE /*+ NO_RANGE_OPTIMIZATION(t3) */ t3 +SET f3 = 'mnbv' WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN + (SELECT t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND + t2.f2 BETWEEN t1.f1 AND t1.f2 AND t2.f2 + 1 >= t1.f1 + 1); + +EXPLAIN EXTENDED DELETE FROM t3 +WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN + (SELECT /*+ QB_NAME(qb1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND + t2.f2 BETWEEN t1.f1 AND t1.f2 AND t2.f2 + 1 >= t1.f1 + 1); + +--echo # Turn off range access. Range access should not be used. +EXPLAIN EXTENDED +DELETE /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY, f2_idx) NO_BNL(t1@QB1) */ FROM t3 +WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN + (SELECT /*+ QB_NAME(qb1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND + t2.f2 BETWEEN t1.f1 AND t1.f2 AND t2.f2 + 1 >= t1.f1 + 1); + +--echo # Make sure ICP is expected to be used when there are no hints +EXPLAIN EXTENDED INSERT INTO t3(f1, f2, f3) + (SELECT t4.x, t5.y, 'filler' FROM t4, t4 t5 WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0); + +--echo # Turn off ICP. ICP should not be used. +EXPLAIN EXTENDED INSERT INTO t3(f1, f2, f3) + (SELECT /*+ NO_ICP(t5) */t4.x, t5.y, 'filler' FROM t4, t4 t5 + WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0); + +--echo # Turn off ICP for a particular table +EXPLAIN EXTENDED INSERT /*+ NO_ICP(t5@QB1) */ INTO t3(f1, f2, f3) + (SELECT /*+ QB_NAME(qb1) */ t4.x, t5.y, 'filler' FROM t4, t4 t5 + WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0); + +--echo # Turn off ICP for a particular table and a key +EXPLAIN EXTENDED INSERT /*+ NO_ICP(t5@QB1 x_idx) */ INTO t3(f1, f2, f3) + (SELECT /*+ QB_NAME(qb1) */ t4.x, t5.y, 'filler' FROM t4, t4 t5 + WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0); + +--echo # Misc tests + +--echo # Should issue warning +EXPLAIN EXTENDED SELECT /*+ QB_NAME(qb1) QB_NAME(qb1 ) */ * FROM t2; +--echo # Should issue warning +EXPLAIN EXTENDED SELECT /*+ BKA(@qb1) QB_NAME(qb1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 +WHERE t1.f1=t2.f1 AND t2.f2 BETWEEN t1.f1 and t1.f2 and t2.f2 + 1 >= t1.f1 + 1; + +--echo # Should not crash +PREPARE stmt1 FROM "SELECT /*+ BKA(t2) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 +WHERE t1.f1=t2.f1 AND t2.f2 BETWEEN t1.f1 and t1.f2 and t2.f2 + 1 >= t1.f1 + 1"; +EXECUTE stmt1; +EXECUTE stmt1; +DEALLOCATE PREPARE stmt1; + +--echo # Check use of alias +set optimizer_switch='join_cache_bka=off'; +EXPLAIN EXTENDED +SELECT * FROM t12, t13 WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); + +--echo # Turn on BKA for multiple tables. BKA should be used for tbl13. +EXPLAIN EXTENDED SELECT /*+ BKA(tbl12, tbl13) */ * FROM t12 tbl12, t13 tbl13 +WHERE tbl12.a=tbl13.a AND (tbl13.b+1 <= tbl13.b+1); + +--echo # Print warnings for nonexistent names +EXPLAIN EXTENDED +SELECT /*+ BKA(t2) NO_BNL(t1) BKA(t3) NO_RANGE_OPTIMIZATION(t3 idx1) NO_RANGE_OPTIMIZATION(t3) */ +t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND +t2.f2 BETWEEN t1.f1 AND t1.f2 AND t2.f2 + 1 >= t1.f1 + 1; + +--echo # Check illegal syntax +EXPLAIN EXTENDED SELECT /*+ BKA(qb1 t3@qb1) */ f2 FROM + (SELECT /*+ QB_NAME(qb1) */ f2, f3, f1 FROM t3 WHERE f1 > 2 AND f3 = 'poiu') AS TD + WHERE TD.f1 > 2 AND TD.f3 = 'poiu'; + +--echo # Check illegal syntax +EXPLAIN EXTENDED SELECT * FROM + (SELECT /*+ QB_NAME(qb1) BKA(@qb1 t1@qb1, t2@qb1, t3) */ t2.f1, t2.f2, t2.f3 FROM t1,t2,t3) tt; + +--echo # Check '@qb_name table_name' syntax +EXPLAIN EXTENDED SELECT /*+ BKA(@qb1 t13) */ * FROM (SELECT /*+ QB_NAME(QB1) */ t12.a, t13.b FROM t12, t13 +WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1)) AS s1; + +--echo # Check that original table name is not recognized if alias is used. +EXPLAIN EXTENDED SELECT /*+ BKA(tbl2) */ * FROM t12 tbl12, t13 tbl13 +WHERE tbl12.a=tbl13.a AND (tbl13.b+1 <= tbl13.b+1); + +--disable_ps2_protocol +--echo # Check that PS and conventional statements give the same result. +FLUSH STATUS; +SELECT /*+ BKA(t13) */ * FROM t12, t13 WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1); +SHOW STATUS LIKE 'handler_read%'; +--enable_ps2_protocol + +PREPARE stmt1 FROM "SELECT /*+ BKA(t13) */ * FROM t12, t13 WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1)"; +FLUSH STATUS; +EXECUTE stmt1; +SHOW STATUS LIKE 'handler_read%'; + +FLUSH STATUS; +EXECUTE stmt1; +SHOW STATUS LIKE 'handler_read%'; + +DEALLOCATE PREPARE stmt1; + +DROP TABLE t1, t2, t3, t10, t11, t12, t13; + +--echo # BNL & NO_BNL hint testing + +set optimizer_switch=default; + +CREATE TABLE t1 (a INT, b INT); +INSERT INTO t1 VALUES (1,1),(2,2); +CREATE TABLE t2 (a INT, b INT); +INSERT INTO t2 VALUES (1,1),(2,2); +CREATE TABLE t3 (a INT, b INT); +INSERT INTO t3 VALUES (1,1),(2,2); + +--disable_ps2_protocol +--echo # Check statistics without hint +FLUSH STATUS; +SELECT t1.* FROM t1,t2,t3; +SHOW STATUS LIKE 'handler_read%'; + +--echo # Check statistics with hint +FLUSH STATUS; +SELECT /*+ NO_BNL() */t1.* FROM t1,t2,t3; +SHOW STATUS LIKE 'handler_read%'; +--enable_ps2_protocol + +EXPLAIN EXTENDED SELECT t1.* FROM t1,t2,t3; +EXPLAIN EXTENDED SELECT /*+ NO_BNL() */t1.* FROM t1,t2,t3; +EXPLAIN EXTENDED SELECT /*+ NO_BNL(t2, t3) */t1.* FROM t1,t2,t3; +EXPLAIN EXTENDED SELECT /*+ NO_BNL(t1, t3) */t1.* FROM t1,t2,t3; + +--echo # MariaDB does not have optimizer_switch='block_nested_loop=off' +--echo # as MySQL does, so in fact we cannot disable BNL join. The cases below +--echo # test the BNL() hint, although it does not affect the execution plan +EXPLAIN EXTENDED SELECT t1.* FROM t1,t2,t3; +EXPLAIN EXTENDED SELECT /*+ BNL() */t1.* FROM t1,t2,t3; +EXPLAIN EXTENDED SELECT /*+ BNL(t2, t3) */t1.* FROM t1,t2,t3; +EXPLAIN EXTENDED SELECT /*+ BNL(t1, t3) */t1.* FROM t1,t2,t3; +EXPLAIN EXTENDED SELECT /*+ BNL(t2) BNL(t3) */t1.* FROM t1,t2,t3; + +DROP TABLE t1, t2, t3; + +--echo # BNL in subquery +set optimizer_switch = DEFAULT; +CREATE TABLE t1 (a INT, b INT, PRIMARY KEY (a)); +CREATE TABLE t2 (a INT); +CREATE TABLE t3 (a INT, b INT, INDEX a (a,b)); +INSERT INTO t1 VALUES (1,10), (2,20), (3,30), (4,40); +INSERT INTO t2 VALUES (2), (3), (4), (5); +INSERT INTO t3 VALUES (10,3), (20,4), (30,5); +ANALYZE TABLE t1, t2, t3; + +EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) */ * FROM t1 JOIN t2 ON t1.b = t2.a WHERE +t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); + +EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL() */ * FROM t1 JOIN t2 ON t1.b = t2.a WHERE +t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); + +EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL(t1, t2) */ * FROM t1 JOIN t2 ON t1.b = t2.a WHERE +t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); + +EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL(@subq1) */ * FROM t1 JOIN t2 ON t1.b = t2.a WHERE +t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); + +EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL(t4@subq1) */ * FROM t1 JOIN t2 ON t1.b = t2.a WHERE +t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); + +EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL(t3@subq1,t4@subq1) */ * FROM t1 JOIN t2 ON t1.b = t2.a WHERE +t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); + +EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL(@subq1 t3, t4) */ * FROM t1 JOIN t2 ON t1.b = t2.a WHERE +t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); + +EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) */ * FROM t1 JOIN t2 ON t1.b = t2.a WHERE +t2.a IN (SELECT /*+ QB_NAME(subq1) NO_BNL(t3, t4) */ t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); + +DROP TABLE t1, t2, t3, t4; + +--echo # MRR & NO_MRR hint testing +set optimizer_switch=default; + +CREATE TABLE t1 +( + f1 int NOT NULL DEFAULT '0', + f2 int NOT NULL DEFAULT '0', + f3 int NOT NULL DEFAULT '0', + INDEX idx1(f2, f3), INDEX idx2(f3) +); + +INSERT INTO t1(f1) VALUES (1), (2), (3), (4), (5), (6), (7), (8); +INSERT INTO t1(f2, f3) VALUES (3,4), (3,4); +ANALYZE TABLE t1; + +set optimizer_switch='mrr=on,mrr_cost_based=off'; + +--disable_ps2_protocol +--echo # Check statistics without hint +FLUSH STATUS; +SELECT * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +SHOW STATUS LIKE 'handler_read%'; + +--echo # Check statistics with hint +FLUSH STATUS; +SELECT /*+ NO_MRR(t1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +SHOW STATUS LIKE 'handler_read%'; + +--echo # Make sure hints are preserved in a stored procedure body +CREATE PROCEDURE p() SELECT /*+ NO_MRR(t1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +SHOW CREATE PROCEDURE p; +FLUSH STATUS; +CALL p(); +SHOW STATUS LIKE 'handler_read%'; + +DROP PROCEDURE p; +--enable_ps2_protocol + +EXPLAIN EXTENDED SELECT * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +--echo # Turn off MRR. MRR should not be used. +EXPLAIN EXTENDED SELECT /*+ NO_MRR(t1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +--echo # Turn off MRR. MRR should not be used. +EXPLAIN EXTENDED SELECT /*+ NO_MRR(t1 idx2) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +--echo # Turn off MRR for unused key. MRR should be used. +EXPLAIN EXTENDED SELECT /*+ NO_MRR(t1 idx1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; + +set optimizer_switch='mrr=off,mrr_cost_based=off'; + +EXPLAIN EXTENDED SELECT * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +--echo # Turn on MRR. MRR should be used. +EXPLAIN EXTENDED SELECT /*+ MRR(t1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +--echo # Turn on MRR. MRR should be used. +EXPLAIN EXTENDED SELECT /*+ MRR(t1 IDX2) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +--echo # Turn on MRR for unused key. MRR should not be used. +EXPLAIN EXTENDED SELECT /*+ MRR(t1 idx1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; + +set optimizer_switch='mrr=off,mrr_cost_based=on'; + +EXPLAIN EXTENDED SELECT * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +--echo # Turn on MRR. MRR should be used. +EXPLAIN EXTENDED SELECT /*+ MRR(t1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +--echo # Turn on MRR. MRR should be used. +EXPLAIN EXTENDED SELECT /*+ MRR(t1 idx2) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; +--echo # Turn on MRR for unused key. MRR should not be used. +EXPLAIN EXTENDED SELECT /*+ MRR(t1 IDX1) */ * FROM t1 WHERE f2 <= 3 AND 3 <= f3; + +DROP TABLE t1; + +set optimizer_switch=default; + +--echo # +--echo # Duplicate hints +--echo # + +CREATE TABLE t1 (i INT PRIMARY KEY); + +SELECT /*+ BKA() BKA() */ 1; +SELECT /*+ BKA(t1) BKA(t1) */ * FROM t1; +SELECT /*+ QB_NAME(q1) BKA(t1@q1) BKA(t1@q1) */ * FROM t1; +SELECT /*+ QB_NAME(q1) NO_ICP(@q1 t1 PRIMARY) NO_ICP(@q1 t1 PRIMARY) */ * FROM t1; + +DROP TABLE t1; + +--echo # WL#8016 Parser for optimizer hints + + +CREATE TABLE t1 (i INT, j INT); +CREATE INDEX i1 ON t1(i); +CREATE INDEX i2 ON t1(j); + +--echo +--echo # invalid hint sequences, must issue warnings: +--echo +SELECT /*+*/ 1; +SELECT /*+ */ 1; +SELECT /*+ * ** / // /* */ 1; +SELECT /*+ @ */ 1; +SELECT /*+ @foo */ 1; +SELECT /*+ foo@bar */ 1; +SELECT /*+ foo @bar */ 1; +SELECT /*+ `@` */ 1; +SELECT /*+ `@foo` */ 1; +SELECT /*+ `foo@bar` */ 1; +SELECT /*+ `foo @bar` */ 1; +SELECT /*+ BKA( @) */ 1; +SELECT /*+ BKA( @) */ 1; +SELECT /*+ BKA(t1 @) */ 1; + +--echo +--echo # We don't support "*/" inside quoted identifiers (syntax error): +--echo + +--error ER_PARSE_ERROR +SELECT /*+ BKA(`test*/`) */ 1; + +--echo +--echo # invalid hint sequences, must issue warnings: +--echo +SELECT /*+ NO_ICP() */ 1; +SELECT /*+NO_ICP()*/ 1; +SELECT /*+ NO_ICP () */ 1; +SELECT /*+ NO_ICP ( ) */ 1; + +SELECT /*+ NO_ICP() */ 1 UNION SELECT 1; +(SELECT /*+ NO_ICP() */ 1) UNION (SELECT 1); + +--echo # OLEGS: this one does not issue a warning although should: +((SELECT /* + NO_ICP() */ 1)); + +UPDATE /*+ NO_ICP() */ t1 SET i = 10; +INSERT /*+ NO_ICP() */ INTO t1 VALUES (); +DELETE /*+ NO_ICP() */ FROM t1 WHERE 1; + + +SELECT /*+ BKA(a b) */ 1 FROM t1 a, t1 b; + +SELECT /*+ NO_ICP(i1) */ 1 FROM t1; +SELECT /*+ NO_ICP(i1 i2) */ 1 FROM t1; +SELECT /*+ NO_ICP(@qb ident) */ 1 FROM t1; + +--echo +--echo # valid hint sequences, no warnings expected: +--echo +SELECT /*+ BKA(t1) */ 1 FROM t1; +EXPLAIN EXTENDED SELECT /*+ QB_NAME(qb1) */ 1 UNION SELECT /*+ QB_NAME(qb2) */ 1; +EXPLAIN EXTENDED (SELECT /*+ QB_NAME(qb1) */ 1) UNION (SELECT /*+ QB_NAME(qb2) */ 1); + +--echo # +--echo # test explainable statements for hint support: +--echo # they should warn with a hint syntax error near "test */" +--echo # + +EXPLAIN EXTENDED SELECT /*+ test */ 1; +EXPLAIN EXTENDED INSERT /*+ test */ INTO t1 VALUES (10, 10); +EXPLAIN EXTENDED UPDATE /*+ test */ t1 SET i = 10 WHERE j = 10; +EXPLAIN EXTENDED DELETE /*+ test */ FROM t1 WHERE i = 10; + +--echo +--echo # non-alphabetic and non-ASCII identifiers, should warn: +--echo + +CREATE INDEX 3rd_index ON t1(i, j); +SELECT /*+ NO_ICP(3rd_index) */ 1 FROM t1; + +CREATE INDEX $index ON t1(j, i); +SELECT /*+ NO_ICP($index) */ 1 FROM t1; + +CREATE TABLE ` quoted name test` (i INT); +SELECT /*+ BKA(` quoted name test`) */ 1 FROM t1; +SELECT /*+ BKA(` quoted name test`@`select#1`) */ 1 FROM t1; +DROP TABLE ` quoted name test`; + +SET SQL_MODE = 'ANSI_QUOTES'; + +CREATE TABLE " quoted name test" (i INT); +SELECT /*+ BKA(" quoted name test") */ 1 FROM t1; +SELECT /*+ BKA(" quoted name test"@"select#1") */ 1 FROM t1; + +CREATE TABLE `test1``test2``` (i INT); + +SELECT /*+ BKA(`test1``test2```) */ 1; +SELECT /*+ BKA("test1""test2""") */ 1; + +SET SQL_MODE = ''; +--echo # should warn: +SELECT /*+ BKA(" quoted name test") */ 1 FROM t1; + +DROP TABLE ` quoted name test`; +DROP TABLE `test1``test2```; + +--echo # Valid hints, no warning: +EXPLAIN EXTENDED SELECT /*+ QB_NAME(`*`) */ 1; +EXPLAIN EXTENDED SELECT /*+ QB_NAME(`a*`) */ 1; +EXPLAIN EXTENDED SELECT /*+ QB_NAME(`*b`) */ 1; +EXPLAIN EXTENDED SELECT /*+ QB_NAME(`a +b`) */ 1; + +--echo # hint syntax error: empty quoted identifier +EXPLAIN EXTENDED SELECT /*+ QB_NAME(``) */ 1; + +SET NAMES utf8; +EXPLAIN EXTENDED SELECT /*+ QB_NAME(`\BF``\BF`) */ 1; + +CREATE TABLE tableТ (i INT); + +--echo # invalid hints, should warn: +SELECT /*+ BKA(tableТ) */ 1 FROM t1; +SELECT /*+ BKA(test@tableТ) */ 1 FROM t1; +DROP TABLE tableТ; + +CREATE TABLE таблица (i INT); + +SELECT /*+ BKA(`таблица`) */ 1 FROM t1; +SELECT /*+ BKA(таблица) */ 1 FROM t1; +SELECT /*+ BKA(test@таблица) */ 1 FROM t1; + +SELECT /*+ NO_ICP(`\D1`) */ 1 FROM t1; + +DROP TABLE таблица; + +--echo +--echo # derived tables and other subqueries: +--echo + +SELECT * FROM (SELECT /*+ DEBUG_HINT3 */ 1) a; +SELECT (SELECT /*+ DEBUG_HINT3 */ 1); +SELECT 1 FROM DUAL WHERE 1 IN (SELECT /*+ DEBUG_HINT3 */ 1); + +--echo +--echo # invalid hint sequences (should warn): +--echo +SELECT /*+ 10 */ 1; +SELECT /*+ NO_ICP() */ 1; +SELECT /*+ NO_ICP(10) */ 1; +SELECT /*+ NO_ICP( */ 1; +SELECT /*+ NO_ICP) */ 1; +SELECT /*+ NO_ICP(t1 */ 1; +SELECT /*+ NO_ICP(t1 ( */ 1; +(SELECT 1) UNION (SELECT /*+ NO_ICP() */ 1); + +INSERT INTO t1 VALUES (1, 1), (2, 2); + +--echo +--echo # wrong place for hint, so recognize that stuff as a regular commentary: +--echo + +SELECT 1 FROM /*+ regular commentary, not a hint! */ t1; +SELECT 1 FROM /*+ #1 */ t1 WHERE /*+ #2 */ 1 /*+ #3 */; + +--echo # Warnings expected: +SELECT /*+ NO_ICP() */ 1 + FROM /*+ regular commentary, not a hint! */ t1; + +SELECT /*+ NO_ICP(t1) bad_hint */ 1 FROM t1; + +SELECT /*+ + NO_ICP(@qb ident) +*/ 1 FROM t1; + +SELECT /*+ + ? bad syntax +*/ 1; + +SELECT +/*+ ? bad syntax */ 1; + +DROP TABLE t1; +set optimizer_switch=default; diff --git a/sql/CMakeLists.txt b/sql/CMakeLists.txt index 0243bd6e2cc..d1100119276 100644 --- a/sql/CMakeLists.txt +++ b/sql/CMakeLists.txt @@ -193,6 +193,7 @@ SET (SQL_SOURCE socketpair.c socketpair.h opt_vcol_substitution.h opt_vcol_substitution.cc + opt_hints_parser.cc opt_hints_parser.h scan_char.h ${CMAKE_CURRENT_BINARY_DIR}/lex_hash.h ${CMAKE_CURRENT_BINARY_DIR}/lex_token.h ${GEN_SOURCES} diff --git a/sql/lex_ident.h b/sql/lex_ident.h index b281b48f369..19b01b0b066 100644 --- a/sql/lex_ident.h +++ b/sql/lex_ident.h @@ -18,8 +18,11 @@ Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1335 USA */ +#include "my_global.h" +#include "m_ctype.h" #include "char_buffer.h" #include "lex_string.h" +#include "my_sys.h" extern MYSQL_PLUGIN_IMPORT CHARSET_INFO *table_alias_charset; diff --git a/sql/opt_hints_parser.cc b/sql/opt_hints_parser.cc new file mode 100644 index 00000000000..70046ee608f --- /dev/null +++ b/sql/opt_hints_parser.cc @@ -0,0 +1,105 @@ +/* + Copyright (c) 2024, MariaDB + + This program is free software; you can redistribute it and/or + modify it under the terms of the GNU General Public License + as published by the Free Software Foundation; version 2 of + the License. + + This program is distributed in the hope that it will be useful, + but WITHOUT ANY WARRANTY; without even the implied warranty of + MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + GNU General Public License for more details. + + You should have received a copy of the GNU General Public License + along with this program; if not, write to the Free Software + Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1335 USA +*/ + + +#include "opt_hints_parser.h" +#include "sql_error.h" +#include "mysqld_error.h" +#include "sql_class.h" + +// This method is for debug purposes +bool Optimizer_hint_parser::parse_token_list(THD *thd) +{ + for ( ; ; m_look_ahead_token= get_token(m_cs)) + { + char tmp[200]; + my_snprintf(tmp, sizeof(tmp), "TOKEN: %d %.*s", + (int) m_look_ahead_token.id(), + (int) m_look_ahead_token.length, + m_look_ahead_token.str); + push_warning(thd, Sql_condition::WARN_LEVEL_WARN, + ER_UNKNOWN_ERROR, tmp); + if (m_look_ahead_token.id() == TokenID::tNULL || + m_look_ahead_token.id() == TokenID::tEOF) + break; + } + return true; // Success +} + + +void Optimizer_hint_parser::push_warning_syntax_error(THD *thd) +{ + const char *msg= ER_THD(thd, ER_WARN_OPTIMIZER_HINT_SYNTAX_ERROR); + ErrConvString txt(m_look_ahead_token.str, strlen(m_look_ahead_token.str), + thd->variables.character_set_client); + push_warning_printf(thd, Sql_condition::WARN_LEVEL_WARN, + ER_PARSE_ERROR, ER_THD(thd, ER_PARSE_ERROR), + msg, txt.ptr(), 1); +} + + +bool +Optimizer_hint_parser:: + Table_name_list_container::add(Optimizer_hint_parser *p, + Table_name &&elem) +{ + Table_name *pe= (Table_name*) p->m_thd->alloc(sizeof(*pe)); + if (!pe) + return true; + *pe= std::move(elem); + return push_back(pe, p->m_thd->mem_root); +} + + +bool +Optimizer_hint_parser:: + Hint_param_table_list_container::add(Optimizer_hint_parser *p, + Hint_param_table &&elem) +{ + Hint_param_table *pe= (Hint_param_table*) p->m_thd->alloc(sizeof(*pe)); + if (!pe) + return true; + *pe= std::move(elem); + return push_back(pe, p->m_thd->mem_root); +} + + +bool +Optimizer_hint_parser:: + Hint_param_index_list_container::add(Optimizer_hint_parser *p, + Hint_param_index &&elem) +{ + Hint_param_index *pe= (Hint_param_index*) p->m_thd->alloc(sizeof(*pe)); + if (!pe) + return true; + *pe= std::move(elem); + return push_back(pe, p->m_thd->mem_root); +} + + +bool +Optimizer_hint_parser:: + Hint_list_container::add(Optimizer_hint_parser *p, + Hint &&elem) +{ + Hint *pe= (Hint*) p->m_thd->alloc(sizeof(*pe)); + if (!pe) + return true; + *pe= std::move(elem); + return push_back(pe, p->m_thd->mem_root); +} diff --git a/sql/opt_hints_parser.h b/sql/opt_hints_parser.h new file mode 100644 index 00000000000..ca60b96e803 --- /dev/null +++ b/sql/opt_hints_parser.h @@ -0,0 +1,609 @@ +#ifndef OPT_HINTS_PARSER_H +#define OPT_HINTS_PARSER_H +/* + Copyright (c) 2024, MariaDB + + This program is free software; you can redistribute it and/or + modify it under the terms of the GNU General Public License + as published by the Free Software Foundation; version 2 of + the License. + + This program is distributed in the hope that it will be useful, + but WITHOUT ANY WARRANTY; without even the implied warranty of + MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + GNU General Public License for more details. + + You should have received a copy of the GNU General Public License + along with this program; if not, write to the Free Software + Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1335 USA +*/ + + +#include "simple_tokenizer.h" +#include "sql_list.h" +#include "simple_parser.h" + + +class Optimizer_hint_tokenizer: public Extended_string_tokenizer +{ +public: + Optimizer_hint_tokenizer(CHARSET_INFO *cs, const LEX_CSTRING &hint) + :Extended_string_tokenizer(cs, hint) + { } + + // Let's use "enum class" to easier distinguish token IDs vs rule names + enum class TokenID + { + // Special purpose tokens: + tNULL= 0, // returned if the tokenizer failed to detect a token + // also used if the parser failed to parse a token + tEMPTY= 1, // returned on empty optional constructs in a grammar like: + // rule ::= [ rule1 ] + // when rule1 does not present in the input. + tEOF= 2, // returned when the end of input is reached + + // One character tokens + tCOMMA= ',', + tAT= '@', + tLPAREN= '(', + tRPAREN= ')', + + // Keywords + keyword_BKA, + keyword_BNL, + keyword_NO_BKA, + keyword_NO_BNL, + keyword_NO_ICP, + keyword_NO_MRR, + keyword_NO_RANGE_OPTIMIZATION, + keyword_MRR, + keyword_QB_NAME, + + // Other token types + tIDENT + }; + +protected: + + TokenID find_keyword(const LEX_CSTRING &str) + { + switch (str.length) + { + case 3: + if ("BKA"_Lex_ident_column.streq(str)) return TokenID::keyword_BKA; + if ("BNL"_Lex_ident_column.streq(str)) return TokenID::keyword_BNL; + if ("MRR"_Lex_ident_column.streq(str)) return TokenID::keyword_MRR; + break; + + case 6: + if ("NO_BKA"_Lex_ident_column.streq(str)) return TokenID::keyword_NO_BKA; + if ("NO_BNL"_Lex_ident_column.streq(str)) return TokenID::keyword_NO_BNL; + if ("NO_ICP"_Lex_ident_column.streq(str)) return TokenID::keyword_NO_ICP; + if ("NO_MRR"_Lex_ident_column.streq(str)) return TokenID::keyword_NO_MRR; + break; + + case 7: + if ("QB_NAME"_Lex_ident_column.streq(str)) + return TokenID::keyword_QB_NAME; + break; + + case 21: + if ("NO_RANGE_OPTIMIZATION"_Lex_ident_column.streq(str)) + return TokenID::keyword_NO_RANGE_OPTIMIZATION; + break; + } + return TokenID::tIDENT; + } + +public: + + class Token: public Lex_cstring + { + protected: + TokenID m_id; + public: + Token() + :Lex_cstring(), m_id(TokenID::tNULL) + { } + Token(const LEX_CSTRING &str, TokenID id) + :Lex_cstring(str), m_id(id) + { } + TokenID id() const { return m_id; } + static Token empty(const char *pos) + { + return Token(Lex_cstring(pos, pos), TokenID::tEMPTY); + } + operator bool() const + { + return m_id != TokenID::tNULL; + } + }; + + Token get_token(CHARSET_INFO *cs) + { + get_spaces(); + if (eof()) + return Token(Lex_cstring(m_ptr, m_ptr), TokenID::tEOF); + const char head= m_ptr[0]; + if (head == '`' || head=='"') + { + const Token_with_metadata delimited_ident= get_quoted_string(); + if (delimited_ident.length) + return Token(delimited_ident, TokenID::tIDENT); + } + const Token_with_metadata ident= get_ident(); + if (ident.length) + return Token(ident, ident.m_extended_chars ? + TokenID::tIDENT : find_keyword(ident)); + if (!get_char(',')) + return Token(Lex_cstring(m_ptr - 1, 1), TokenID::tCOMMA); + if (!get_char('@')) + return Token(Lex_cstring(m_ptr - 1, 1), TokenID::tAT); + if (!get_char('(')) + return Token(Lex_cstring(m_ptr - 1, 1), TokenID::tLPAREN); + if (!get_char(')')) + return Token(Lex_cstring(m_ptr - 1, 1), TokenID::tRPAREN); + return Token(Lex_cstring(m_ptr, m_ptr), TokenID::tNULL); + } +}; + + +class Optimizer_hint_parser: public Optimizer_hint_tokenizer, + public Parser_templates +{ +private: + Token m_look_ahead_token; + THD *m_thd; + bool m_syntax_error; + bool m_fatal_error; +public: + Optimizer_hint_parser(THD *thd, CHARSET_INFO *cs, const LEX_CSTRING &hint) + :Optimizer_hint_tokenizer(cs, hint), + m_look_ahead_token(get_token(cs)), + m_thd(thd), + m_syntax_error(false), + m_fatal_error(false) + { } + bool set_syntax_error() + { + m_syntax_error= true; + return false; + } + bool set_fatal_error() + { + m_fatal_error= true; + return false; + } + TokenID look_ahead_token_id() const + { + return is_error() ? TokenID::tNULL : m_look_ahead_token.id(); + } + /* + Return an empty token at the position of the current + look ahead token with a zero length. Used for optional grammar constructs. + + For example, if the grammar is "rule ::= ruleA [ruleB] ruleC" + and the input is "A C", then: + - the optional rule "ruleB" will point to the input position "C" + with a zero length + - while the rule "ruleC" will point to the same input position "C" + with a non-zero length + */ + Token empty_token() const + { + return Token::empty(m_look_ahead_token.str); + } + static Token null_token() + { + return Token(); + } + + /* + Return the current look ahead token and scan the next one + */ + Token shift() + { + DBUG_ASSERT(!is_error()); + const Token res= m_look_ahead_token; + m_look_ahead_token= get_token(m_cs); + return res; + } + +public: + /* + Return the current look ahead token if it matches the given ID + and scan the next one. + */ + Token token(TokenID id) + { + if (m_look_ahead_token.id() != id || is_error()) + return Token(); + return shift(); + } + + bool is_error() const + { + return m_syntax_error || m_fatal_error; + } + bool is_syntax_error() const + { + return m_syntax_error; + } + bool is_fatal_error() const + { + return m_fatal_error; + } + + bool parse_token_list(THD *thd); // For debug purposes + + void push_warning_syntax_error(THD *thd); + + +private: + + using PARSER= Optimizer_hint_parser; // for a shorter notation + + // Rules consisting of a single token + + class TokenAT: public TOKEN + { + public: + using TOKEN::TOKEN; + }; + + class TokenEOF: public TOKEN + { + public: + using TOKEN::TOKEN; + }; + + class Keyword_QB_NAME: public TOKEN + { + public: + using TOKEN::TOKEN; + }; + + class Identifier: public TOKEN + { + public: + using TOKEN::TOKEN; + }; + + class LParen: public TOKEN + { + public: + using TOKEN::TOKEN; + }; + + class RParen: public TOKEN + { + public: + using TOKEN::TOKEN; + }; + + + // Rules consisting of multiple choices of tokens + + // table_level_hint_type ::= BKA | BNL | NO_BKA | NO_BNL + class Table_level_hint_type_cond + { + public: + static bool allowed_token_id(TokenID id) + { + return id == TokenID::keyword_BKA || + id == TokenID::keyword_BNL || + id == TokenID::keyword_NO_BKA || + id == TokenID::keyword_NO_BNL; + } + }; + class Table_level_hint_type: public TokenChoice + { + public: + using TokenChoice::TokenChoice; + }; + + + // index_level_hint_type ::= MRR | NO_RANGE_OPTIMIZATION | NO_ICP | NO_MRR + class Index_level_hint_type_cond + { + public: + static bool allowed_token_id(TokenID id) + { + return id == TokenID::keyword_MRR || + id == TokenID::keyword_NO_RANGE_OPTIMIZATION || + id == TokenID::keyword_NO_ICP || + id == TokenID::keyword_NO_MRR; + } + }; + class Index_level_hint_type: public TokenChoice + { + public: + using TokenChoice::TokenChoice; + }; + + + // Identifiers of various kinds + + + // query_block_name ::= identifier + class Query_block_name: public Identifier + { + public: + using Identifier::Identifier; + }; + + // table_name ::= identifier + class Table_name: public Identifier + { + public: + using Identifier::Identifier; + }; + + // hint_param_index ::= identifier + class Hint_param_index: public Identifier + { + public: + using Identifier::Identifier; + }; + + + // More complex rules + + /* + at_query_block_name ::= @ query_block_name + */ + class At_query_block_name: public AND2 + { + public: + using AND2::AND2; + using AND2::operator=; + }; + + /* + opt_qb_name ::= [ @ query_block_name ] + */ + class Opt_qb_name: public OPT + { + public: + using OPT::OPT; + }; + + /* + hint_param_table ::= table_name opt_qb_name + */ + class Hint_param_table: public AND2 + { + public: + using AND2::AND2; + }; + + + /* + hint_param_table_list ::= hint_param_table [ {, hint_param_table}... ] + opt_hint_param_table_list ::= [ hint_param_table_list ] + */ + class Hint_param_table_list_container: public List + { + public: + Hint_param_table_list_container() + { } + bool add(Optimizer_hint_parser *p, Hint_param_table &&table); + size_t count() const { return elements; } + }; + + class Opt_hint_param_table_list: public LIST + { + using LIST::LIST; + }; + + /* + table_name_list ::= table_name [ {, table_name }... ] + opt_table_name_list ::= [ table_name_list ] + */ + class Table_name_list_container: public List + { + public: + Table_name_list_container() + { } + bool add(Optimizer_hint_parser *p, Table_name &&table); + size_t count() const { return elements; } + }; + + class Opt_table_name_list: public LIST + { + public: + using LIST::LIST; + }; + + + /* + hint_param_index_list ::= hint_param_index [ {, hint_param_index }...] + opt_hint_param_index_list ::= [ hint_param_index_list ] + */ + class Hint_param_index_list_container: public List + { + public: + Hint_param_index_list_container() + { } + bool add(Optimizer_hint_parser *p, Hint_param_index &&table); + size_t count() const { return elements; } + }; + + class Opt_hint_param_index_list: public LIST + { + public: + using LIST::LIST; + }; + + + /* + hint_param_table_ext ::= hint_param_table + | @ query_block_name table_name + */ + class At_query_block_name_table_name: public AND2 + { + public: + using AND2::AND2; + }; + + class Hint_param_table_ext_container: public Query_block_name, + public Table_name + { + public: + Hint_param_table_ext_container() + { } + Hint_param_table_ext_container(const Hint_param_table &hint_param_table) + :Query_block_name(hint_param_table), Table_name(hint_param_table) + { } + Hint_param_table_ext_container(const At_query_block_name_table_name &qbt) + :Query_block_name(qbt), Table_name(qbt) + { } + operator bool() const + { + return Query_block_name::operator bool() && Table_name::operator bool(); + } + }; + + class Hint_param_table_ext: public OR2C + { + public: + using OR2C::OR2C; + }; + + + /* + at_query_block_name_opt_table_name_list ::= + @ query_block_name opt_table_name_list + */ + class At_query_block_name_opt_table_name_list: public AND2< + PARSER, + At_query_block_name, + Opt_table_name_list> + { + public: + using AND2::AND2; + }; + + + /* + table_level_hint_body: @ query_block_name opt_table_name_list + | opt_hint_param_table_list + */ + class Table_level_hint_body: public OR2< + PARSER, + At_query_block_name_opt_table_name_list, + Opt_hint_param_table_list> + { + public: + using OR2::OR2; + }; + + + // table_level_hint ::= table_level_hint_type ( table_level_hint_body ) + class Table_level_hint: public AND4 + { + public: + using AND4::AND4; + }; + + + // index_level_hint_body ::= hint_param_table_ext opt_hint_param_index_list + class Index_level_hint_body: public AND2 + { + public: + using AND2::AND2; + }; + + + // index_level_hint ::= index_level_hint_type ( index_level_hint_body ) + class Index_level_hint: public AND4 + { + public: + using AND4::AND4; + }; + + + // qb_name_hint ::= QB_NAME ( query_block_name ) + class Qb_name_hint: public AND4 + { + public: + using AND4::AND4; + }; + + + /* + hint ::= index_level_hint + | table_level_hint + | qb_name_hint + */ + class Hint: public OR3 + { + public: + using OR3::OR3; + }; + + + // hint_list ::= hint [ hint... ] + class Hint_list_container: public List + { + public: + Hint_list_container() + { } + bool add(Optimizer_hint_parser *p, Hint &&hint); + size_t count() const { return elements; } + }; + +public: + + class Hint_list: public LIST + { + public: + using LIST::LIST; + }; + + /* + The main rule: + hints ::= hint_list EOF + */ + class Hints: public AND2 + { + public: + using AND2::AND2; + }; + +}; + +#endif // OPT_HINTS_PARSER diff --git a/sql/scan_char.h b/sql/scan_char.h new file mode 100644 index 00000000000..1aba6e39ce5 --- /dev/null +++ b/sql/scan_char.h @@ -0,0 +1,53 @@ +/* Copyright (c) 2024, MariaDB Corporation. + + This program is free software; you can redistribute it and/or modify + it under the terms of the GNU General Public License as published by + the Free Software Foundation; version 2 of the License. + + This program is distributed in the hope that it will be useful, + but WITHOUT ANY WARRANTY; without even the implied warranty of + MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + GNU General Public License for more details. + + You should have received a copy of the GNU General Public License + along with this program; if not, write to the Free Software + Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1335 USA */ + +#ifndef SCAN_CHAR_H +#define SCAN_CHAR_H + + +/** + A helper class to store the head character of a string, + with help of a charlen() call. +*/ +class Scan_char +{ + const char *m_ptr; // The start of the character + int m_length; // The result: + // >0 - the character octet length + // <=0 - an error (e.g. end of input, wrong byte sequence) +public: + Scan_char(CHARSET_INFO *const cs, const char *str, const char *end) + :m_ptr(str), m_length(cs->charlen(str, end)) + { } + // Compare if two non-erroneous characters are equal + bool eq(const Scan_char &rhs) const + { + DBUG_ASSERT(m_length > 0); + DBUG_ASSERT(rhs.m_length > 0); + return m_length == rhs.m_length && + !memcmp(m_ptr, rhs.m_ptr, (size_t) m_length); + } + // Compare if two possibly erroneous characters are equal + bool eq_safe(const Scan_char &rhs) const + { + return m_length == rhs.m_length && m_length > 0 && + !memcmp(m_ptr, rhs.m_ptr, (size_t) m_length); + } + const char *ptr() const { return m_ptr; } + int length() const { return m_length; } +}; + + +#endif // SCAN_CHAR_H diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index c7d132c3e3d..fd20bd91efa 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -12312,3 +12312,11 @@ ER_SEQUENCE_TABLE_HAS_TOO_FEW_ROWS eng "Fewer than one row in the table" ER_SEQUENCE_TABLE_HAS_TOO_MANY_ROWS eng "More than one row in the table" +ER_WARN_OPTIMIZER_HINT_SYNTAX_ERROR + eng "Optimizer hint syntax error" +ER_WARN_CONFLICTING_HINT + eng "Hint %s is ignored as conflicting/duplicated" +ER_WARN_UNKNOWN_QB_NAME + eng "Query block name %s is not found for %s hint" +ER_UNRESOLVED_HINT_NAME + eng "Unresolved name %s for %s hint" diff --git a/sql/simple_parser.h b/sql/simple_parser.h new file mode 100644 index 00000000000..669535496f4 --- /dev/null +++ b/sql/simple_parser.h @@ -0,0 +1,534 @@ +#ifndef SIMPLE_PARSER_H +#define SIMPLE_PARSER_H +/* + Copyright (c) 2024, MariaDB + + This program is free software; you can redistribute it and/or + modify it under the terms of the GNU General Public License + as published by the Free Software Foundation; version 2 of + the License. + + This program is distributed in the hope that it will be useful, + but WITHOUT ANY WARRANTY; without even the implied warranty of + MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + GNU General Public License for more details. + + You should have received a copy of the GNU General Public License + along with this program; if not, write to the Free Software + Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1335 USA +*/ + + +#include "simple_tokenizer.h" + +class Parser_templates +{ +protected: + + // Templates to parse common rule sequences + + /* + A rule consisting of a single token, e.g.: + rule ::= @ + rule ::= IDENT + */ + template + class TOKEN: public PARSER::Token + { + public: + TOKEN() + { } + TOKEN(const class PARSER::Token &tok) + :PARSER::Token(tok) + { } + TOKEN(class PARSER::Token &&tok) + :PARSER::Token(std::move(tok)) + { } + TOKEN(PARSER *p) + :PARSER::Token(p->token(tid)) + { } + static TOKEN empty(const PARSER &p) + { + return TOKEN(p.empty_token()); + } + }; + + + /* + A rule consisting of a choice of multiple tokens + rule ::= TOK1 | TOK2 | TOK3 + */ + template + class TokenChoice: public PARSER::Token + { + public: + TokenChoice() + { } + TokenChoice(PARSER *p) + :PARSER::Token(COND::allowed_token_id(p->look_ahead_token_id()) ? + p->shift() : + p->null_token()) + { + DBUG_ASSERT(!p->is_error() || !PARSER::Token::operator bool()); + } + }; + + + /* + An optional rule: + opt_rule ::= [ rule ] + */ + template + class OPT: public RULE + { + public: + OPT() + { } + OPT(PARSER *p) + :RULE(p) + { + if (!RULE::operator bool() && !p->is_error()) + { + RULE::operator=(RULE::empty(*p)); + DBUG_ASSERT(RULE::operator bool()); + } + } + }; + + + /* + A rule consisting of two other rules in a row: + rule ::= rule1 rule2 + */ + template + class AND2: public A, public B + { + public: + AND2() + :A(), B() + { } + AND2(AND2 && rhs) + :A(std::move(static_cast(rhs))), + B(std::move(static_cast(rhs))) + { } + AND2(A &&a, B &&b) + :A(std::move(a)), B(std::move(b)) + { } + AND2 & operator=(AND2 &&rhs) + { + A::operator=(std::move(static_cast(rhs))); + B::operator=(std::move(static_cast(rhs))); + return *this; + } + AND2(PARSER *p) + :A(p), + B(A::operator bool() ? B(p) : B()) + { + if (A::operator bool() && !B::operator bool()) + { + p->set_syntax_error(); + // Reset A to have A, B reported as "false" by their operator bool() + A::operator=(std::move(A())); + } + DBUG_ASSERT(!operator bool() || !p->is_error()); + } + operator bool() const + { + return A::operator bool() && B::operator bool(); + } + static AND2 empty(const PARSER &p) + { + return AND2(A::empty(p), B::empty(p)); + } + }; + + + /* + A rule consisting of three other rules in a row: + rule ::= rule1 rule2 rule3 + */ + template + class AND3: public A, public B, public C + { + public: + AND3() + :A(), B(), C() + { } + AND3(AND3 && rhs) + :A(std::move(static_cast(rhs))), + B(std::move(static_cast(rhs))), + C(std::move(static_cast(rhs))) + { } + AND3(A &&a, B &&b, C &&c) + :A(std::move(a)), B(std::move(b)), C(std::move(c)) + { } + AND3 & operator=(AND3 &&rhs) + { + A::operator=(std::move(static_cast(rhs))); + B::operator=(std::move(static_cast(rhs))); + C::operator=(std::move(static_cast(rhs))); + return *this; + } + AND3(PARSER *p) + :A(p), + B(A::operator bool() ? B(p) : B()), + C(A::operator bool() && B::operator bool() ? C(p) : C()) + { + if (A::operator bool() && (!B::operator bool() || !C::operator bool())) + { + p->set_syntax_error(); + // Reset A to have A, B, C reported as "false" by their operator bool() + A::operator=(A()); + B::operator=(B()); + C::operator=(C()); + } + DBUG_ASSERT(!operator bool() || !p->is_error()); + } + operator bool() const + { + return A::operator bool() && B::operator bool() && C::operator bool(); + } + static AND3 empty(const PARSER &p) + { + return AND3(A::empty(p), B::empty(p), C::empty()); + } + }; + + + /* + A rule consisting of three other rules in a row: + rule ::= rule1 rule2 rule3 rule4 + */ + template + class AND4: public A, public B, public C, public D + { + public: + AND4() + :A(), B(), C(), D() + { } + AND4(AND4 && rhs) + :A(std::move(static_cast(rhs))), + B(std::move(static_cast(rhs))), + C(std::move(static_cast(rhs))), + D(std::move(static_cast(rhs))) + { } + AND4(A &&a, B &&b, C &&c, D &&d) + :A(std::move(a)), B(std::move(b)), C(std::move(c)), D(std::move(d)) + { } + AND4 & operator=(AND4 &&rhs) + { + A::operator=(std::move(static_cast(rhs))); + B::operator=(std::move(static_cast(rhs))); + C::operator=(std::move(static_cast(rhs))); + D::operator=(std::move(static_cast(rhs))); + return *this; + } + AND4(PARSER *p) + :A(p), + B(A::operator bool() ? B(p) : B()), + C(A::operator bool() && B::operator bool() ? C(p) : C()), + D(A::operator bool() && B::operator bool() && C::operator bool() ? + D(p) : D()) + { + if (A::operator bool() && + (!B::operator bool() || !C::operator bool() || !D::operator bool())) + { + p->set_syntax_error(); + // Reset A to have A, B, C reported as "false" by their operator bool() + A::operator=(A()); + B::operator=(B()); + C::operator=(C()); + D::operator=(D()); + } + DBUG_ASSERT(!operator bool() || !p->is_error()); + } + operator bool() const + { + return A::operator bool() && B::operator bool() && + C::operator bool() && D::operator bool(); + } + static AND4 empty(const PARSER &p) + { + return AND4(A::empty(p), B::empty(p), C::empty(), D::empty()); + } + }; + + + /* + A rule consisting of a choice of rwo rules: + rule ::= rule1 | rule2 + + For the cases when the two branches have incompatible storage. + */ + template + class OR2: public A, public B + { + public: + OR2() + { } + OR2(OR2 &&rhs) + :A(std::move(static_cast(rhs))), + B(std::move(static_cast(rhs))) + { } + OR2(A && rhs) + :A(std::move(rhs)), B() + { } + OR2(B && rhs) + :A(), B(std::move(rhs)) + { } + OR2 & operator=(OR2 &&rhs) + { + A::operator=(std::move(static_cast(rhs))); + B::operator=(std::move(static_cast(rhs))); + return *this; + } + OR2(PARSER *p) + :A(p), B(A::operator bool() ? B() :B(p)) + { + DBUG_ASSERT(!operator bool() || !p->is_error()); + } + operator bool() const + { + return A::operator bool() || B::operator bool(); + } + }; + + + /* + A rule consisting of a choice of rwo rules, e.g. + rule ::= rule1 | rule2 + + For the cases when the two branches have a compatible storage, + passed as a CONTAINER, which must have constructors: + CONTAINER(const A &a) + CONTAINER(const B &b) + */ + template + class OR2C: public CONTAINER + { + public: + OR2C() + { } + OR2C(A &&a) + :CONTAINER(std::move(a)) + { } + OR2C(B &&b) + :CONTAINER(std::move(b)) + { } + OR2C(OR2C &&rhs) + :CONTAINER(std::move(rhs)) + { } + OR2C & operator=(OR2C &&rhs) + { + CONTAINER::operator=(std::move(rhs)); + return *this; + } + OR2C & operator=(A &&rhs) + { + CONTAINER::operator=(std::move(rhs)); + return *this; + } + OR2C & operator=(B &&rhs) + { + CONTAINER::operator=(std::move(rhs)); + return *this; + } + OR2C(PARSER *p) + :CONTAINER(A(p)) + { + if (CONTAINER::operator bool() || + CONTAINER::operator=(B(p))) + return; + DBUG_ASSERT(!CONTAINER::operator bool()); + } + }; + + + /* + A rule consisting of a choice of thee rules: + rule ::= rule1 | rule2 | rule3 + + For the case when the three branches have incompatible storage + */ + template + class OR3: public A, public B, public C + { + public: + OR3() + { } + OR3(OR3 &&rhs) + :A(std::move(static_cast(rhs))), + B(std::move(static_cast(rhs))), + C(std::move(static_cast(rhs))) + { } + OR3 & operator=(OR3 &&rhs) + { + A::operator=(std::move(static_cast(rhs))); + B::operator=(std::move(static_cast(rhs))); + C::operator=(std::move(static_cast(rhs))); + return *this; + } + OR3(PARSER *p) + :A(p), + B(A::operator bool() ? B() : B(p)), + C(A::operator bool() || B::operator bool() ? C() : C(p)) + { + DBUG_ASSERT(!operator bool() || !p->is_error()); + } + operator bool() const + { + return A::operator bool() || B::operator bool() || C::operator bool(); + } + }; + + /* + A rule consisting of a choice of three rules, e.g. + rule ::= rule1 | rule2 | rule3 + + For the cases when the three branches have a compatible storage, + passed as a CONTAINER, which must have constructors: + CONTAINER(const A &a) + CONTAINER(const B &b) + CONTAINER(const C &c) + */ + template + class OR3C: public CONTAINER + { + public: + OR3C() + { } + OR3C(OR3C &&rhs) + :CONTAINER(std::move(rhs)) + { } + OR3C(A &&a) + :CONTAINER(std::move(a)) + { } + OR3C(B &&b) + :CONTAINER(std::move(b)) + { } + OR3C(C &&c) + :CONTAINER(std::move(c)) + { } + OR3C & operator=(OR3C &&rhs) + { + CONTAINER::operator=(std::move(rhs)); + return *this; + } + OR3C & operator=(A &&rhs) + { + CONTAINER::operator=(std::move(rhs)); + return *this; + } + OR3C & operator=(B &&rhs) + { + CONTAINER::operator=(std::move(rhs)); + return *this; + } + OR3C & operator=(C &&rhs) + { + CONTAINER::operator=(std::move(rhs)); + return *this; + } + + OR3C(PARSER *p) + :CONTAINER(A(p)) + { + if (CONTAINER::operator bool() || + CONTAINER::operator=(B(p)) || + CONTAINER::operator=(C(p))) + return; + DBUG_ASSERT(!CONTAINER::operator bool()); + } + }; + + + /* + A list with at least MIN_COUNT elements (typlically 0 or 1), + with or without a token separator between elements: + + list ::= element [ {, element }... ] // with a separator + list ::= element [ element ... ] // without a separator + + Pass the null-token special purpose ID in SEP for a non-separated list, + or a real token ID for a separated list. + + If MIN_COUNT is 0, then the list becomes optional, + which corresponds to the following grammar: + + list ::= [ element [ {, element }... ] ] // with a separator + list ::= [ element [ element ... ] ] // without a separator + */ + template + class LIST: public LIST_CONTAINER + { + protected: + bool m_error; + public: + LIST() + :m_error(true) + { } + LIST(LIST &&rhs) + :LIST_CONTAINER(std::move(rhs)), + m_error(rhs.m_error) + { } + LIST & operator=(LIST &&rhs) + { + LIST_CONTAINER::operator=(std::move(rhs)); + m_error= rhs.m_error; + return *this; + } + LIST(PARSER *p) + :m_error(true) + { + // Determine if the caller wants a separated or a non-separated list + const bool separated= SEP != PARSER::null_token().id(); + for ( ; ; ) + { + ELEMENT elem(p); + if (!elem) + { + if (LIST_CONTAINER::count() == 0 || !separated) + { + /* + Could not get the very first element, + or not-first element in a non-separated list. + */ + m_error= p->is_error(); + DBUG_ASSERT(!m_error || !operator bool()); + return; + } + // Could not get the next element after the separator + p->set_syntax_error(); + m_error= true; + DBUG_ASSERT(!operator bool()); + return; + } + if (LIST_CONTAINER::add(p, std::move(elem))) + { + p->set_fatal_error(); + m_error= true; + DBUG_ASSERT(!operator bool()); + return; + } + if (separated) + { + if (!p->token(SEP)) + { + m_error= false; + DBUG_ASSERT(operator bool()); + return; + } + } + } + } + operator bool() const + { + return !m_error && LIST_CONTAINER::count() >= MIN_COUNT; + } + }; + +}; + +#endif // SIMPLE_PARSER_H diff --git a/sql/simple_tokenizer.h b/sql/simple_tokenizer.h index b284dc10017..bc55c03561b 100644 --- a/sql/simple_tokenizer.h +++ b/sql/simple_tokenizer.h @@ -17,11 +17,21 @@ #define SIMPLE_TOKENIZER_INCLUDED +#include "lex_ident.h" +#include "scan_char.h" + +/** + A tokenizer for an ASCII7 input +*/ class Simple_tokenizer { +protected: const char *m_ptr; const char *m_end; public: + Simple_tokenizer(const LEX_CSTRING &str) + :m_ptr(str.str), m_end(str.str + str.length) + { } Simple_tokenizer(const char *str, size_t length) :m_ptr(str), m_end(str + length) { } @@ -33,11 +43,15 @@ public: { return m_ptr >= m_end; } + bool is_space() const + { + return m_ptr[0] == ' ' || m_ptr[0] == '\r' || m_ptr[0] == '\n'; + } void get_spaces() { for ( ; !eof(); m_ptr++) { - if (m_ptr[0] != ' ') + if (!is_space()) break; } } @@ -82,4 +96,184 @@ public: }; +/** + A tokenizer for a character set aware input. +*/ +class Extended_string_tokenizer: public Simple_tokenizer +{ +protected: + + CHARSET_INFO *m_cs; + + class Token_metadata + { + public: + bool m_extended_chars:1; + bool m_double_quotes:1; + Token_metadata() + :m_extended_chars(false), m_double_quotes(false) + { } + }; + + class Token_with_metadata: public Lex_cstring, + public Token_metadata + { + public: + Token_with_metadata() + { } + Token_with_metadata(const char *str, size_t length, + const Token_metadata &metadata) + :Lex_cstring(str, length), Token_metadata(metadata) + { } + Token_with_metadata(const char *str) + :Lex_cstring(str, (size_t) 0), Token_metadata() + { } + }; + + /* + Get a non-delimited identifier for a 8-bit character set + */ + Token_with_metadata get_ident_8bit(const char *str, const char *end) const + { + DBUG_ASSERT(m_cs->mbmaxlen == 1); + Token_with_metadata res(str); + for ( ; str < end && m_cs->ident_map[(uchar) *str]; str++, res.length++) + { + if (*str & 0x80) + res.m_extended_chars= true; + } + return res; + } + + /* + Get a non-identifier for a multi-byte character set + */ + Token_with_metadata get_ident_mb(const char *str, const char *end) const + { + DBUG_ASSERT(m_cs->mbmaxlen > 1); + Token_with_metadata res(str); + for ( ; m_cs->ident_map[(uchar) *str]; ) + { + int char_length= m_cs->charlen(str, end); + if (char_length <= 0) + break; + str+= char_length; + res.length+= (size_t) char_length; + res.m_extended_chars|= char_length > 1; + } + return res; + } + + /* + Get a non-delimited identifier + */ + Token_with_metadata get_ident(const char *str, const char *end) + { + return m_cs->mbmaxlen == 1 ? get_ident_8bit(str, end) : + get_ident_mb(str, end); + } + + /* + Get a quoted string or a quoted identifier. + The quote character is determined by the current head character + pointed by str. The result is returned together with the left + and the right quotes. + */ + Token_with_metadata get_quoted_string(const char *str, const char *end) + { + Token_with_metadata res(str); + const Scan_char quote(m_cs, str, end); + if (quote.length() <= 0) + { + /* + Could not get the left quote character: + - the end of the input reached, or + - a bad byte sequence found. + Return a null token to signal the error to the caller. + */ + return Token_with_metadata(); + } + str+= quote.length(); + res.length+= (size_t) quote.length(); + + for ( ; ; ) + { + const Scan_char ch(m_cs, str, end); + if (ch.length() <= 0) + { + /* + Could not find the right quote character: + - the end of the input reached before the quote was not found, or + - a bad byte sequences found + Return a null token to signal the error to the caller. + */ + return Token_with_metadata(); + } + str+= ch.length(); + res.length+= (size_t) ch.length(); + if (quote.eq(ch)) + { + if (quote.eq_safe(Scan_char(m_cs, str, end))) + { + /* + Two quotes in a row found: + - `a``b` + - "a""b" + */ + str+= quote.length(); + res.length+= (size_t) quote.length(); + res.m_extended_chars|= quote.length() > 1; + res.m_double_quotes= true; + continue; + } + return res; // The right quote found + } + res.m_extended_chars|= ch.length() > 1; + } + return res; + } + +public: + Extended_string_tokenizer(CHARSET_INFO *cs, const LEX_CSTRING &str) + :Simple_tokenizer(str), + m_cs(cs) + { } + + // Skip all leading spaces + void get_spaces() + { + for ( ; !eof(); m_ptr++) + { + if (!my_isspace(m_cs, *m_ptr)) + break; + } + } + + /* + Get a non-delimited identifier. + Can return an empty token if the head character is not an identifier + character. + */ + Token_with_metadata get_ident() + { + const Token_with_metadata tok= get_ident(m_ptr, m_end); + m_ptr+= tok.length; + return tok; + } + + /* + Get a quoted string or a quoted identifier. + Can return a null token if there were errors + (e.g. unexpected end of the input, bad byte sequence). + */ + Token_with_metadata get_quoted_string() + { + const Token_with_metadata tok= get_quoted_string(m_ptr, m_end); + m_ptr+= tok.length; + return tok; + } + +}; + + #endif // SIMPLE_TOKENIZER_INCLUDED diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 13625728cc9..92ba1aa2935 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -855,6 +855,7 @@ Lex_input_stream::reset(char *buffer, size_t length) found_semicolon= NULL; ignore_space= MY_TEST(m_thd->variables.sql_mode & MODE_IGNORE_SPACE); stmt_prepare_mode= FALSE; + hint_comment= FALSE; multi_statements= TRUE; in_comment=NO_COMMENT; m_underscore_cs= NULL; @@ -2493,10 +2494,20 @@ int Lex_input_stream::lex_one_token(YYSTYPE *yylval, THD *thd) else { in_comment= PRESERVE_COMMENT; + yylval->lex_str.str= m_ptr; yySkip(); // Accept / yySkip(); // Accept * - comment_closed= ! consume_comment(0); /* regular comments can have zero comments inside. */ + if ((comment_closed= ! consume_comment(0)) && hint_comment) + { + if (yylval->lex_str.str[2]=='+') + { + next_state= MY_LEX_START; + yylval->lex_str.length= m_ptr - yylval->lex_str.str; + restore_in_comment_state(); + return HINT_COMMENT; + } + } } /* Discard: @@ -12830,3 +12841,53 @@ bool SELECT_LEX_UNIT::is_derived_eliminated() const return true; return derived->table->map & outer_select()->join->eliminated_tables; } + + +/* + Parse optimizer hints and return as Hint_list allocated on thd->mem_root. + + The caller should check both return value and thd->is_error() + to know what happened, as follows: + + Return value thd->is_error() Meaning + ------------ --------------- ------- + rc != nullptr false the hints were parsed without errors + rc != nullptr true not possible + rc == nullptr false no hints, empty hints, hint parse error + rc == nullptr true fatal error, such as EOM +*/ +Optimizer_hint_parser::Hint_list * +LEX::parse_optimizer_hints(const LEX_CSTRING &hints_str) +{ + DBUG_ASSERT(!hints_str.str || hints_str.length >= 5); + if (!hints_str.str) + return nullptr; // There were no a hint comment + + // Instantiate the query hint parser. + // Remove the leading '/*+' and trailing '*/' + // when passing hints to the parser. + Optimizer_hint_parser p(thd, thd->charset(), + Lex_cstring(hints_str.str + 3, hints_str.length - 5)); + // Parse hints + Optimizer_hint_parser::Hints hints(&p); + DBUG_ASSERT(!p.is_error() || !hints); + + if (p.is_fatal_error()) + { + /* + Fatal error (e.g. EOM), have the caller fail. + The SQL error should be in DA already. + */ + DBUG_ASSERT(thd->is_error()); + return nullptr; // Continue, the caller will test thd->is_error() + } + + if (!hints) // Hint parsing failed with a syntax error + { + p.push_warning_syntax_error(thd); + return nullptr; // Continue and ignore hints. + } + + // Hints were not empty and were parsed without errors + return new (thd->mem_root) Optimizer_hint_parser::Hint_list(std::move(hints)); +} diff --git a/sql/sql_lex.h b/sql/sql_lex.h index 12474426801..c1f116db1ef 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -40,6 +40,7 @@ #include "table.h" #include "sql_class.h" // enum enum_column_usage #include "select_handler.h" +#include "opt_hints_parser.h" /* Used for flags of nesting constructs */ #define SELECT_NESTING_MAP_SIZE 64 @@ -2824,6 +2825,11 @@ public: */ bool multi_statements:1; + /** + TRUE if hint comments should be returned as a token. + */ + bool hint_comment:1; + /** Current line number. */ uint yylineno; @@ -4959,6 +4965,9 @@ public: { return nullptr; } + + Optimizer_hint_parser::Hint_list * + parse_optimizer_hints(const LEX_CSTRING &hint); }; diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 8c77e8c330d..96067bd4fd6 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -278,6 +278,7 @@ void _CONCAT_UNDERSCORED(turn_parser_debug_on,yyparse)() TABLE_LIST *table_list; Table_ident *table; Qualified_column_ident *qualified_column_ident; + Optimizer_hint_parser::Hint_list *opt_hints; char *simple_string; const char *const_simple_string; chooser_compare_func_creator boolfunc2creator; @@ -385,6 +386,8 @@ bool my_yyoverflow(short **a, YYSTYPE **b, size_t *yystacksize); %token '@' +%token HINT_COMMENT + /* Special purpose tokens */ @@ -1330,6 +1333,7 @@ bool my_yyoverflow(short **a, YYSTYPE **b, size_t *yystacksize); opt_constraint constraint opt_ident sp_block_label sp_control_label opt_place opt_db udt_name + HINT_COMMENT opt_hint_comment %type IDENT_sys @@ -1584,6 +1588,9 @@ bool my_yyoverflow(short **a, YYSTYPE **b, size_t *yystacksize); %type expr_lex +%type + opt_optimizer_hint + %destructor { /* @@ -8951,8 +8958,23 @@ table_value_constructor: } ; +opt_hint_comment: + /*empty */ { $$= null_clex_str; } + | HINT_COMMENT { $$= $1; } + ; + +opt_optimizer_hint: + { YYLIP->hint_comment= true; } + opt_hint_comment + { + YYLIP->hint_comment= false; + if (!($$= Lex->parse_optimizer_hints($2)) && thd->is_error()) + MYSQL_YYABORT; + } + ; + query_specification_start: - SELECT_SYM + SELECT_SYM opt_optimizer_hint { SELECT_LEX *sel; LEX *lex= Lex; @@ -13562,7 +13584,7 @@ opt_temporary: */ insert: - INSERT + INSERT opt_optimizer_hint { Lex->sql_command= SQLCOM_INSERT; Lex->duplicates= DUP_ERROR; @@ -13571,7 +13593,7 @@ insert: } insert_start insert_lock_option opt_ignore opt_into insert_table { - Select->set_lock_for_tables($4, true, false); + Select->set_lock_for_tables($5, true, false); } insert_field_spec opt_insert_update opt_returning stmt_end @@ -13582,7 +13604,7 @@ insert: ; replace: - REPLACE + REPLACE opt_optimizer_hint { Lex->sql_command = SQLCOM_REPLACE; Lex->duplicates= DUP_REPLACE; @@ -13591,7 +13613,7 @@ replace: } insert_start replace_lock_option opt_into insert_table { - Select->set_lock_for_tables($4, true, false); + Select->set_lock_for_tables($5, true, false); } insert_field_spec opt_returning stmt_end @@ -13866,7 +13888,7 @@ update_table_list: /* Update rows in a table */ update: - UPDATE_SYM + UPDATE_SYM opt_optimizer_hint { LEX *lex= Lex; if (Lex->main_select_push()) @@ -13901,12 +13923,12 @@ update: be too pessimistic. We will decrease lock level if possible later while processing the statement. */ - slex->set_lock_for_tables($3, slex->table_list.elements == 1, false); + slex->set_lock_for_tables($4, slex->table_list.elements == 1, false); } opt_where_clause opt_order_clause delete_limit_clause { - if ($10) - Select->order_list= *($10); + if ($11) + Select->order_list= *($11); } stmt_end {} ; @@ -13953,7 +13975,7 @@ opt_low_priority: /* Delete rows from a table */ delete: - DELETE_SYM + DELETE_SYM opt_optimizer_hint { LEX *lex= Lex; YYPS->m_lock_type= TL_WRITE_DEFAULT;