opt_hints.test 34.8 KB
Newer Older
1
--enable_prepare_warnings
2
--disable_view_protocol # Since optimizer hints are not supported inside views
3 4 5 6 7 8 9
SET NAMES utf8mb4;

--echo # Testing that index names in hints are accent sensitive case insensitive
CREATE TABLE t1 (a INT, ä INT, INDEX idx_a(a), INDEX idx_ä(ä));
INSERT INTO t1 VALUES (1,1),(2,2);
SELECT /*+ NO_MRR(t1 idx_a) */ a FROM t1;
SELECT /*+ NO_MRR(t1 idx_A) */ a FROM t1;
10 11 12 13

# Warnings "Unresolved table/index name..." are generated during both prepare
# and execution stages. So disable PS protocol to avoid duplication
--disable_ps_protocol
14 15
SELECT /*+ NO_MRR(t1 idx_å) */ a FROM t1;
SELECT /*+ NO_MRR(t1 idx_a, idx_å, idx_A) */ a FROM t1;
16
--enable_ps_protocol
17 18 19 20 21 22 23 24
DROP TABLE t1;

--echo # Testing that query block names are accent sensitive case insensitive
CREATE TABLE t1 (a INT);
SELECT /*+ QB_NAME(a) BKA(t1@a) BKA(t1@A) */ * FROM t1;
SELECT /*+ QB_NAME(a) BKA(t1@a) BKA(t1@å) */ * FROM t1;
DROP TABLE t1;

25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72
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
73 74
EXPLAIN EXTENDED SELECT /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY) */ f1
  FROM t3 WHERE f1 > 30 AND f1 < 33;
75 76
--echo # Turn off range access for PRIMARY & f2_idx keys
--echo # Should use index access
77 78
EXPLAIN EXTENDED SELECT /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY, f2_idx) */ f1
  FROM t3 WHERE f1 > 30 AND f1 < 33;
79 80
--echo # Turn off range access for all keys
--echo # Should use index access
81 82
EXPLAIN EXTENDED SELECT /*+ NO_RANGE_OPTIMIZATION(t3) */ f1
  FROM t3 WHERE f1 > 30 AND f1 < 33;
83 84
--echo # Turn off range access for PRIMARY & f2_idx keys
--echo # Should use index access
85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110
EXPLAIN EXTENDED SELECT /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY) NO_RANGE_OPTIMIZATION(t3 f2_idx) */ f1
  FROM t3 WHERE f1 > 30 AND f1 < 33;

--echo # Create a clone of t3 with cyrillic names
CREATE TABLE таблица (f1 INT NOT NULL, поле2 INT, поле3 VARCHAR(32),
                 PRIMARY KEY(f1), KEY f2_индекс(f1), KEY f3_индекс(поле3))
                 AS SELECT * FROM t3;
ANALYZE TABLE таблица;
--echo # Turn off range access for PRIMARY key
--echo # Should use range access by f2_индекс key
EXPLAIN EXTENDED SELECT /*+ NO_RANGE_OPTIMIZATION(таблица PRIMARY) */ f1
  FROM таблица WHERE f1 > 30 AND f1 < 33;
--echo # Turn off range access for PRIMARY & f2_индекс keys
--echo # Should use index access
EXPLAIN EXTENDED SELECT /*+ NO_RANGE_OPTIMIZATION(таблица PRIMARY, f2_индекс) */ f1
  FROM таблица 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(таблица) */ f1
  FROM таблица WHERE f1 > 30 AND f1 < 33;
--echo # Turn off range access for PRIMARY & f2_индекс keys
--echo # Should use index access
EXPLAIN EXTENDED
  SELECT /*+ NO_RANGE_OPTIMIZATION(таблица PRIMARY) NO_RANGE_OPTIMIZATION(таблица f2_индекс) */ f1
  FROM таблица WHERE f1 > 30 AND f1 < 33;
DROP TABLE таблица;
111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129

--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;

130 131 132 133 134 135
--echo # Cyrillic query block name
EXPLAIN EXTENDED SELECT /*+ NO_ICP(t5@блок1 x_idx) */ * FROM
  (SELECT /*+ QB_NAME(блок1) */ t4.x, t5.y FROM t4, t4 t5
   WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0) AS TD;


