xref: /sqlite-3.40.0/test/analyze8.test (revision 8210233c)
1461728d3Sdrh# 2011 August 13
2461728d3Sdrh#
3461728d3Sdrh# The author disclaims copyright to this source code.  In place of
4461728d3Sdrh# a legal notice, here is a blessing:
5461728d3Sdrh#
6461728d3Sdrh#    May you do good and not evil.
7461728d3Sdrh#    May you find forgiveness for yourself and forgive others.
8461728d3Sdrh#    May you share freely, never taking more than you give.
9461728d3Sdrh#
10461728d3Sdrh#***********************************************************************
11461728d3Sdrh#
12461728d3Sdrh# This file implements tests for SQLite library.  The focus of the tests
13175b8f06Sdrh# in this file is testing the capabilities of sqlite_stat4.
14461728d3Sdrh#
15461728d3Sdrh
16461728d3Sdrhset testdir [file dirname $argv0]
17461728d3Sdrhsource $testdir/tester.tcl
18461728d3Sdrh
19175b8f06Sdrhifcapable !stat4 {
20461728d3Sdrh  finish_test
21461728d3Sdrh  return
22461728d3Sdrh}
23461728d3Sdrh
24461728d3Sdrhset testprefix analyze8
25461728d3Sdrh
26461728d3Sdrhproc eqp {sql {db db}} {
27461728d3Sdrh  uplevel execsql [list "EXPLAIN QUERY PLAN $sql"] $db
28461728d3Sdrh}
29461728d3Sdrh
30461728d3Sdrh# Scenario:
31461728d3Sdrh#
32461728d3Sdrh#    Two indices.  One has mostly singleton entries, but for a few
33461728d3Sdrh#    values there are hundreds of entries.  The other has 10-20
34461728d3Sdrh#    entries per value.
35461728d3Sdrh#
36461728d3Sdrh# Verify that the query planner chooses the first index for the singleton
37461728d3Sdrh# entries and the second index for the others.
38461728d3Sdrh#
39461728d3Sdrhdo_test 1.0 {
40461728d3Sdrh  db eval {
41461728d3Sdrh    CREATE TABLE t1(a,b,c,d);
42461728d3Sdrh    CREATE INDEX t1a ON t1(a);
43461728d3Sdrh    CREATE INDEX t1b ON t1(b);
44461728d3Sdrh    CREATE INDEX t1c ON t1(c);
45461728d3Sdrh  }
46461728d3Sdrh  for {set i 0} {$i<1000} {incr i} {
47461728d3Sdrh    if {$i%2==0} {set a $i} {set a [expr {($i%8)*100}]}
48461728d3Sdrh    set b [expr {$i/10}]
49461728d3Sdrh    set c [expr {$i/8}]
50461728d3Sdrh    set c [expr {$c*$c*$c}]
51461728d3Sdrh    db eval {INSERT INTO t1 VALUES($a,$b,$c,$i)}
52461728d3Sdrh  }
53461728d3Sdrh  db eval {ANALYZE}
54461728d3Sdrh} {}
55461728d3Sdrh
56461728d3Sdrh# The a==100 comparison is expensive because there are many rows
57461728d3Sdrh# with a==100.  And so for those cases, choose the t1b index.
58461728d3Sdrh#
59461728d3Sdrh# Buf ro a==99 and a==101, there are far fewer rows so choose
60461728d3Sdrh# the t1a index.
61461728d3Sdrh#
62461728d3Sdrhdo_test 1.1 {
63461728d3Sdrh  eqp {SELECT * FROM t1 WHERE a=100 AND b=55}
64*8210233cSdrh} {/*SEARCH t1 USING INDEX t1b (b=?)*/}
65461728d3Sdrhdo_test 1.2 {
66461728d3Sdrh  eqp {SELECT * FROM t1 WHERE a=99 AND b=55}
67*8210233cSdrh} {/*SEARCH t1 USING INDEX t1a (a=?)*/}
68461728d3Sdrhdo_test 1.3 {
69461728d3Sdrh  eqp {SELECT * FROM t1 WHERE a=101 AND b=55}
70*8210233cSdrh} {/*SEARCH t1 USING INDEX t1a (a=?)*/}
71461728d3Sdrhdo_test 1.4 {
72461728d3Sdrh  eqp {SELECT * FROM t1 WHERE a=100 AND b=56}
73*8210233cSdrh} {/*SEARCH t1 USING INDEX t1b (b=?)*/}
74461728d3Sdrhdo_test 1.5 {
75461728d3Sdrh  eqp {SELECT * FROM t1 WHERE a=99 AND b=56}
76*8210233cSdrh} {/*SEARCH t1 USING INDEX t1a (a=?)*/}
77461728d3Sdrhdo_test 1.6 {
78461728d3Sdrh  eqp {SELECT * FROM t1 WHERE a=101 AND b=56}
79*8210233cSdrh} {/*SEARCH t1 USING INDEX t1a (a=?)*/}
80461728d3Sdrhdo_test 2.1 {
81461728d3Sdrh  eqp {SELECT * FROM t1 WHERE a=100 AND b BETWEEN 50 AND 54}
82*8210233cSdrh} {/*SEARCH t1 USING INDEX t1b (b>? AND b<?)*/}
83461728d3Sdrh
84461728d3Sdrh# There are many more values of c between 0 and 100000 than there are
85461728d3Sdrh# between 800000 and 900000.  So t1c is more selective for the latter
86461728d3Sdrh# range.
87461728d3Sdrh#
886cb8d76cSdan# Test 3.2 is a little unstable. It depends on the planner estimating
896d3f91d0Sdrh# that (b BETWEEN 30 AND 34) will match more rows than (c BETWEEN
906cb8d76cSdan# 800000 AND 900000). Which is a pretty close call (50 vs. 32), so
916cb8d76cSdan# the planner could get it wrong with an unlucky set of samples. This
92f00e9025Sdan# case happens to work, but others ("b BETWEEN 40 AND 44" for example)
936cb8d76cSdan# will fail.
946cb8d76cSdan#
956cb8d76cSdando_execsql_test 3.0 {
966d3f91d0Sdrh  SELECT count(*) FROM t1 WHERE b BETWEEN 30 AND 34;
976cb8d76cSdan  SELECT count(*) FROM t1 WHERE c BETWEEN 0 AND 100000;
986cb8d76cSdan  SELECT count(*) FROM t1 WHERE c BETWEEN 800000 AND 900000;
996cb8d76cSdan} {50 376 32}
100461728d3Sdrhdo_test 3.1 {
1016d3f91d0Sdrh  eqp {SELECT * FROM t1 WHERE b BETWEEN 30 AND 34 AND c BETWEEN 0 AND 100000}
102*8210233cSdrh} {/*SEARCH t1 USING INDEX t1b (b>? AND b<?)*/}
103461728d3Sdrhdo_test 3.2 {
104461728d3Sdrh  eqp {SELECT * FROM t1
1056d3f91d0Sdrh       WHERE b BETWEEN 30 AND 34 AND c BETWEEN 800000 AND 900000}
106*8210233cSdrh} {/*SEARCH t1 USING INDEX t1c (c>? AND c<?)*/}
107461728d3Sdrhdo_test 3.3 {
108461728d3Sdrh  eqp {SELECT * FROM t1 WHERE a=100 AND c BETWEEN 0 AND 100000}
109*8210233cSdrh} {/*SEARCH t1 USING INDEX t1a (a=?)*/}
110461728d3Sdrhdo_test 3.4 {
111461728d3Sdrh  eqp {SELECT * FROM t1
112461728d3Sdrh       WHERE a=100 AND c BETWEEN 800000 AND 900000}
113*8210233cSdrh} {/*SEARCH t1 USING INDEX t1c (c>? AND c<?)*/}
114461728d3Sdrh
115461728d3Sdrhfinish_test
116