3 # The author disclaims copyright to this source code. In place of
4 # a legal notice, here is a blessing:
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.
10 #***********************************************************************
12 # This file implements regression tests for SQLite library. This file
13 # implements tests for ANALYZE to verify that multiple rows containing
14 # a NULL value count as distinct rows for the purposes of analyze
17 # Also include test cases for collating sequences on indices.
20 set testdir [file dirname $argv0]
21 source $testdir/tester.tcl
23 # If SQLITE_OMIT_ALTERTABLE is defined, omit this file.
24 ifcapable !altertable {
29 do_test analyze4-1.0 {
32 CREATE INDEX t1a ON t1(a);
33 CREATE INDEX t1b ON t1(b);
34 INSERT INTO t1 VALUES(1,NULL);
35 INSERT INTO t1 SELECT a+1, b FROM t1;
36 INSERT INTO t1 SELECT a+2, b FROM t1;
37 INSERT INTO t1 SELECT a+4, b FROM t1;
38 INSERT INTO t1 SELECT a+8, b FROM t1;
39 INSERT INTO t1 SELECT a+16, b FROM t1;
40 INSERT INTO t1 SELECT a+32, b FROM t1;
41 INSERT INTO t1 SELECT a+64, b FROM t1;
45 # Should choose the t1a index since it is more specific than t1b.
46 db eval {EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE a=5 AND b IS NULL}
47 } {/*SEARCH t1 USING INDEX t1a (a=?)*/}
49 # Verify that the t1b index shows that it does not narrow down the
52 do_test analyze4-1.1 {
54 SELECT idx, stat FROM sqlite_stat1 WHERE tbl='t1' ORDER BY idx;
56 } {t1a {128 1} t1b {128 128}}
58 # Change half of the b values from NULL to a constant. Verify
59 # that the number of rows selected in stat1 is half the total
62 do_test analyze4-1.2 {
64 UPDATE t1 SET b='x' WHERE a%2;
66 SELECT idx, stat FROM sqlite_stat1 WHERE tbl='t1' ORDER BY idx;
68 } {t1a {128 1} t1b {128 64}}
70 # Change the t1.b values all back to NULL. Add columns t1.c and t1.d.
71 # Create a multi-column indices using t1.b and verify that ANALYZE
72 # processes them correctly.
74 do_test analyze4-1.3 {
77 ALTER TABLE t1 ADD COLUMN c;
78 ALTER TABLE t1 ADD COLUMN d;
79 UPDATE t1 SET c=a/4, d=a/2;
80 CREATE INDEX t1bcd ON t1(b,c,d);
81 CREATE INDEX t1cdb ON t1(c,d,b);
82 CREATE INDEX t1cbd ON t1(c,b,d);
84 SELECT idx, stat FROM sqlite_stat1 WHERE tbl='t1' ORDER BY idx;
86 } {t1a {128 1} t1b {128 128} t1bcd {128 128 4 2} t1cbd {128 4 4 2} t1cdb {128 4 2 2}}
88 # Verify that collating sequences are taken into account when computing
91 do_test analyze4-2.0 {
94 x INTEGER PRIMARY KEY,
95 a TEXT COLLATE nocase,
99 CREATE INDEX t2a ON t2(a);
100 CREATE INDEX t2b ON t2(b);
101 CREATE INDEX t2c ON t2(c);
102 CREATE INDEX t2c2 ON t2(c COLLATE nocase);
103 CREATE INDEX t2c3 ON t2(c COLLATE rtrim);
104 INSERT INTO t2 VALUES(1, 'abc', 'abc', 'abc');
105 INSERT INTO t2 VALUES(2, 'abC', 'abC', 'abC');
106 INSERT INTO t2 VALUES(3, 'abc ', 'abc ', 'abc ');
107 INSERT INTO t2 VALUES(4, 'abC ', 'abC ', 'abC ');
108 INSERT INTO t2 VALUES(5, 'aBc', 'aBc', 'aBc');
109 INSERT INTO t2 VALUES(6, 'aBC', 'aBC', 'aBC');
110 INSERT INTO t2 VALUES(7, 'aBc ', 'aBc ', 'aBc ');
111 INSERT INTO t2 VALUES(8, 'aBC ', 'aBC ', 'aBC ');
113 SELECT idx, stat FROM sqlite_stat1 WHERE tbl='t2' ORDER BY idx;
115 } {t2a {8 4} t2b {8 2} t2c {8 1} t2c2 {8 4} t2c3 {8 2}}