Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Test case updates. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | nextgen-query-plan-exp |
Files: | files | file ages | folders |
SHA1: |
0360fec7c093870269211447e9642b5e |
User & Date: | drh 2013-06-04 15:31:16.980 |
Context
2013-06-04
| ||
18:03 | Get the index-only optimization working for OR queries. (check-in: 774d5ff857 user: drh tags: nextgen-query-plan-exp) | |
15:31 | Test case updates. (check-in: 0360fec7c0 user: drh tags: nextgen-query-plan-exp) | |
13:37 | Better determination of when an index is UNIQUE. (check-in: 63fd025ad9 user: drh tags: nextgen-query-plan-exp) | |
Changes
Changes to test/orderby1.test.
︙ | ︙ | |||
44 45 46 47 48 49 50 | (NULL, 2, 1, 'two-a'), (NULL, 3, 1, 'three-a'); COMMIT; } } {} do_test 1.1a { db eval { | | | | | | | | | | | | | | | > | > | > | | 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 73 74 75 76 77 78 79 80 81 82 83 84 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 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 | (NULL, 2, 1, 'two-a'), (NULL, 3, 1, 'three-a'); COMMIT; } } {} do_test 1.1a { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn } } {one-a one-c two-a two-b three-a three-c} # Verify that the ORDER BY clause is optimized out # do_test 1.1b { db eval { EXPLAIN QUERY PLAN SELECT name FROM album CROSS JOIN track USING (aid) ORDER BY title, tn } } {~/ORDER BY/} ;# ORDER BY optimized out # The same query with ORDER BY clause optimization disabled via + operators # should give exactly the same answer. # do_test 1.2a { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn } } {one-a one-c two-a two-b three-a three-c} # The output is sorted manually in this case. # do_test 1.2b { db eval { EXPLAIN QUERY PLAN SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn } } {/ORDER BY/} ;# separate sorting pass due to "+" on ORDER BY terms # The same query with ORDER BY optimizations turned off via built-in test. # do_test 1.3a { optimization_control db order-by-idx-join 0 db cache flush db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn } } {one-a one-c two-a two-b three-a three-c} do_test 1.3b { db eval { EXPLAIN QUERY PLAN SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn } } {/ORDER BY/} ;# separate sorting pass due to disabled optimization optimization_control db all 1 db cache flush # Reverse order sorts # do_test 1.4a { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY title DESC, tn } } {three-a three-c two-a two-b one-a one-c} do_test 1.4b { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY +title DESC, +tn } } {three-a three-c two-a two-b one-a one-c} ;# verify same order after sorting do_test 1.4c { db eval { EXPLAIN QUERY PLAN SELECT name FROM album JOIN track USING (aid) ORDER BY title DESC, tn } } {/ORDER BY/} ;# separate sorting pass due to mixed DESC/ASC do_test 1.5a { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn DESC } } {one-c one-a two-b two-a three-c three-a} do_test 1.5b { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn DESC } } {one-c one-a two-b two-a three-c three-a} ;# verify same order after sorting do_test 1.5c { db eval { EXPLAIN QUERY PLAN SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn DESC } } {/ORDER BY/} ;# separate sorting pass due to mixed DESC/ASC do_test 1.6a { db eval { SELECT name FROM album CROSS JOIN track USING (aid) ORDER BY title DESC, tn DESC } } {three-c three-a two-b two-a one-c one-a} do_test 1.6b { db eval { SELECT name FROM album CROSS JOIN track USING (aid) ORDER BY +title DESC, +tn DESC } } {three-c three-a two-b two-a one-c one-a} ;# verify same order after sorting do_test 1.6c { db eval { EXPLAIN QUERY PLAN SELECT name FROM album CROSS JOIN track USING (aid) ORDER BY title DESC, tn DESC } } {~/ORDER BY/} ;# ORDER BY # Reconstruct the test data to use indices rather than integer primary keys. # do_test 2.0 { db eval { BEGIN; |
︙ | ︙ | |||
179 180 181 182 183 184 185 | (20, 1, 'two-a'), (3, 1, 'three-a'); COMMIT; } } {} do_test 2.1a { db eval { | | | | | | | | | | | | | | | | | | | | | | | | 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 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 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 | (20, 1, 'two-a'), (3, 1, 'three-a'); COMMIT; } } {} do_test 2.1a { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn } } {one-a one-c two-a two-b three-a three-c} # Verify that the ORDER BY clause is optimized out # do_test 2.1b { db eval { EXPLAIN QUERY PLAN SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn } } {/ORDER BY/} ;# ORDER BY required because of missing aid term in ORDER BY do_test 2.1c { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY title, aid, tn } } {one-a one-c two-a two-b three-a three-c} do_test 2.1d { db eval { EXPLAIN QUERY PLAN SELECT name FROM album JOIN track USING (aid) ORDER BY title, aid, tn } } {/ORDER BY/} ;# ORDER BY required in this case # The same query with ORDER BY clause optimization disabled via + operators # should give exactly the same answer. # do_test 2.2a { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn } } {one-a one-c two-a two-b three-a three-c} # The output is sorted manually in this case. # do_test 2.2b { db eval { EXPLAIN QUERY PLAN SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn } } {/ORDER BY/} ;# separate sorting pass due to "+" on ORDER BY terms # The same query with ORDER BY optimizations turned off via built-in test. # do_test 2.3a { optimization_control db order-by-idx-join 0 db cache flush db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn } } {one-a one-c two-a two-b three-a three-c} do_test 2.3b { db eval { EXPLAIN QUERY PLAN SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn } } {/ORDER BY/} ;# separate sorting pass due to disabled optimization optimization_control db all 1 db cache flush # Reverse order sorts # do_test 2.4a { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY title DESC, tn } } {three-a three-c two-a two-b one-a one-c} do_test 2.4b { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY +title DESC, +tn } } {three-a three-c two-a two-b one-a one-c} ;# verify same order after sorting do_test 2.4c { db eval { EXPLAIN QUERY PLAN SELECT name FROM album JOIN track USING (aid) ORDER BY title DESC, tn } } {/ORDER BY/} ;# separate sorting pass due to mixed DESC/ASC do_test 2.5a { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn DESC } } {one-c one-a two-b two-a three-c three-a} do_test 2.5b { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn DESC } } {one-c one-a two-b two-a three-c three-a} ;# verify same order after sorting do_test 2.5c { db eval { EXPLAIN QUERY PLAN SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn DESC } } {/ORDER BY/} ;# separate sorting pass due to mixed ASC/DESC do_test 2.6a { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY title DESC, tn DESC } } {three-c three-a two-b two-a one-c one-a} do_test 2.6b { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY +title DESC, +tn DESC } } {three-c three-a two-b two-a one-c one-a} ;# verify same order after sorting do_test 2.6c { db eval { EXPLAIN QUERY PLAN SELECT name FROM album JOIN track USING (aid) ORDER BY title DESC, tn DESC } } {/ORDER BY/} ;# ORDER BY required # Generate another test dataset, but this time using mixed ASC/DESC indices. # do_test 3.0 { db eval { BEGIN; |
︙ | ︙ | |||
344 345 346 347 348 349 350 | } {~/ORDER BY/} ;# ORDER BY optimized out # The same query with ORDER BY clause optimization disabled via + operators # should give exactly the same answer. # do_test 3.2a { db eval { | | | | | | | | | | | | | | > > > > > > > > > > > > > > > > > > | 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 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 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 | } {~/ORDER BY/} ;# ORDER BY optimized out # The same query with ORDER BY clause optimization disabled via + operators # should give exactly the same answer. # do_test 3.2a { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn DESC } } {one-c one-a two-b two-a three-c three-a} # The output is sorted manually in this case. # do_test 3.2b { db eval { EXPLAIN QUERY PLAN SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn DESC } } {/ORDER BY/} ;# separate sorting pass due to "+" on ORDER BY terms # The same query with ORDER BY optimizations turned off via built-in test. # do_test 3.3a { optimization_control db order-by-idx-join 0 db cache flush db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn DESC } } {one-c one-a two-b two-a three-c three-a} do_test 3.3b { db eval { EXPLAIN QUERY PLAN SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn DESC } } {/ORDER BY/} ;# separate sorting pass due to disabled optimization optimization_control db all 1 db cache flush # Without the mixed ASC/DESC on ORDER BY # do_test 3.4a { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn } } {one-a one-c two-a two-b three-a three-c} do_test 3.4b { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn } } {one-a one-c two-a two-b three-a three-c} ;# verify same order after sorting do_test 3.4c { db eval { EXPLAIN QUERY PLAN SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn } } {/ORDER BY/} ;# separate sorting pass due to mismatched DESC/ASC do_test 3.5a { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY title DESC, tn DESC } } {three-c three-a two-b two-a one-c one-a} do_test 3.5b { db eval { SELECT name FROM album JOIN track USING (aid) ORDER BY +title DESC, +tn DESC } } {three-c three-a two-b two-a one-c one-a} ;# verify same order after sorting do_test 3.5c { db eval { EXPLAIN QUERY PLAN SELECT name FROM album JOIN track USING (aid) ORDER BY title DESC, tn DESC } } {/ORDER BY/} ;# separate sorting pass due to mismatched ASC/DESC do_test 3.6a { db eval { SELECT name FROM album CROSS JOIN track USING (aid) ORDER BY title DESC, tn } } {three-a three-c two-a two-b one-a one-c} do_test 3.6b { db eval { SELECT name FROM album CROSS JOIN track USING (aid) ORDER BY +title DESC, +tn } } {three-a three-c two-a two-b one-a one-c} ;# verify same order after sorting do_test 3.6c { db eval { EXPLAIN QUERY PLAN SELECT name FROM album CROSS JOIN track USING (aid) ORDER BY title DESC, tn } } {~/ORDER BY/} ;# inverted ASC/DESC is optimized out # Ticket 5ed1772895bf3deeab78c5e3519b1da9165c541b (2013-06-04) # Incorrect ORDER BY on an indexed JOIN # do_test 4.0 { db eval { CREATE TABLE t41(a INT UNIQUE NOT NULL, b INT NOT NULL); CREATE INDEX t41ba ON t41(b,a); CREATE TABLE t42(x INT NOT NULL REFERENCES t41(a), y INT NOT NULL); CREATE UNIQUE INDEX t42xy ON t42(x,y); INSERT INTO t41 VALUES(1,1),(3,1); INSERT INTO t42 VALUES(1,13),(1,15),(3,14),(3,16); SELECT b, y FROM t41 CROSS JOIN t42 ON x=a ORDER BY b, y; } } {1 13 1 14 1 15 1 16} finish_test |