xref: /sqlite-3.40.0/test/skipscan2.test (revision ce00a837)
1# 2013-11-27
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 of the "skip-scan" query strategy.
13#
14# The test cases in this file are derived from the description of
15# the skip-scan query strategy in the "optoverview.html" document.
16#
17
18set testdir [file dirname $argv0]
19source $testdir/tester.tcl
20
21do_execsql_test skipscan2-1.1 {
22  CREATE TABLE people(
23    name TEXT PRIMARY KEY,
24    role TEXT NOT NULL,
25    height INT NOT NULL, -- in cm
26    CHECK( role IN ('student','teacher') )
27  );
28  CREATE INDEX people_idx1 ON people(role, height);
29} {}
30do_execsql_test skipscan2-1.2 {
31  INSERT INTO people VALUES('Alice','student',156);
32  INSERT INTO people VALUES('Bob','student',161);
33  INSERT INTO people VALUES('Cindy','student',155);
34  INSERT INTO people VALUES('David','student',181);
35  INSERT INTO people VALUES('Emily','teacher',158);
36  INSERT INTO people VALUES('Fred','student',163);
37  INSERT INTO people VALUES('Ginny','student',169);
38  INSERT INTO people VALUES('Harold','student',172);
39  INSERT INTO people VALUES('Imma','student',179);
40  INSERT INTO people VALUES('Jack','student',181);
41  INSERT INTO people VALUES('Karen','student',163);
42  INSERT INTO people VALUES('Logan','student',177);
43  INSERT INTO people VALUES('Megan','teacher',159);
44  INSERT INTO people VALUES('Nathan','student',163);
45  INSERT INTO people VALUES('Olivia','student',161);
46  INSERT INTO people VALUES('Patrick','teacher',180);
47  INSERT INTO people VALUES('Quiana','student',182);
48  INSERT INTO people VALUES('Robert','student',159);
49  INSERT INTO people VALUES('Sally','student',166);
50  INSERT INTO people VALUES('Tom','student',171);
51  INSERT INTO people VALUES('Ursula','student',170);
52  INSERT INTO people VALUES('Vance','student',179);
53  INSERT INTO people VALUES('Willma','student',175);
54  INSERT INTO people VALUES('Xavier','teacher',185);
55  INSERT INTO people VALUES('Yvonne','student',149);
56  INSERT INTO people VALUES('Zach','student',170);
57}
58
59# Without ANALYZE, a skip-scan is not used
60#
61do_execsql_test skipscan2-1.3 {
62  SELECT name FROM people WHERE height>=180 ORDER BY +name;
63} {David Jack Patrick Quiana Xavier}
64do_execsql_test skipscan2-1.3eqp {
65  EXPLAIN QUERY PLAN
66  SELECT name FROM people WHERE height>=180 ORDER BY +name;
67} {~/*INDEX people_idx1 */}
68
69# Now do an ANALYZE.  A skip-scan can be used after ANALYZE.
70#
71do_execsql_test skipscan2-1.4 {
72  ANALYZE;
73  -- We do not have enough people above to actually force the use
74  -- of a skip-scan.  So make a manual adjustment to the stat1 table
75  -- to make it seem like there are many more.
76  UPDATE sqlite_stat1 SET stat='10000 5000 20' WHERE idx='people_idx1';
77  ANALYZE sqlite_master;
78}
79db cache flush
80do_execsql_test skipscan2-1.5 {
81  SELECT name FROM people WHERE height>=180 ORDER BY +name;
82} {David Jack Patrick Quiana Xavier}
83do_execsql_test skipscan2-1.5eqp {
84  EXPLAIN QUERY PLAN
85  SELECT name FROM people WHERE height>=180 ORDER BY +name;
86} {/*INDEX people_idx1 */}
87
88# Same answer with other formulations of the same query
89#
90do_execsql_test skipscan2-1.6 {
91  SELECT name FROM people
92   WHERE role IN (SELECT DISTINCT role FROM people)
93     AND height>=180 ORDER BY +name;
94} {David Jack Patrick Quiana Xavier}
95do_execsql_test skipscan2-1.7 {
96  SELECT name FROM people WHERE role='teacher' AND height>=180
97  UNION ALL
98  SELECT name FROM people WHERE role='student' AND height>=180
99  ORDER BY 1;
100} {David Jack Patrick Quiana Xavier}
101
102# Add 8 more people, bringing the total to 34.  Then the number of
103# duplicates in the left-column of the index will be 17 and
104# skip-scan should not be used after an (unfudged) ANALYZE.
105#
106do_execsql_test skipscan2-1.8 {
107  INSERT INTO people VALUES('Angie','student',166);
108  INSERT INTO people VALUES('Brad','student',176);
109  INSERT INTO people VALUES('Claire','student',168);
110  INSERT INTO people VALUES('Donald','student',162);
111  INSERT INTO people VALUES('Elaine','student',177);
112  INSERT INTO people VALUES('Frazier','student',159);
113  INSERT INTO people VALUES('Grace','student',179);
114  INSERT INTO people VALUES('Horace','student',166);
115  ANALYZE;
116  SELECT stat FROM sqlite_stat1 WHERE idx='people_idx1';
117} {{34 17 2}}
118db cache flush
119do_execsql_test skipscan2-1.9 {
120  SELECT name FROM people WHERE height>=180 ORDER BY +name;
121} {David Jack Patrick Quiana Xavier}
122do_execsql_test skipscan2-1.9eqp {
123  EXPLAIN QUERY PLAN
124  SELECT name FROM people WHERE height>=180 ORDER BY +name;
125} {~/*INDEX people_idx1 */}
126
127# Add 2 more people, bringing the total to 36.  Then the number of
128# duplicates in the left-column of the index will be 18 and
129# skip-scan will be used after an (unfudged) ANALYZE.
130#
131do_execsql_test skipscan2-1.10 {
132  INSERT INTO people VALUES('Ingrad','student',155);
133  INSERT INTO people VALUES('Jacob','student',179);
134  ANALYZE;
135  SELECT stat FROM sqlite_stat1 WHERE idx='people_idx1';
136} {{36 18 2}}
137db cache flush
138do_execsql_test skipscan2-1.11 {
139  SELECT name FROM people WHERE height>=180 ORDER BY +name;
140} {David Jack Patrick Quiana Xavier}
141do_execsql_test skipscan2-1.11eqp {
142  EXPLAIN QUERY PLAN
143  SELECT name FROM people WHERE height>=180 ORDER BY +name;
144} {/*INDEX people_idx1 */}
145
146
147# Repeat using a WITHOUT ROWID table.
148#
149do_execsql_test skipscan2-2.1 {
150  CREATE TABLE peoplew(
151    name TEXT PRIMARY KEY,
152    role TEXT NOT NULL,
153    height INT NOT NULL, -- in cm
154    CHECK( role IN ('student','teacher') )
155  ) WITHOUT ROWID;
156  CREATE INDEX peoplew_idx1 ON peoplew(role, height);
157  INSERT INTO peoplew(name,role,height)
158     SELECT name, role, height FROM  people;
159  ALTER TABLE people RENAME TO old_people;
160  SELECT name FROM peoplew WHERE height>=180 ORDER BY +name;
161} {David Jack Patrick Quiana Xavier}
162do_execsql_test skipscan2-2.2 {
163  SELECT name FROM peoplew
164   WHERE role IN (SELECT DISTINCT role FROM peoplew)
165     AND height>=180 ORDER BY +name;
166} {David Jack Patrick Quiana Xavier}
167do_execsql_test skipscan2-2.2 {
168  SELECT name FROM peoplew WHERE role='teacher' AND height>=180
169  UNION ALL
170  SELECT name FROM peoplew WHERE role='student' AND height>=180
171  ORDER BY 1;
172} {David Jack Patrick Quiana Xavier}
173
174# Now do an ANALYZE.  A skip-scan can be used after ANALYZE.
175#
176do_execsql_test skipscan2-2.4 {
177  ANALYZE;
178}
179db cache flush
180do_execsql_test skipscan2-2.5 {
181  SELECT name FROM peoplew WHERE height>=180 ORDER BY +name;
182} {David Jack Patrick Quiana Xavier}
183do_execsql_test skipscan2-2.5eqp {
184  EXPLAIN QUERY PLAN
185  SELECT name FROM peoplew WHERE height>=180 ORDER BY +name;
186} {/*INDEX peoplew_idx1 */}
187
188
189
190finish_test
191