xref: /sqlite-3.40.0/test/skipscan2.test (revision 37f3ac8f)
121236679Sdrh# 2013-11-27
221236679Sdrh#
321236679Sdrh# The author disclaims copyright to this source code.  In place of
421236679Sdrh# a legal notice, here is a blessing:
521236679Sdrh#
621236679Sdrh#    May you do good and not evil.
721236679Sdrh#    May you find forgiveness for yourself and forgive others.
821236679Sdrh#    May you share freely, never taking more than you give.
921236679Sdrh#
1021236679Sdrh#***********************************************************************
1121236679Sdrh#
1221236679Sdrh# This file implements tests of the "skip-scan" query strategy.
1321236679Sdrh#
1421236679Sdrh# The test cases in this file are derived from the description of
1521236679Sdrh# the skip-scan query strategy in the "optoverview.html" document.
1621236679Sdrh#
1721236679Sdrh
1821236679Sdrhset testdir [file dirname $argv0]
1921236679Sdrhsource $testdir/tester.tcl
2021236679Sdrh
2121236679Sdrhdo_execsql_test skipscan2-1.1 {
2221236679Sdrh  CREATE TABLE people(
2321236679Sdrh    name TEXT PRIMARY KEY,
2421236679Sdrh    role TEXT NOT NULL,
2521236679Sdrh    height INT NOT NULL, -- in cm
2621236679Sdrh    CHECK( role IN ('student','teacher') )
2721236679Sdrh  );
2821236679Sdrh  CREATE INDEX people_idx1 ON people(role, height);
2921236679Sdrh} {}
3021236679Sdrhdo_execsql_test skipscan2-1.2 {
3121236679Sdrh  INSERT INTO people VALUES('Alice','student',156);
3221236679Sdrh  INSERT INTO people VALUES('Bob','student',161);
3321236679Sdrh  INSERT INTO people VALUES('Cindy','student',155);
3421236679Sdrh  INSERT INTO people VALUES('David','student',181);
3521236679Sdrh  INSERT INTO people VALUES('Emily','teacher',158);
3621236679Sdrh  INSERT INTO people VALUES('Fred','student',163);
3721236679Sdrh  INSERT INTO people VALUES('Ginny','student',169);
3821236679Sdrh  INSERT INTO people VALUES('Harold','student',172);
3921236679Sdrh  INSERT INTO people VALUES('Imma','student',179);
4021236679Sdrh  INSERT INTO people VALUES('Jack','student',181);
4121236679Sdrh  INSERT INTO people VALUES('Karen','student',163);
4221236679Sdrh  INSERT INTO people VALUES('Logan','student',177);
4321236679Sdrh  INSERT INTO people VALUES('Megan','teacher',159);
4421236679Sdrh  INSERT INTO people VALUES('Nathan','student',163);
4521236679Sdrh  INSERT INTO people VALUES('Olivia','student',161);
4621236679Sdrh  INSERT INTO people VALUES('Patrick','teacher',180);
4721236679Sdrh  INSERT INTO people VALUES('Quiana','student',182);
4821236679Sdrh  INSERT INTO people VALUES('Robert','student',159);
4921236679Sdrh  INSERT INTO people VALUES('Sally','student',166);
5021236679Sdrh  INSERT INTO people VALUES('Tom','student',171);
5121236679Sdrh  INSERT INTO people VALUES('Ursula','student',170);
5221236679Sdrh  INSERT INTO people VALUES('Vance','student',179);
5321236679Sdrh  INSERT INTO people VALUES('Willma','student',175);
5421236679Sdrh  INSERT INTO people VALUES('Xavier','teacher',185);
5521236679Sdrh  INSERT INTO people VALUES('Yvonne','student',149);
5621236679Sdrh  INSERT INTO people VALUES('Zach','student',170);
5721236679Sdrh}
5821236679Sdrh
5921236679Sdrh# Without ANALYZE, a skip-scan is not used
6021236679Sdrh#
6121236679Sdrhdo_execsql_test skipscan2-1.3 {
6221236679Sdrh  SELECT name FROM people WHERE height>=180 ORDER BY +name;
6321236679Sdrh} {David Jack Patrick Quiana Xavier}
6421236679Sdrhdo_execsql_test skipscan2-1.3eqp {
6521236679Sdrh  EXPLAIN QUERY PLAN
6621236679Sdrh  SELECT name FROM people WHERE height>=180 ORDER BY +name;
6721236679Sdrh} {~/*INDEX people_idx1 */}
6821236679Sdrh
6921236679Sdrh# Now do an ANALYZE.  A skip-scan can be used after ANALYZE.
7021236679Sdrh#
7121236679Sdrhdo_execsql_test skipscan2-1.4 {
7221236679Sdrh  ANALYZE;
7321236679Sdrh  -- We do not have enough people above to actually force the use
7421236679Sdrh  -- of a skip-scan.  So make a manual adjustment to the stat1 table
7521236679Sdrh  -- to make it seem like there are many more.
7621236679Sdrh  UPDATE sqlite_stat1 SET stat='10000 5000 20' WHERE idx='people_idx1';
7767a03cfdSdan  UPDATE sqlite_stat1 SET stat='10000 1' WHERE idx='sqlite_autoindex_people_1';
7821236679Sdrh  ANALYZE sqlite_master;
7921236679Sdrh}
8021236679Sdrhdb cache flush
8121236679Sdrhdo_execsql_test skipscan2-1.5 {
8221236679Sdrh  SELECT name FROM people WHERE height>=180 ORDER BY +name;
8321236679Sdrh} {David Jack Patrick Quiana Xavier}
8421236679Sdrhdo_execsql_test skipscan2-1.5eqp {
8521236679Sdrh  EXPLAIN QUERY PLAN
8621236679Sdrh  SELECT name FROM people WHERE height>=180 ORDER BY +name;
8721236679Sdrh} {/*INDEX people_idx1 */}
8821236679Sdrh
8921236679Sdrh# Same answer with other formulations of the same query
9021236679Sdrh#
9121236679Sdrhdo_execsql_test skipscan2-1.6 {
9221236679Sdrh  SELECT name FROM people
9321236679Sdrh   WHERE role IN (SELECT DISTINCT role FROM people)
9421236679Sdrh     AND height>=180 ORDER BY +name;
9521236679Sdrh} {David Jack Patrick Quiana Xavier}
9621236679Sdrhdo_execsql_test skipscan2-1.7 {
9721236679Sdrh  SELECT name FROM people WHERE role='teacher' AND height>=180
9821236679Sdrh  UNION ALL
9921236679Sdrh  SELECT name FROM people WHERE role='student' AND height>=180
10021236679Sdrh  ORDER BY 1;
10121236679Sdrh} {David Jack Patrick Quiana Xavier}
10221236679Sdrh
103ce00a837Sdrh# Add 8 more people, bringing the total to 34.  Then the number of
104ce00a837Sdrh# duplicates in the left-column of the index will be 17 and
105ce00a837Sdrh# skip-scan should not be used after an (unfudged) ANALYZE.
106ce00a837Sdrh#
107ce00a837Sdrhdo_execsql_test skipscan2-1.8 {
108ce00a837Sdrh  INSERT INTO people VALUES('Angie','student',166);
109ce00a837Sdrh  INSERT INTO people VALUES('Brad','student',176);
110ce00a837Sdrh  INSERT INTO people VALUES('Claire','student',168);
111ce00a837Sdrh  INSERT INTO people VALUES('Donald','student',162);
112ce00a837Sdrh  INSERT INTO people VALUES('Elaine','student',177);
113ce00a837Sdrh  INSERT INTO people VALUES('Frazier','student',159);
114ce00a837Sdrh  INSERT INTO people VALUES('Grace','student',179);
115ce00a837Sdrh  INSERT INTO people VALUES('Horace','student',166);
116ce00a837Sdrh  ANALYZE;
117ce00a837Sdrh  SELECT stat FROM sqlite_stat1 WHERE idx='people_idx1';
118ce00a837Sdrh} {{34 17 2}}
119ce00a837Sdrhdb cache flush
120ce00a837Sdrhdo_execsql_test skipscan2-1.9 {
121ce00a837Sdrh  SELECT name FROM people WHERE height>=180 ORDER BY +name;
122ce00a837Sdrh} {David Jack Patrick Quiana Xavier}
123ce00a837Sdrhdo_execsql_test skipscan2-1.9eqp {
124ce00a837Sdrh  EXPLAIN QUERY PLAN
125ce00a837Sdrh  SELECT name FROM people WHERE height>=180 ORDER BY +name;
126ce00a837Sdrh} {~/*INDEX people_idx1 */}
127ce00a837Sdrh
128ce00a837Sdrh# Add 2 more people, bringing the total to 36.  Then the number of
129ce00a837Sdrh# duplicates in the left-column of the index will be 18 and
130ce00a837Sdrh# skip-scan will be used after an (unfudged) ANALYZE.
131ce00a837Sdrh#
132ce00a837Sdrhdo_execsql_test skipscan2-1.10 {
133ce00a837Sdrh  INSERT INTO people VALUES('Ingrad','student',155);
134ce00a837Sdrh  INSERT INTO people VALUES('Jacob','student',179);
135ce00a837Sdrh  ANALYZE;
136ce00a837Sdrh  SELECT stat FROM sqlite_stat1 WHERE idx='people_idx1';
137ce00a837Sdrh} {{36 18 2}}
138ce00a837Sdrhdb cache flush
139ce00a837Sdrhdo_execsql_test skipscan2-1.11 {
140ce00a837Sdrh  SELECT name FROM people WHERE height>=180 ORDER BY +name;
141ce00a837Sdrh} {David Jack Patrick Quiana Xavier}
142ce00a837Sdrhdo_execsql_test skipscan2-1.11eqp {
143ce00a837Sdrh  EXPLAIN QUERY PLAN
144ce00a837Sdrh  SELECT name FROM people WHERE height>=180 ORDER BY +name;
145ce00a837Sdrh} {/*INDEX people_idx1 */}
146ce00a837Sdrh
147ce00a837Sdrh
14821236679Sdrh# Repeat using a WITHOUT ROWID table.
14921236679Sdrh#
15021236679Sdrhdo_execsql_test skipscan2-2.1 {
15121236679Sdrh  CREATE TABLE peoplew(
15221236679Sdrh    name TEXT PRIMARY KEY,
15321236679Sdrh    role TEXT NOT NULL,
15421236679Sdrh    height INT NOT NULL, -- in cm
15521236679Sdrh    CHECK( role IN ('student','teacher') )
15621236679Sdrh  ) WITHOUT ROWID;
15721236679Sdrh  CREATE INDEX peoplew_idx1 ON peoplew(role, height);
15821236679Sdrh  INSERT INTO peoplew(name,role,height)
15921236679Sdrh     SELECT name, role, height FROM  people;
16021236679Sdrh  SELECT name FROM peoplew WHERE height>=180 ORDER BY +name;
16121236679Sdrh} {David Jack Patrick Quiana Xavier}
16221236679Sdrhdo_execsql_test skipscan2-2.2 {
16321236679Sdrh  SELECT name FROM peoplew
16421236679Sdrh   WHERE role IN (SELECT DISTINCT role FROM peoplew)
16521236679Sdrh     AND height>=180 ORDER BY +name;
16621236679Sdrh} {David Jack Patrick Quiana Xavier}
16721236679Sdrhdo_execsql_test skipscan2-2.2 {
16821236679Sdrh  SELECT name FROM peoplew WHERE role='teacher' AND height>=180
16921236679Sdrh  UNION ALL
17021236679Sdrh  SELECT name FROM peoplew WHERE role='student' AND height>=180
17121236679Sdrh  ORDER BY 1;
17221236679Sdrh} {David Jack Patrick Quiana Xavier}
17321236679Sdrh
17421236679Sdrh# Now do an ANALYZE.  A skip-scan can be used after ANALYZE.
17521236679Sdrh#
17621236679Sdrhdo_execsql_test skipscan2-2.4 {
17721236679Sdrh  ANALYZE;
17821236679Sdrh}
17921236679Sdrhdb cache flush
18021236679Sdrhdo_execsql_test skipscan2-2.5 {
18121236679Sdrh  SELECT name FROM peoplew WHERE height>=180 ORDER BY +name;
18221236679Sdrh} {David Jack Patrick Quiana Xavier}
18321236679Sdrhdo_execsql_test skipscan2-2.5eqp {
18421236679Sdrh  EXPLAIN QUERY PLAN
18521236679Sdrh  SELECT name FROM peoplew WHERE height>=180 ORDER BY +name;
18621236679Sdrh} {/*INDEX peoplew_idx1 */}
18721236679Sdrh
1886044f31dSdan# A skip-scan on a PK index of a WITHOUT ROWID table.
1896044f31dSdan#
1906044f31dSdando_execsql_test skipscan2-3.1 {
1916044f31dSdan  CREATE TABLE t3(a, b, c, PRIMARY KEY(a, b)) WITHOUT ROWID;
1926044f31dSdan}
1936044f31dSdando_test skipscan2-3.2 {
1946044f31dSdan  for {set i 0} {$i < 1000} {incr i} {
1956044f31dSdan    execsql { INSERT INTO t3 VALUES($i%2, $i, 'xyz') }
1966044f31dSdan  }
1976044f31dSdan  execsql { ANALYZE }
1986044f31dSdan} {}
1996044f31dSdando_eqp_test skipscan2-3.3eqp {
2006044f31dSdan  SELECT * FROM t3 WHERE b=42;
201*8210233cSdrh} {SEARCH t3 USING PRIMARY KEY (ANY(a) AND b=?)}
20221236679Sdrh
20321236679Sdrh
204d1f9932eSdan
20521236679Sdrhfinish_test
206