--- /dev/null
+# 2013-11-27
+#
+# The author disclaims copyright to this source code. In place of
+# a legal notice, here is a blessing:
+#
+# May you do good and not evil.
+# May you find forgiveness for yourself and forgive others.
+# May you share freely, never taking more than you give.
+#
+#***********************************************************************
+#
+# This file implements tests of the "skip-scan" query strategy.
+#
+# The test cases in this file are derived from the description of
+# the skip-scan query strategy in the "optoverview.html" document.
+#
+
+set testdir [file dirname $argv0]
+source $testdir/tester.tcl
+
+do_execsql_test skipscan2-1.1 {
+ CREATE TABLE people(
+ name TEXT PRIMARY KEY,
+ role TEXT NOT NULL,
+ height INT NOT NULL, -- in cm
+ CHECK( role IN ('student','teacher') )
+ );
+ CREATE INDEX people_idx1 ON people(role, height);
+} {}
+do_execsql_test skipscan2-1.2 {
+ INSERT INTO people VALUES('Alice','student',156);
+ INSERT INTO people VALUES('Bob','student',161);
+ INSERT INTO people VALUES('Cindy','student',155);
+ INSERT INTO people VALUES('David','student',181);
+ INSERT INTO people VALUES('Emily','teacher',158);
+ INSERT INTO people VALUES('Fred','student',163);
+ INSERT INTO people VALUES('Ginny','student',169);
+ INSERT INTO people VALUES('Harold','student',172);
+ INSERT INTO people VALUES('Imma','student',179);
+ INSERT INTO people VALUES('Jack','student',181);
+ INSERT INTO people VALUES('Karen','student',163);
+ INSERT INTO people VALUES('Logan','student',177);
+ INSERT INTO people VALUES('Megan','teacher',159);
+ INSERT INTO people VALUES('Nathan','student',163);
+ INSERT INTO people VALUES('Olivia','student',161);
+ INSERT INTO people VALUES('Patrick','teacher',180);
+ INSERT INTO people VALUES('Quiana','student',182);
+ INSERT INTO people VALUES('Robert','student',159);
+ INSERT INTO people VALUES('Sally','student',166);
+ INSERT INTO people VALUES('Tom','student',171);
+ INSERT INTO people VALUES('Ursula','student',170);
+ INSERT INTO people VALUES('Vance','student',179);
+ INSERT INTO people VALUES('Willma','student',175);
+ INSERT INTO people VALUES('Xavier','teacher',185);
+ INSERT INTO people VALUES('Yvonne','student',149);
+ INSERT INTO people VALUES('Zach','student',170);
+}
+
+# Without ANALYZE, a skip-scan is not used
+#
+do_execsql_test skipscan2-1.3 {
+ SELECT name FROM people WHERE height>=180 ORDER BY +name;
+} {David Jack Patrick Quiana Xavier}
+do_execsql_test skipscan2-1.3eqp {
+ EXPLAIN QUERY PLAN
+ SELECT name FROM people WHERE height>=180 ORDER BY +name;
+} {~/*INDEX people_idx1 */}
+
+# Now do an ANALYZE. A skip-scan can be used after ANALYZE.
+#
+do_execsql_test skipscan2-1.4 {
+ ANALYZE;
+ -- We do not have enough people above to actually force the use
+ -- of a skip-scan. So make a manual adjustment to the stat1 table
+ -- to make it seem like there are many more.
+ UPDATE sqlite_stat1 SET stat='10000 5000 20' WHERE idx='people_idx1';
+ ANALYZE sqlite_master;
+}
+db cache flush
+do_execsql_test skipscan2-1.5 {
+ SELECT name FROM people WHERE height>=180 ORDER BY +name;
+} {David Jack Patrick Quiana Xavier}
+do_execsql_test skipscan2-1.5eqp {
+ EXPLAIN QUERY PLAN
+ SELECT name FROM people WHERE height>=180 ORDER BY +name;
+} {/*INDEX people_idx1 */}
+
+# Same answer with other formulations of the same query
+#
+do_execsql_test skipscan2-1.6 {
+ SELECT name FROM people
+ WHERE role IN (SELECT DISTINCT role FROM people)
+ AND height>=180 ORDER BY +name;
+} {David Jack Patrick Quiana Xavier}
+do_execsql_test skipscan2-1.7 {
+ SELECT name FROM people WHERE role='teacher' AND height>=180
+ UNION ALL
+ SELECT name FROM people WHERE role='student' AND height>=180
+ ORDER BY 1;
+} {David Jack Patrick Quiana Xavier}
+
+# Repeat using a WITHOUT ROWID table.
+#
+do_execsql_test skipscan2-2.1 {
+ CREATE TABLE peoplew(
+ name TEXT PRIMARY KEY,
+ role TEXT NOT NULL,
+ height INT NOT NULL, -- in cm
+ CHECK( role IN ('student','teacher') )
+ ) WITHOUT ROWID;
+ CREATE INDEX peoplew_idx1 ON peoplew(role, height);
+ INSERT INTO peoplew(name,role,height)
+ SELECT name, role, height FROM people;
+ DROP TABLE people;
+ SELECT name FROM peoplew WHERE height>=180 ORDER BY +name;
+} {David Jack Patrick Quiana Xavier}
+do_execsql_test skipscan2-2.2 {
+ SELECT name FROM peoplew
+ WHERE role IN (SELECT DISTINCT role FROM peoplew)
+ AND height>=180 ORDER BY +name;
+} {David Jack Patrick Quiana Xavier}
+do_execsql_test skipscan2-2.2 {
+ SELECT name FROM peoplew WHERE role='teacher' AND height>=180
+ UNION ALL
+ SELECT name FROM peoplew WHERE role='student' AND height>=180
+ ORDER BY 1;
+} {David Jack Patrick Quiana Xavier}
+
+# Now do an ANALYZE. A skip-scan can be used after ANALYZE.
+#
+do_execsql_test skipscan2-2.4 {
+ ANALYZE;
+ -- We do not have enough people above to actually force the use
+ -- of a skip-scan. So make a manual adjustment to the stat1 table
+ -- to make it seem like there are many more.
+ UPDATE sqlite_stat1 SET stat='10000 5000 20' WHERE idx='peoplew_idx1';
+ ANALYZE sqlite_master;
+}
+db cache flush
+do_execsql_test skipscan2-2.5 {
+ SELECT name FROM peoplew WHERE height>=180 ORDER BY +name;
+} {David Jack Patrick Quiana Xavier}
+do_execsql_test skipscan2-2.5eqp {
+ EXPLAIN QUERY PLAN
+ SELECT name FROM peoplew WHERE height>=180 ORDER BY +name;
+} {/*INDEX peoplew_idx1 */}
+
+
+
+finish_test