136
--echo # Expected warning for z_idx key, unresolved name.
137 138 139
# Warnings "Unresolved table/index name..." are generated during both prepare
# and execution stages. So disable PS protocol to avoid duplication
--disable_ps_protocol
140 141 142
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;
143
--enable_ps_protocol
144 145 146 147 148 149 150

--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
151 152 153
set optimizer_switch = DEFAULT;
set optimizer_switch = 'mrr=on,mrr_cost_based=off';
set join_cache_level = 8;
154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199

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);

200 201 202 203 204 205 206 207 208 209 210 211 212 213 214
--echo # Hint overrides both join_cache_level and optimizer switch
set join_cache_level = 0;
EXPLAIN EXTENDED SELECT /*+ BKA(t12, t13) */ * FROM t12, t13
  WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1);

set join_cache_level = 2;
EXPLAIN EXTENDED SELECT /*+ BKA(t12, t13) */ * FROM t12, t13
  WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1);

set join_cache_level = 4;
EXPLAIN EXTENDED SELECT /*+ BKA(t12, t13) */ * FROM t12, t13
  WHERE t12.a=t13.a AND (t13.b+1 <= t13.b+1);

set join_cache_level = 8;

215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232
--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);

233
--echo # UPDATE|DELETE|INSERT|REPLACE hint testing
234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282
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);

283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301
--echo # Make sure ICP is expected to be used when there are no hints
EXPLAIN EXTENDED REPLACE 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 REPLACE 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 REPLACE /*+ 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 REPLACE /*+ 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);

302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326
--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
327 328 329
# Warnings "Unresolved table/index name..." are generated during both prepare
# and execution stages. So disable PS protocol to avoid duplication
--disable_ps_protocol
330 331 332 333
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;
334
--enable_ps_protocol
335 336 337 338 339 340 341 342 343 344 345 346 347 348 349

--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.
350 351 352
# Warnings "Unresolved table/index name..." are generated during both prepare
# and execution stages. So disable PS protocol to avoid duplication
--disable_ps_protocol
353 354
EXPLAIN EXTENDED SELECT /*+ BKA(tbl2) */ * FROM t12 tbl12, t13 tbl13 
WHERE tbl12.a=tbl13.a AND (tbl13.b+1 <= tbl13.b+1);
355
--enable_ps_protocol
356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376

--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;

377 378 379
--echo #
--echo # BNL and NO_BNL hint testing
--echo #
380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406

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;

407 408 409 410 411 412 413 414 415 416 417 418
--echo # Make sure query results are the same for any hints combination
--sorted_result
SELECT * FROM t1,t2,t3;
--sorted_result
SELECT /*+ NO_BNL(t1, t2) */* FROM t1,t2,t3;
--sorted_result
SELECT /*+ NO_BNL(t1, t3) */* FROM t1,t2,t3;
--sorted_result
SELECT /*+ NO_BNL(t2, t3) */* FROM t1,t2,t3;

--echo # BNL() overrides current join_cache_level setting
set join_cache_level = 0;
419 420
EXPLAIN EXTENDED SELECT t1.* FROM t1,t2,t3;
EXPLAIN EXTENDED SELECT /*+ BNL() */t1.* FROM t1,t2,t3;
421
EXPLAIN EXTENDED SELECT /*+ BNL(t1, t2) */t1.* FROM t1,t2,t3;
422
EXPLAIN EXTENDED SELECT /*+ BNL(t1, t3) */t1.* FROM t1,t2,t3;
423
EXPLAIN EXTENDED SELECT /*+ BNL(t2, t3) */t1.* FROM t1,t2,t3;
424 425 426
EXPLAIN EXTENDED SELECT /*+ BNL(t2) BNL(t3) */t1.* FROM t1,t2,t3;

DROP TABLE t1, t2, t3;
427
set join_cache_level = 8;
428 429 430 431 432 433 434 435 436 437 438

--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;

439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506
EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) */ * FROM t1 JOIN t2 ON t1.a = t2.a WHERE
t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.a = t4.b);

EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL() */ *
  FROM t1 JOIN t2 ON t1.a = t2.a
  WHERE t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.a = t4.b);

EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL(t1, t2) */ *
  FROM t1 JOIN t2 ON t1.a = t2.a
  WHERE t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.a = t4.b);

EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL(@subq1) */ *
  FROM t1 JOIN t2 ON t1.a = t2.a
  WHERE t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.a = t4.b);

EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL(t4@subq1) */ *
  FROM t1 JOIN t2 ON t1.a = t2.a
  WHERE t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.a = t4.b);

EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL(t3@subq1,t4@subq1) */ *
  FROM t1 JOIN t2 ON t1.a = t2.a
  WHERE t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.a = t4.b);

EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) NO_BNL(@subq1 t3, t4) */ *
  FROM t1 JOIN t2 ON t1.a = t2.a
  WHERE t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.a = t4.b);

EXPLAIN EXTENDED SELECT /*+ QB_NAME(q) */ *
  FROM t1 JOIN t2 ON t1.a = t2.a
  WHERE t2.a IN (SELECT /*+ QB_NAME(subq1)  NO_BNL(t3, t4) */ t3.b
    FROM t3 JOIN t1 t4 ON t3.a = t4.b);

--echo # Make sure query results are the same for any hints combination
# --sorted_result
SELECT * FROM t1 JOIN t2 ON t1.a = t2.a WHERE
t2.a IN (SELECT t3.b FROM t3 JOIN t1 t4 ON t3.a = t4.b);
# --sorted_result
SELECT /*+ QB_NAME(q) */ * FROM t1 JOIN t2 ON t1.a = t2.a WHERE
t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.a = t4.b);
--sorted_result
SELECT /*+ QB_NAME(q) NO_BNL() */ *
  FROM t1 JOIN t2 ON t1.a = t2.a
  WHERE t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.a = t4.b);
--sorted_result
SELECT /*+ QB_NAME(q) NO_BNL(t1, t2) */ *
  FROM t1 JOIN t2 ON t1.a = t2.a
  WHERE t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.a = t4.b);
--sorted_result
SELECT /*+ QB_NAME(q) NO_BNL(@subq1) */ *
  FROM t1 JOIN t2 ON t1.a = t2.a
  WHERE t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.a = t4.b);
--sorted_result
SELECT /*+ QB_NAME(q) NO_BNL(t4@subq1) */ *
  FROM t1 JOIN t2 ON t1.a = t2.a
  WHERE t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.a = t4.b);
--sorted_result
SELECT /*+ QB_NAME(q) NO_BNL(t3@subq1,t4@subq1) */ *
  FROM t1 JOIN t2 ON t1.a = t2.a
  WHERE t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.a = t4.b);
--sorted_result
SELECT /*+ QB_NAME(q) NO_BNL(@subq1 t3, t4) */ *
  FROM t1 JOIN t2 ON t1.a = t2.a
  WHERE t2.a IN (SELECT /*+ QB_NAME(subq1) */ t3.b FROM t3 JOIN t1 t4 ON t3.a = t4.b);
--sorted_result
SELECT /*+ QB_NAME(q) */ *
  FROM t1 JOIN t2 ON t1.a = t2.a
  WHERE t2.a IN (SELECT /*+ QB_NAME(subq1)  NO_BNL(t3, t4) */ t3.b
    FROM t3 JOIN t1 t4 ON t3.a = t4.b);
507

508
DROP TABLE t1, t2, t3, t4;
509

510 511 512
--echo #
--echo # BNL() and NO_BNL() for LEFT JOINs
--echo #
513

514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568
CREATE TABLE t1 (a int);
CREATE TABLE t2 (a int);
CREATE TABLE t3 (a int);
CREATE TABLE t4 (a int);

INSERT INTO t1 VALUES (null), (2), (null), (1);

set join_cache_level = 8;

--echo # Two join buffers are employed by default (without hints):
EXPLAIN SELECT t1.a
  FROM t1 LEFT JOIN (t2 LEFT JOIN t3 ON t2.a) ON 0
    WHERE t1.a OR t3.a;

--echo # Disabling either of join buffers disables another one automatically due
--echo # to join buffer employment rules:
EXPLAIN SELECT /*+ NO_BNL(t2) */ t1.a
  FROM t1 LEFT JOIN (t2 LEFT JOIN t3 ON t2.a) ON 0
    WHERE t1.a OR t3.a;

EXPLAIN SELECT /*+ NO_BNL(t3) */ t1.a
  FROM t1 LEFT JOIN (t2 LEFT JOIN t3 ON t2.a) ON 0
    WHERE t1.a OR t3.a;

--echo # Three join buffers are employed here by default (without hints):
EXPLAIN SELECT t1.a
  FROM t1 LEFT JOIN (t2 LEFT JOIN (t3 LEFT JOIN t4 ON 1) ON t2.a) ON 0
    WHERE t1.a OR t4.a;

