1# include/index_merge_ror.inc 2# 3# ROR-index_merge tests. 4# 5# The variable 6# $engine_type -- storage engine to be tested 7# has to be set before sourcing this script. 8# 9# Note: The comments/expectations refer to MyISAM. 10# They might be not valid for other storage engines. 11# 12# Last update: 13# 2006-08-02 ML test refactored 14# old name was t/index_merge_ror.test 15# main code went into include/index_merge_ror.inc 16# 17 18--echo #---------------- ROR-index_merge tests ----------------------- 19 20create table t1 21( 22 /* Field names reflect value(rowid) distribution, st=STairs, swt= SaWTooth */ 23 st_a int not null default 0, 24 swt1a int not null default 0, 25 swt2a int not null default 0, 26 27 st_b int not null default 0, 28 swt1b int not null default 0, 29 swt2b int not null default 0, 30 31 /* fields/keys for row retrieval tests */ 32 key1 int, 33 key2 int, 34 key3 int, 35 key4 int, 36 37 /* make rows much bigger then keys */ 38 filler1 char (200), 39 filler2 char (200), 40 filler3 char (200), 41 filler4 char (200), 42 filler5 char (200), 43 filler6 char (200), 44 45 /* order of keys is important */ 46 key sta_swt12a(st_a,swt1a,swt2a), 47 key sta_swt1a(st_a,swt1a), 48 key sta_swt2a(st_a,swt2a), 49 key sta_swt21a(st_a,swt2a,swt1a), 50 51 key st_a(st_a), 52 key stb_swt1a_2b(st_b,swt1b,swt2a), 53 key stb_swt1b(st_b,swt1b), 54 key st_b(st_b), 55 56 key(key1), 57 key(key2), 58 key(key3), 59 key(key4) 60) ; 61# Fill table 62create table t0 as select * from t1; 63--disable_query_log 64--echo # Printing of many insert into t0 values (....) disabled. 65begin; 66let $cnt=1000; 67while ($cnt) 68{ 69 eval insert into t0 values (1, 2, 3, 1, 2, 3, 0, 0, 0, 0, 'data1', 'data2', 'data3', 'data4', 'data5', 'data6'); 70 dec $cnt; 71} 72commit; 73--enable_query_log 74 75alter table t1 disable keys; 76--disable_query_log 77--echo # Printing of many insert into t1 select .... from t0 disabled. 78let $1=4; 79begin; 80while ($1) 81{ 82 let $2=4; 83 while ($2) 84 { 85 let $3=4; 86 while ($3) 87 { 88 eval insert into t1 select $1, $2, $3, $1 ,$2, $3, key1, key2, key3, key4, filler1, filler2, filler3, filler4, filler5, filler6 from t0; 89 dec $3; 90 } 91 dec $2; 92 } 93 dec $1; 94} 95commit; 96 97--echo # Printing of many insert into t1 (...) values (....) disabled. 98# Row retrieval tests 99# -1 is used for values 'out of any range we are using' 100# insert enough rows for index intersection to be used for (key1,key2) 101insert into t1 (key1, key2, key3, key4, filler1) values (100, 100, 100, 100,'key1-key2-key3-key4'); 102let $cnt=400; 103begin; 104while ($cnt) 105{ 106 eval insert into t1 (key1, key2, key3, key4, filler1) values (100, -1, 100, -1,'key1-key3'); 107 dec $cnt; 108} 109let $cnt=400; 110while ($cnt) 111{ 112 eval insert into t1 (key1, key2, key3, key4, filler1) values (-1, 100, -1, 100,'key2-key4'); 113 dec $cnt; 114} 115commit; 116--enable_query_log 117alter table t1 enable keys; 118select count(*) from t1; 119 120# One row results tests for cases where a single row matches all conditions 121explain select key1,key2 from t1 where key1=100 and key2=100; 122select key1,key2 from t1 where key1=100 and key2=100; 123explain select key1,key2,key3,key4,filler1 from t1 where key1=100 and key2=100 or key3=100 and key4=100; 124select key1,key2,key3,key4,filler1 from t1 where key1=100 and key2=100 or key3=100 and key4=100; 125 126# Several-rows results 127insert into t1 (key1, key2, key3, key4, filler1) values (100, 100, -1, -1, 'key1-key2'); 128insert into t1 (key1, key2, key3, key4, filler1) values (-1, -1, 100, 100, 'key4-key3'); 129 130# ROR-intersection, not covering 131explain select key1,key2,filler1 from t1 where key1=100 and key2=100; 132select key1,key2,filler1 from t1 where key1=100 and key2=100; 133 134# ROR-intersection, covering 135explain select key1,key2 from t1 where key1=100 and key2=100; 136select key1,key2 from t1 where key1=100 and key2=100; 137 138# ROR-union of ROR-intersections 139explain select key1,key2,key3,key4 from t1 where key1=100 and key2=100 or key3=100 and key4=100; 140select key1,key2,key3,key4 from t1 where key1=100 and key2=100 or key3=100 and key4=100; 141explain select key1,key2,key3,key4,filler1 from t1 where key1=100 and key2=100 or key3=100 and key4=100; 142select key1,key2,key3,key4,filler1 from t1 where key1=100 and key2=100 or key3=100 and key4=100; 143 144# 3-way ROR-intersection 145explain select key1,key2,key3 from t1 where key1=100 and key2=100 and key3=100; 146select key1,key2,key3 from t1 where key1=100 and key2=100 and key3=100; 147 148# ROR-union(ROR-intersection, ROR-range) 149insert into t1 (key1,key2,key3,key4,filler1) values (101,101,101,101, 'key1234-101'); 150explain select key1,key2,key3,key4,filler1 from t1 where key1=100 and key2=100 or key3=101; 151select key1,key2,key3,key4,filler1 from t1 where key1=100 and key2=100 or key3=101; 152 153# Run some ROR updates/deletes 154select key1,key2, filler1 from t1 where key1=100 and key2=100; 155update t1 set filler1='to be deleted' where key1=100 and key2=100; 156update t1 set key1=200,key2=200 where key1=100 and key2=100; 157delete from t1 where key1=200 and key2=200; 158select key1,key2,filler1 from t1 where key2=100 and key2=200; 159 160# ROR-union(ROR-intersection) with one of ROR-intersection giving empty 161# results 162explain select key1,key2,key3,key4,filler1 from t1 where key1=100 and key2=100 or key3=100 and key4=100; 163select key1,key2,key3,key4,filler1 from t1 where key1=100 and key2=100 or key3=100 and key4=100; 164 165delete from t1 where key3=100 and key4=100; 166 167# ROR-union with all ROR-intersections giving empty results 168explain select key1,key2,key3,key4,filler1 from t1 where key1=100 and key2=100 or key3=100 and key4=100; 169select key1,key2,key3,key4,filler1 from t1 where key1=100 and key2=100 or key3=100 and key4=100; 170 171# ROR-intersection with empty result 172explain select key1,key2 from t1 where key1=100 and key2=100; 173select key1,key2 from t1 where key1=100 and key2=100; 174 175# ROR-union tests with various cases. 176# All scans returning duplicate rows: 177insert into t1 (key1, key2, key3, key4, filler1) values (100, 100, 200, 200,'key1-key2-key3-key4-1'); 178insert into t1 (key1, key2, key3, key4, filler1) values (100, 100, 200, 200,'key1-key2-key3-key4-2'); 179insert into t1 (key1, key2, key3, key4, filler1) values (100, 100, 200, 200,'key1-key2-key3-key4-3'); 180 181explain select key1,key2,key3,key4,filler1 from t1 where key3=200 or (key1=100 and key2=100) or key4=200; 182select key1,key2,key3,key4,filler1 from t1 where key3=200 or (key1=100 and key2=100) or key4=200; 183 184insert into t1 (key1, key2, key3, key4, filler1) values (-1, -1, -1, 200,'key4'); 185 186explain select key1,key2,key3,key4,filler1 from t1 where key3=200 or (key1=100 and key2=100) or key4=200; 187select key1,key2,key3,key4,filler1 from t1 where key3=200 or (key1=100 and key2=100) or key4=200; 188 189insert into t1 (key1, key2, key3, key4, filler1) values (-1, -1, 200, -1,'key3'); 190 191explain select key1,key2,key3,key4,filler1 from t1 where key3=200 or (key1=100 and key2=100) or key4=200; 192select key1,key2,key3,key4,filler1 from t1 where key3=200 or (key1=100 and key2=100) or key4=200; 193 194## 195## Optimizer tests 196## 197 198# Check that the shortest key is used for ROR-intersection, covering and non-covering. 199explain select * from t1 where st_a=1 and st_b=1; 200explain select st_a,st_b from t1 where st_a=1 and st_b=1; 201 202# Check if "ingore index" syntax works 203explain select st_a from t1 ignore index (st_a) where st_a=1 and st_b=1; 204 205# Do many tests 206# Check that keys that don't improve selectivity are skipped. 207# 208 209# Different value on 32 and 64 bit 210--replace_result sta_swt12a sta_swt21a sta_swt12a, sta_swt12a, 211explain select * from t1 where st_a=1 and swt1a=1 and swt2a=1; 212 213explain select * from t1 where st_b=1 and swt1b=1 and swt2b=1; 214 215explain select * from t1 where st_a=1 and swt1a=1 and swt2a=1 and st_b=1 and swt1b=1 and swt2b=1; 216 217explain select * from t1 ignore index (sta_swt21a, stb_swt1a_2b) 218 where st_a=1 and swt1a=1 and swt2a=1 and st_b=1 and swt1b=1 and swt2b=1; 219 220explain select * from t1 ignore index (sta_swt21a, sta_swt12a, stb_swt1a_2b) 221 where st_a=1 and swt1a=1 and swt2a=1 and st_b=1 and swt1b=1 and swt2b=1; 222 223explain select * from t1 ignore index (sta_swt21a, sta_swt12a, stb_swt1a_2b, stb_swt1b) 224 where st_a=1 and swt1a=1 and swt2a=1 and st_b=1 and swt1b=1 and swt2b=1; 225 226explain select * from t1 227 where st_a=1 and swt1a=1 and swt2a=1 and st_b=1 and swt1b=1; 228 229explain select * from t1 230 where st_a=1 and swt1a=1 and st_b=1 and swt1b=1 and swt1b=1; 231 232explain select st_a from t1 233 where st_a=1 and swt1a=1 and st_b=1 and swt1b=1 and swt1b=1; 234 235explain select st_a from t1 236 where st_a=1 and swt1a=1 and st_b=1 and swt1b=1 and swt1b=1; 237 238drop table t0,t1; 239 240# 'Partially' covered fields test 241 242create table t2 ( 243 a char(10), 244 b char(10), 245 filler1 char(255), 246 filler2 char(255), 247 key(a(5)), 248 key(b(5)) 249); 250 251--disable_query_log 252let $1=8; 253begin; 254while ($1) 255{ 256 eval insert into t2 values (repeat(char($1+64), 8),repeat(char($1+64), 8),'filler1', 'filler2'); 257 dec $1; 258} 259insert into t2 select * from t2; 260insert into t2 select * from t2; 261commit; 262--enable_query_log 263 264# The table row buffer is reused. Fill it with rows that don't match. 265select count(a) from t2 where a='BBBBBBBB'; 266select count(a) from t2 where b='BBBBBBBB'; 267 268# BUG#1: 269--replace_result a a_or_b b a_or_b 270explain select count(a) from t2 where a='AAAAAAAA' and b='AAAAAAAA'; 271select count(a) from t2 where a='AAAAAAAA' and b='AAAAAAAA'; 272select count(a) from t2 ignore index(a,b) where a='AAAAAAAA' and b='AAAAAAAA'; 273 274insert into t2 values ('ab', 'ab', 'uh', 'oh'); 275explain select a from t2 where a='ab'; 276drop table t2; 277 278# 279# BUG#25048 - ERROR 126 : Incorrect key file for table '.XXXX.MYI'; try to 280# repair it 281# 282CREATE TABLE t1(c1 INT, c2 INT DEFAULT 0, c3 CHAR(255) DEFAULT '', 283KEY(c1), KEY(c2), KEY(c3)); 284INSERT INTO t1(c1) VALUES(0),(0),(0),(0),(0),(0),(0),(0),(0),(0),(0),(0),(0), 285(0),(0),(0),(0),(0),(0),(0),(0),(0),(0),(0),(0),(0),(0),(0),(0); 286INSERT INTO t1 VALUES(0,0,0); 287CREATE TABLE t2(c1 int); 288INSERT INTO t2 VALUES(1); 289DELETE t1 FROM t1,t2 WHERE t1.c1=0 AND t1.c2=0; 290SELECT * FROM t1; 291DROP TABLE t1,t2; 292