Annotation of embedaddon/sqlite3/test/analyze6.test, revision 1.1
1.1 ! misho 1: # 2011 March 3
! 2: #
! 3: # The author disclaims copyright to this source code. In place of
! 4: # a legal notice, here is a blessing:
! 5: #
! 6: # May you do good and not evil.
! 7: # May you find forgiveness for yourself and forgive others.
! 8: # May you share freely, never taking more than you give.
! 9: #
! 10: #***********************************************************************
! 11: #
! 12: # This file implements tests for SQLite library. The focus of the tests
! 13: # in this file a corner-case query planner optimization involving the
! 14: # join order of two tables of different sizes.
! 15: #
! 16:
! 17: set testdir [file dirname $argv0]
! 18: source $testdir/tester.tcl
! 19:
! 20: ifcapable !stat3 {
! 21: finish_test
! 22: return
! 23: }
! 24:
! 25: set testprefix analyze6
! 26:
! 27: proc eqp {sql {db db}} {
! 28: uplevel execsql [list "EXPLAIN QUERY PLAN $sql"] $db
! 29: }
! 30:
! 31: do_test analyze6-1.0 {
! 32: db eval {
! 33: CREATE TABLE cat(x INT);
! 34: CREATE UNIQUE INDEX catx ON cat(x);
! 35: /* Give cat 16 unique integers */
! 36: INSERT INTO cat VALUES(1);
! 37: INSERT INTO cat VALUES(2);
! 38: INSERT INTO cat SELECT x+2 FROM cat;
! 39: INSERT INTO cat SELECT x+4 FROM cat;
! 40: INSERT INTO cat SELECT x+8 FROM cat;
! 41:
! 42: CREATE TABLE ev(y INT);
! 43: CREATE INDEX evy ON ev(y);
! 44: /* ev will hold 32 copies of 16 integers found in cat */
! 45: INSERT INTO ev SELECT x FROM cat;
! 46: INSERT INTO ev SELECT x FROM cat;
! 47: INSERT INTO ev SELECT y FROM ev;
! 48: INSERT INTO ev SELECT y FROM ev;
! 49: INSERT INTO ev SELECT y FROM ev;
! 50: INSERT INTO ev SELECT y FROM ev;
! 51: ANALYZE;
! 52: SELECT count(*) FROM cat;
! 53: SELECT count(*) FROM ev;
! 54: }
! 55: } {16 512}
! 56:
! 57: # The lowest cost plan is to scan CAT and for each integer there, do a single
! 58: # lookup of the first corresponding entry in EV then read off the equal values
! 59: # in EV. (Prior to the 2011-03-04 enhancement to where.c, this query would
! 60: # have used EV for the outer loop instead of CAT - which was about 3x slower.)
! 61: #
! 62: do_test analyze6-1.1 {
! 63: eqp {SELECT count(*) FROM ev, cat WHERE x=y}
! 64: } {0 0 1 {SCAN TABLE cat (~16 rows)} 0 1 0 {SEARCH TABLE ev USING COVERING INDEX evy (y=?) (~32 rows)}}
! 65:
! 66: # The same plan is chosen regardless of the order of the tables in the
! 67: # FROM clause.
! 68: #
! 69: do_test analyze6-1.2 {
! 70: eqp {SELECT count(*) FROM cat, ev WHERE x=y}
! 71: } {0 0 0 {SCAN TABLE cat (~16 rows)} 0 1 1 {SEARCH TABLE ev USING COVERING INDEX evy (y=?) (~32 rows)}}
! 72:
! 73:
! 74: # Ticket [83ea97620bd3101645138b7b0e71c12c5498fe3d] 2011-03-30
! 75: # If ANALYZE is run on an empty table, make sure indices are used
! 76: # on the table.
! 77: #
! 78: do_test analyze6-2.1 {
! 79: execsql {
! 80: CREATE TABLE t201(x INTEGER PRIMARY KEY, y UNIQUE, z);
! 81: CREATE INDEX t201z ON t201(z);
! 82: ANALYZE;
! 83: }
! 84: eqp {SELECT * FROM t201 WHERE z=5}
! 85: } {0 0 0 {SEARCH TABLE t201 USING INDEX t201z (z=?) (~10 rows)}}
! 86: do_test analyze6-2.2 {
! 87: eqp {SELECT * FROM t201 WHERE y=5}
! 88: } {0 0 0 {SEARCH TABLE t201 USING INDEX sqlite_autoindex_t201_1 (y=?) (~1 rows)}}
! 89: do_test analyze6-2.3 {
! 90: eqp {SELECT * FROM t201 WHERE x=5}
! 91: } {0 0 0 {SEARCH TABLE t201 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
! 92: do_test analyze6-2.4 {
! 93: execsql {
! 94: INSERT INTO t201 VALUES(1,2,3);
! 95: ANALYZE t201;
! 96: }
! 97: eqp {SELECT * FROM t201 WHERE z=5}
! 98: } {0 0 0 {SEARCH TABLE t201 USING INDEX t201z (z=?) (~10 rows)}}
! 99: do_test analyze6-2.5 {
! 100: eqp {SELECT * FROM t201 WHERE y=5}
! 101: } {0 0 0 {SEARCH TABLE t201 USING INDEX sqlite_autoindex_t201_1 (y=?) (~1 rows)}}
! 102: do_test analyze6-2.6 {
! 103: eqp {SELECT * FROM t201 WHERE x=5}
! 104: } {0 0 0 {SEARCH TABLE t201 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
! 105: do_test analyze6-2.7 {
! 106: execsql {
! 107: INSERT INTO t201 VALUES(4,5,7);
! 108: INSERT INTO t201 SELECT x+100, y+100, z+100 FROM t201;
! 109: INSERT INTO t201 SELECT x+200, y+200, z+200 FROM t201;
! 110: INSERT INTO t201 SELECT x+400, y+400, z+400 FROM t201;
! 111: ANALYZE t201;
! 112: }
! 113: eqp {SELECT * FROM t201 WHERE z=5}
! 114: } {0 0 0 {SEARCH TABLE t201 USING INDEX t201z (z=?) (~10 rows)}}
! 115: do_test analyze6-2.8 {
! 116: eqp {SELECT * FROM t201 WHERE y=5}
! 117: } {0 0 0 {SEARCH TABLE t201 USING INDEX sqlite_autoindex_t201_1 (y=?) (~1 rows)}}
! 118: do_test analyze6-2.9 {
! 119: eqp {SELECT * FROM t201 WHERE x=5}
! 120: } {0 0 0 {SEARCH TABLE t201 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
! 121:
! 122: finish_test
FreeBSD-CVSweb <freebsd-cvsweb@FreeBSD.org>