--echo # Disabling either of join buffers disables others automatically due
--echo # to join buffer employment rules:
EXPLAIN SELECT /*+ NO_BNL(t2)*/ t1.a
  FROM t1 LEFT JOIN (t2 LEFT JOIN (t3 LEFT JOIN t4 ON 1) ON t2.a) ON 0
    WHERE t1.a OR t4.a;
EXPLAIN SELECT /*+ NO_BNL(t3)*/ t1.a
  FROM t1 LEFT JOIN (t2 LEFT JOIN (t3 LEFT JOIN t4 ON 1) ON t2.a) ON 0
    WHERE t1.a OR t4.a;
EXPLAIN SELECT /*+ NO_BNL(t4)*/ t1.a
  FROM t1 LEFT JOIN (t2 LEFT JOIN (t3 LEFT JOIN t4 ON 1) ON t2.a) ON 0
    WHERE t1.a OR t4.a;

set join_cache_level=0;
--echo # It is not allowed to enable join buffers on some subset of inner tables
--echo # of an outer join. Either all tables should use join buffers or none:
EXPLAIN SELECT /*+ BNL(t2)*/ t1.a
  FROM t1 LEFT JOIN (t2 LEFT JOIN (t3 LEFT JOIN t4 ON 1) ON t2.a) ON 0
    WHERE t1.a OR t4.a;
EXPLAIN SELECT /*+ BNL(t2, t3)*/ t1.a
  FROM t1 LEFT JOIN (t2 LEFT JOIN (t3 LEFT JOIN t4 ON 1) ON t2.a) ON 0
    WHERE t1.a OR t4.a;
EXPLAIN SELECT /*+ BNL(t2, t3, t4)*/ t1.a
  FROM t1 LEFT JOIN (t2 LEFT JOIN (t3 LEFT JOIN t4 ON 1) ON t2.a) ON 0
    WHERE t1.a OR t4.a;

DROP TABLE t1,t2,t3,t4;
569 570


571 572 573
--echo #
--echo # Mix of BNL/BKA flat and incremental join buffers for OUTER JOINs
--echo #
574

575
set optimizer_switch='outer_join_with_cache=on,mrr=on,mrr_sort_keys=on,index_condition_pushdown=on';
576

577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620
CREATE TABLE t1 (a1 varchar(32)) ;
INSERT INTO t1 VALUES ('s'),('k');

CREATE TABLE t2 (a2 int PRIMARY KEY, b2 varchar(32)) ;
INSERT INTO t2 VALUES (7,'s');

CREATE TABLE t3 (a3 int PRIMARY KEY, b3 varchar(32)) ;
INSERT INTO t3 VALUES (7,'s');

CREATE TABLE t4 (a4 int);
INSERT INTO t4 VALUES (9);

CREATE TABLE t5(a5 int PRIMARY KEY, b5 int) ;
INSERT INTO t5 VALUES (7,0);
--disable_result_log
ANALYZE TABLES t1, t2, t3, t4, t5;
--enable_result_log

--echo # Disable join buffering to enable it selectively on particular tables
SET SESSION join_cache_level = 0;
EXPLAIN
SELECT t4.a4, t5.b5
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;
SELECT t4.a4, t5.b5 
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;

EXPLAIN
SELECT /*+ BNL(t4) */ t4.a4, t5.b5
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;
SELECT /*+ BNL(t4) */ t4.a4, t5.b5
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;

EXPLAIN
SELECT /*+ BNL(t4, t5) */ t4.a4, t5.b5
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;
SELECT /*+ BNL(t4, t5) */ t4.a4, t5.b5
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;

621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639
--echo # BNL() hint overrides join_cache_levels from 0 to 3 increasing it to 4
set join_cache_level = 1;
EXPLAIN
SELECT /*+ BNL(t4, t5) */ t4.a4, t5.b5
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;

set join_cache_level = 2;
EXPLAIN
SELECT /*+ BNL(t4, t5) */ t4.a4, t5.b5
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;

set join_cache_level = 3;
EXPLAIN
SELECT /*+ BNL(t4, t5) */ t4.a4, t5.b5
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;

640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675
--echo # Enable all join buffering capabilities:
SET SESSION join_cache_level = 8;
EXPLAIN
SELECT t4.a4, t5.b5
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;
SELECT t4.a4, t5.b5
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;

