sqlite/test/index6.test
2013-08-12 20:14:04 +00:00

240 lines
6.0 KiB
Plaintext

# 2013-07-31
#
# 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.
#
#***********************************************************************
#
# Test cases for partial indices
#
set testdir [file dirname $argv0]
source $testdir/tester.tcl
load_static_extension db wholenumber;
do_test index6-1.1 {
# Able to parse and manage partial indices
execsql {
CREATE TABLE t1(a,b,c);
CREATE INDEX t1a ON t1(a) WHERE a IS NOT NULL;
CREATE INDEX t1b ON t1(b) WHERE b>10;
CREATE VIRTUAL TABLE nums USING wholenumber;
INSERT INTO t1(a,b,c)
SELECT CASE WHEN value%3!=0 THEN value END, value, value
FROM nums WHERE value<=20;
SELECT count(a), count(b) FROM t1;
PRAGMA integrity_check;
}
} {14 20 ok}
# Error conditions during parsing...
#
do_test index6-1.2 {
catchsql {
CREATE INDEX bad1 ON t1(a,b) WHERE x IS NOT NULL;
}
} {1 {no such column: x}}
do_test index6-1.3 {
catchsql {
CREATE INDEX bad1 ON t1(a,b) WHERE EXISTS(SELECT * FROM t1);
}
} {1 {subqueries prohibited in partial index WHERE clauses}}
do_test index6-1.4 {
catchsql {
CREATE INDEX bad1 ON t1(a,b) WHERE a!=?1;
}
} {1 {parameters prohibited in partial index WHERE clauses}}
do_test index6-1.5 {
catchsql {
CREATE INDEX bad1 ON t1(a,b) WHERE a!=random();
}
} {1 {functions prohibited in partial index WHERE clauses}}
do_test index6-1.6 {
catchsql {
CREATE INDEX bad1 ON t1(a,b) WHERE a NOT LIKE 'abc%';
}
} {1 {functions prohibited in partial index WHERE clauses}}
do_test index6-1.10 {
execsql {
ANALYZE;
SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
PRAGMA integrity_check;
}
} {{} 20 t1a {14 1} t1b {10 1} ok}
# STAT1 shows the partial indices have a reduced number of
# rows.
#
do_test index6-1.11 {
execsql {
UPDATE t1 SET a=b;
ANALYZE;
SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
PRAGMA integrity_check;
}
} {{} 20 t1a {20 1} t1b {10 1} ok}
do_test index6-1.11 {
execsql {
UPDATE t1 SET a=NULL WHERE b%3!=0;
UPDATE t1 SET b=b+100;
ANALYZE;
SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
PRAGMA integrity_check;
}
} {{} 20 t1a {6 1} t1b {20 1} ok}
do_test index6-1.12 {
execsql {
UPDATE t1 SET a=CASE WHEN b%3!=0 THEN b END;
UPDATE t1 SET b=b-100;
ANALYZE;
SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
PRAGMA integrity_check;
}
} {{} 20 t1a {13 1} t1b {10 1} ok}
do_test index6-1.13 {
execsql {
DELETE FROM t1 WHERE b BETWEEN 8 AND 12;
ANALYZE;
SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
PRAGMA integrity_check;
}
} {{} 15 t1a {10 1} t1b {8 1} ok}
do_test index6-1.14 {
execsql {
REINDEX;
ANALYZE;
SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
PRAGMA integrity_check;
}
} {{} 15 t1a {10 1} t1b {8 1} ok}
do_test index6-1.15 {
execsql {
CREATE INDEX t1c ON t1(c);
ANALYZE;
SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
PRAGMA integrity_check;
}
} {t1a {10 1} t1b {8 1} t1c {15 1} ok}
# Queries use partial indices as appropriate times.
#
do_test index6-2.1 {
execsql {
CREATE TABLE t2(a,b);
INSERT INTO t2(a,b) SELECT value, value FROM nums WHERE value<1000;
UPDATE t2 SET a=NULL WHERE b%5==0;
CREATE INDEX t2a1 ON t2(a) WHERE a IS NOT NULL;
SELECT count(*) FROM t2 WHERE a IS NOT NULL;
}
} {800}
do_test index6-2.2 {
execsql {
EXPLAIN QUERY PLAN
SELECT * FROM t2 WHERE a=5;
}
} {/.* TABLE t2 USING INDEX t2a1 .*/}
ifcapable stat4||stat3 {
do_test index6-2.3stat4 {
execsql {
EXPLAIN QUERY PLAN
SELECT * FROM t2 WHERE a IS NOT NULL;
}
} {/.* TABLE t2 USING INDEX t2a1 .*/}
} else {
do_test index6-2.3stat4 {
execsql {
EXPLAIN QUERY PLAN
SELECT * FROM t2 WHERE a IS NOT NULL AND a>0;
}
} {/.* TABLE t2 USING INDEX t2a1 .*/}
}
do_test index6-2.4 {
execsql {
EXPLAIN QUERY PLAN
SELECT * FROM t2 WHERE a IS NULL;
}
} {~/.*INDEX t2a1.*/}
do_execsql_test index6-2.101 {
DROP INDEX t2a1;
UPDATE t2 SET a=b, b=b+10000;
SELECT b FROM t2 WHERE a=15;
} {10015}
do_execsql_test index6-2.102 {
CREATE INDEX t2a2 ON t2(a) WHERE a<100 OR a>200;
SELECT b FROM t2 WHERE a=15;
PRAGMA integrity_check;
} {10015 ok}
do_execsql_test index6-2.102eqp {
EXPLAIN QUERY PLAN
SELECT b FROM t2 WHERE a=15;
} {~/.*INDEX t2a2.*/}
do_execsql_test index6-2.103 {
SELECT b FROM t2 WHERE a=15 AND a<100;
} {10015}
do_execsql_test index6-2.103eqp {
EXPLAIN QUERY PLAN
SELECT b FROM t2 WHERE a=15 AND a<100;
} {/.*INDEX t2a2.*/}
do_execsql_test index6-2.104 {
SELECT b FROM t2 WHERE a=515 AND a>200;
} {10515}
do_execsql_test index6-2.104eqp {
EXPLAIN QUERY PLAN
SELECT b FROM t2 WHERE a=515 AND a>200;
} {/.*INDEX t2a2.*/}
# Partial UNIQUE indices
#
do_execsql_test index6-3.1 {
CREATE TABLE t3(a,b);
INSERT INTO t3 SELECT value, value FROM nums WHERE value<200;
UPDATE t3 SET a=999 WHERE b%5!=0;
CREATE UNIQUE INDEX t3a ON t3(a) WHERE a<>999;
} {}
do_test index6-3.2 {
# unable to insert a duplicate row a-value that is not 999.
catchsql {
INSERT INTO t3(a,b) VALUES(150, 'test1');
}
} {1 {column a is not unique}}
do_test index6-3.3 {
# can insert multiple rows with a==999 because such rows are not
# part of the unique index.
catchsql {
INSERT INTO t3(a,b) VALUES(999, 'test1'), (999, 'test2');
}
} {0 {}}
do_execsql_test index6-3.4 {
SELECT count(*) FROM t3 WHERE a=999;
} {162}
integrity_check index6-3.5
do_execsql_test index6-4.0 {
VACUUM;
PRAGMA integrity_check;
} {ok}
# Silently ignore database name qualifiers in partial indices.
#
do_execsql_test index6-5.0 {
CREATE INDEX t3b ON t3(b) WHERE xyzzy.t3.b BETWEEN 5 AND 10;
/* ^^^^^-- ignored */
ANALYZE;
SELECT count(*) FROM t3 WHERE t3.b BETWEEN 5 AND 10;
SELECT stat+0 FROM sqlite_stat1 WHERE idx='t3b';
} {6 6}
finish_test