EXPLAIN
SELECT /*+ NO_BNL(t4)*/ t4.a4, t5.b5
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;
SELECT /*+ NO_BNL(t4)*/ t4.a4, t5.b5
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;

--echo # Disable BKA so the BNLH join buffer will be employed:
EXPLAIN
SELECT /*+ NO_BKA(t5)*/ t4.a4, t5.b5
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;
SELECT /*+ NO_BKA(t5)*/ t4.a4, t5.b5
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;

EXPLAIN
SELECT /*+ NO_BKA(t5) NO_BNL(t5)*/ t4.a4, t5.b5
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;
SELECT /*+ NO_BKA(t5) NO_BNL(t5)*/ t4.a4, t5.b5
  FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
       LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;

DROP TABLE t1,t2,t3,t4,t5;
676 677 678 679


--echo # MRR & NO_MRR hint testing
set optimizer_switch=default;
680
set join_cache_level = 8;
681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761

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;

762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783
--echo #
--echo # Hints inside views are not supported
--echo #
CREATE TABLE t1 (a INT, INDEX idx_a(a));
INSERT INTO t1 VALUES (1),(2);

CREATE VIEW v1 AS SELECT /*+ NO_MRR(t1 idx_a) */ a FROM t1;
SELECT * FROM v1;
--echo # Make sure hints are not present inside the view definition:
SHOW CREATE VIEW v1;
EXPLAIN EXTENDED SELECT * FROM v1;

CREATE OR REPLACE VIEW v1 AS SELECT /*+ NO_MRR(t1 idx_a) BKA(t1)*/ a FROM t1;
SHOW CREATE VIEW v1;

ALTER VIEW v1 AS SELECT /*+ QB_NAME(q1)*/ a FROM t1;
SHOW CREATE VIEW v1;
SELECT * FROM v1;

--echo # Wrong place for the hint, must be simply ignored:
CREATE OR REPLACE VIEW v1 AS SELECT a /*+ NO_ICP(t1 idx_a)*/ FROM t1;
SHOW CREATE VIEW v1;
784

785 786 787 788 789 790 791 792 793 794 795 796
--echo # Incorrect hint does not prevent view creation, only a warning generated:
CREATE VIEW v2 AS SELECT /*+ BAD HINT*/ a+10 FROM t1;
SELECT * FROM v2;
EXPLAIN EXTENDED SELECT * FROM v2;
SHOW CREATE VIEW v2;

DROP VIEW v1, v2;
DROP TABLE t1;

--echo #
--echo # Tests of parser for optimizer hints
--echo #
797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846

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);

((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;

847 848 849
# Warnings "Unresolved table/index name..." are generated during both prepare
# and execution stages. So disable PS protocol to avoid duplication
--disable_ps_protocol
850 851
SELECT /*+ NO_ICP(i1) */ 1 FROM t1;
SELECT /*+ NO_ICP(i1 i2) */ 1 FROM t1;
852
--enable_ps_protocol
853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876
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);
877 878 879 880

# Warnings "Unresolved table/index name..." are generated during both prepare
# and execution stages. So disable PS protocol to avoid duplication
--disable_ps_protocol
881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907
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```;
908
--enable_ps_protocol
909 910 911 912 913 914 915 916 917 918 919 920 921 922 923 924 925

--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:
926 927 928 929

# Warnings "Unresolved table/index name..." are generated during both prepare
# and execution stages. So disable PS protocol to avoid duplication
--disable_ps_protocol
930 931 932 933 934 935 936 937 938 939 940 941 942
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 таблица;
943
--enable_ps_protocol
944 945 946 947 948 949 950 951 952 953 954 955 956 957

--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;
958
--disable_ps_protocol # to avoid warnings duplication, see details above
959
SELECT /*+ NO_ICP(10) */ 1;
960
--enable_ps_protocol
961 962 963 964 965 966 967 968 969 970 971 972 973 974
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 */;
975
SELECT 1 FROM /*+ QB_NAME(q1) */ t1 /*+ NO_ICP() */WHERE /*+ NO_MRR(t1) */ 1 /*+ #3 */;
976 977 978 979 980 981 982 983 984 985 986 987 988 989 990 991 992 993 994

--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;
995 996 997 998 999
set optimizer_switch = DEFAULT;
set join_cache_level = DEFAULT;
--echo #
--echo # End of 11.7 tests
--echo #