xref: /sqlite-3.40.0/test/minmax3.test (revision 083310df)
1a9d1ccb9Sdanielk1977# 2008 January 5
2a9d1ccb9Sdanielk1977#
3a9d1ccb9Sdanielk1977# The author disclaims copyright to this source code.  In place of
4a9d1ccb9Sdanielk1977# a legal notice, here is a blessing:
5a9d1ccb9Sdanielk1977#
6a9d1ccb9Sdanielk1977#    May you do good and not evil.
7a9d1ccb9Sdanielk1977#    May you find forgiveness for yourself and forgive others.
8a9d1ccb9Sdanielk1977#    May you share freely, never taking more than you give.
9a9d1ccb9Sdanielk1977#
10a9d1ccb9Sdanielk1977#***********************************************************************
11e8f52c50Sdrh# $Id: minmax3.test,v 1.5 2008/07/12 14:52:20 drh Exp $
12a9d1ccb9Sdanielk1977
13a9d1ccb9Sdanielk1977set testdir [file dirname $argv0]
14a9d1ccb9Sdanielk1977source $testdir/tester.tcl
15a9d1ccb9Sdanielk1977
1668928b6cSdan# Do not use a codec for tests in this file, as the database file is
1768928b6cSdan# manipulated directly using tcl scripts (using the [hexio_write] command).
1868928b6cSdan#
1968928b6cSdando_not_use_codec
2068928b6cSdan
21a9d1ccb9Sdanielk1977# Do an SQL statement.  Append the search count to the end of the result.
22a9d1ccb9Sdanielk1977#
23a9d1ccb9Sdanielk1977proc count sql {
24a9d1ccb9Sdanielk1977  set ::sqlite_search_count 0
25a9d1ccb9Sdanielk1977  return [concat [execsql $sql] $::sqlite_search_count]
26a9d1ccb9Sdanielk1977}
27a9d1ccb9Sdanielk1977
28a9d1ccb9Sdanielk1977# This procedure sets the value of the file-format in file 'test.db'
29a9d1ccb9Sdanielk1977# to $newval. Also, the schema cookie is incremented.
30a9d1ccb9Sdanielk1977#
31a9d1ccb9Sdanielk1977proc set_file_format {newval} {
32bb8a279eSdrh  hexio_write test.db 44 [hexio_render_int32 $newval]
33bb8a279eSdrh  set schemacookie [hexio_get_int [hexio_read test.db 40 4]]
34bb8a279eSdrh  incr schemacookie
35bb8a279eSdrh  hexio_write test.db 40 [hexio_render_int32 $schemacookie]
36bb8a279eSdrh  return {}
37a9d1ccb9Sdanielk1977}
38a9d1ccb9Sdanielk1977
39a9d1ccb9Sdanielk1977do_test minmax3-1.0 {
40a9d1ccb9Sdanielk1977  execsql {
41a9d1ccb9Sdanielk1977    CREATE TABLE t1(x, y, z);
42bb8a279eSdrh  }
43bb8a279eSdrh  db close
44bb8a279eSdrh  set_file_format 4
45bb8a279eSdrh  sqlite3 db test.db
46bb8a279eSdrh  execsql {
47bb8a279eSdrh    BEGIN;
48a9d1ccb9Sdanielk1977    INSERT INTO t1 VALUES('1', 'I',   'one');
49a9d1ccb9Sdanielk1977    INSERT INTO t1 VALUES('2', 'IV',  'four');
50a9d1ccb9Sdanielk1977    INSERT INTO t1 VALUES('2', NULL,  'three');
51a9d1ccb9Sdanielk1977    INSERT INTO t1 VALUES('2', 'II',  'two');
52a9d1ccb9Sdanielk1977    INSERT INTO t1 VALUES('2', 'V',   'five');
53a9d1ccb9Sdanielk1977    INSERT INTO t1 VALUES('3', 'VI',  'six');
54a9d1ccb9Sdanielk1977    COMMIT;
55*083310dfSdrh    PRAGMA automatic_index=OFF;
56a9d1ccb9Sdanielk1977  }
57a9d1ccb9Sdanielk1977} {}
58a9d1ccb9Sdanielk1977do_test minmax3-1.1.1 {
59a9d1ccb9Sdanielk1977  # Linear scan.
60a9d1ccb9Sdanielk1977  count { SELECT max(y) FROM t1 WHERE x = '2'; }
61a9d1ccb9Sdanielk1977} {V 5}
62a9d1ccb9Sdanielk1977do_test minmax3-1.1.2 {
63a9d1ccb9Sdanielk1977  # Index optimizes the WHERE x='2' constraint.
64a9d1ccb9Sdanielk1977  execsql { CREATE INDEX i1 ON t1(x) }
65a9d1ccb9Sdanielk1977  count   { SELECT max(y) FROM t1 WHERE x = '2'; }
66a9d1ccb9Sdanielk1977} {V 9}
67a9d1ccb9Sdanielk1977do_test minmax3-1.1.3 {
68a9d1ccb9Sdanielk1977  # Index optimizes the WHERE x='2' constraint and the MAX(y).
69a9d1ccb9Sdanielk1977  execsql { CREATE INDEX i2 ON t1(x,y) }
70a9d1ccb9Sdanielk1977  count   { SELECT max(y) FROM t1 WHERE x = '2'; }
71a9d1ccb9Sdanielk1977} {V 1}
72a9d1ccb9Sdanielk1977do_test minmax3-1.1.4 {
73a9d1ccb9Sdanielk1977  # Index optimizes the WHERE x='2' constraint and the MAX(y).
74a9d1ccb9Sdanielk1977  execsql { DROP INDEX i2 ; CREATE INDEX i2 ON t1(x, y DESC) }
75a9d1ccb9Sdanielk1977  count   { SELECT max(y) FROM t1 WHERE x = '2'; }
76a9d1ccb9Sdanielk1977} {V 1}
77a9d1ccb9Sdanielk1977do_test minmax3-1.1.5 {
78a9d1ccb9Sdanielk1977  count   { SELECT max(y) FROM t1 WHERE x = '2' AND y != 'V'; }
79a9d1ccb9Sdanielk1977} {IV 2}
80a9d1ccb9Sdanielk1977do_test minmax3-1.1.6 {
81a9d1ccb9Sdanielk1977  count   { SELECT max(y) FROM t1 WHERE x = '2' AND y < 'V'; }
82a9d1ccb9Sdanielk1977} {IV 1}
83a9d1ccb9Sdanielk1977do_test minmax3-1.1.6 {
84a9d1ccb9Sdanielk1977  count   { SELECT max(y) FROM t1 WHERE x = '2' AND z != 'five'; }
85a9d1ccb9Sdanielk1977} {IV 4}
86a9d1ccb9Sdanielk1977
87a9d1ccb9Sdanielk1977do_test minmax3-1.2.1 {
88a9d1ccb9Sdanielk1977  # Linear scan of t1.
89a9d1ccb9Sdanielk1977  execsql { DROP INDEX i1 ; DROP INDEX i2 }
90a9d1ccb9Sdanielk1977  count { SELECT min(y) FROM t1 WHERE x = '2'; }
91a9d1ccb9Sdanielk1977} {II 5}
92a9d1ccb9Sdanielk1977do_test minmax3-1.2.2 {
93a9d1ccb9Sdanielk1977  # Index i1 optimizes the WHERE x='2' constraint.
94a9d1ccb9Sdanielk1977  execsql { CREATE INDEX i1 ON t1(x) }
95a9d1ccb9Sdanielk1977  count   { SELECT min(y) FROM t1 WHERE x = '2'; }
96a9d1ccb9Sdanielk1977} {II 9}
97a9d1ccb9Sdanielk1977do_test minmax3-1.2.3 {
98a9d1ccb9Sdanielk1977  # Index i2 optimizes the WHERE x='2' constraint and the min(y).
99a9d1ccb9Sdanielk1977  execsql { CREATE INDEX i2 ON t1(x,y) }
100a9d1ccb9Sdanielk1977  count   { SELECT min(y) FROM t1 WHERE x = '2'; }
101a9d1ccb9Sdanielk1977} {II 1}
102a9d1ccb9Sdanielk1977do_test minmax3-1.2.4 {
103a9d1ccb9Sdanielk1977  # Index optimizes the WHERE x='2' constraint and the MAX(y).
104a9d1ccb9Sdanielk1977  execsql { DROP INDEX i2 ; CREATE INDEX i2 ON t1(x, y DESC) }
105a9d1ccb9Sdanielk1977  count   { SELECT min(y) FROM t1 WHERE x = '2'; }
106a9d1ccb9Sdanielk1977} {II 1}
107a9d1ccb9Sdanielk1977
108a9d1ccb9Sdanielk1977do_test minmax3-1.3.1 {
109a9d1ccb9Sdanielk1977  # Linear scan
110a9d1ccb9Sdanielk1977  execsql { DROP INDEX i1 ; DROP INDEX i2 }
111a9d1ccb9Sdanielk1977  count   { SELECT min(y) FROM t1; }
112a9d1ccb9Sdanielk1977} {I 5}
113a9d1ccb9Sdanielk1977do_test minmax3-1.3.2 {
114a9d1ccb9Sdanielk1977  # Index i1 optimizes the min(y)
115a9d1ccb9Sdanielk1977  execsql { CREATE INDEX i1 ON t1(y) }
116a9d1ccb9Sdanielk1977  count   { SELECT min(y) FROM t1; }
117a9d1ccb9Sdanielk1977} {I 1}
118a9d1ccb9Sdanielk1977do_test minmax3-1.3.3 {
119a9d1ccb9Sdanielk1977  # Index i1 optimizes the min(y)
120a9d1ccb9Sdanielk1977  execsql { DROP INDEX i1 ; CREATE INDEX i1 ON t1(y DESC) }
121a9d1ccb9Sdanielk1977  count   { SELECT min(y) FROM t1; }
122a9d1ccb9Sdanielk1977} {I 1}
123a9d1ccb9Sdanielk1977
124a9d1ccb9Sdanielk1977do_test minmax3-1.4.1 {
125a9d1ccb9Sdanielk1977  # Linear scan
126a9d1ccb9Sdanielk1977  execsql { DROP INDEX i1 }
127a9d1ccb9Sdanielk1977  count   { SELECT max(y) FROM t1; }
128a9d1ccb9Sdanielk1977} {VI 5}
129a9d1ccb9Sdanielk1977do_test minmax3-1.4.2 {
130a9d1ccb9Sdanielk1977  # Index i1 optimizes the max(y)
131a9d1ccb9Sdanielk1977  execsql { CREATE INDEX i1 ON t1(y) }
132a9d1ccb9Sdanielk1977  count   { SELECT max(y) FROM t1; }
133a9d1ccb9Sdanielk1977} {VI 0}
134a9d1ccb9Sdanielk1977do_test minmax3-1.4.3 {
135a9d1ccb9Sdanielk1977  # Index i1 optimizes the max(y)
136a9d1ccb9Sdanielk1977  execsql { DROP INDEX i1 ; CREATE INDEX i1 ON t1(y DESC) }
137a9d1ccb9Sdanielk1977  execsql   { SELECT y from t1}
138a9d1ccb9Sdanielk1977  count   { SELECT max(y) FROM t1; }
139a9d1ccb9Sdanielk1977} {VI 0}
140a9d1ccb9Sdanielk1977do_test minmax3-1.4.4 {
141a9d1ccb9Sdanielk1977  execsql { DROP INDEX i1 }
142a9d1ccb9Sdanielk1977} {}
143a9d1ccb9Sdanielk1977
144e5f5b8f1Sdanielk1977do_test minmax3-2.1 {
145e5f5b8f1Sdanielk1977  execsql {
146e5f5b8f1Sdanielk1977    CREATE TABLE t2(a, b);
147e5f5b8f1Sdanielk1977    CREATE INDEX i3 ON t2(a, b);
148e5f5b8f1Sdanielk1977    INSERT INTO t2 VALUES(1, NULL);
149e5f5b8f1Sdanielk1977    INSERT INTO t2 VALUES(1, 1);
150e5f5b8f1Sdanielk1977    INSERT INTO t2 VALUES(1, 2);
151e5f5b8f1Sdanielk1977    INSERT INTO t2 VALUES(1, 3);
152e5f5b8f1Sdanielk1977    INSERT INTO t2 VALUES(2, NULL);
153e5f5b8f1Sdanielk1977    INSERT INTO t2 VALUES(2, 1);
154e5f5b8f1Sdanielk1977    INSERT INTO t2 VALUES(2, 2);
155e5f5b8f1Sdanielk1977    INSERT INTO t2 VALUES(2, 3);
156e5f5b8f1Sdanielk1977    INSERT INTO t2 VALUES(3, 1);
157e5f5b8f1Sdanielk1977    INSERT INTO t2 VALUES(3, 2);
158e5f5b8f1Sdanielk1977    INSERT INTO t2 VALUES(3, 3);
159e5f5b8f1Sdanielk1977  }
160e5f5b8f1Sdanielk1977} {}
161e5f5b8f1Sdanielk1977do_test minmax3-2.2 {
162e5f5b8f1Sdanielk1977  execsql { SELECT min(b) FROM t2 WHERE a = 1; }
163e5f5b8f1Sdanielk1977} {1}
164e5f5b8f1Sdanielk1977do_test minmax3-2.3 {
165e5f5b8f1Sdanielk1977  execsql { SELECT min(b) FROM t2 WHERE a = 1 AND b>1; }
166e5f5b8f1Sdanielk1977} {2}
167e5f5b8f1Sdanielk1977do_test minmax3-2.4 {
168e5f5b8f1Sdanielk1977  execsql { SELECT min(b) FROM t2 WHERE a = 1 AND b>-1; }
169e5f5b8f1Sdanielk1977} {1}
170e5f5b8f1Sdanielk1977do_test minmax3-2.5 {
171e5f5b8f1Sdanielk1977  execsql { SELECT min(b) FROM t2 WHERE a = 1; }
172e5f5b8f1Sdanielk1977} {1}
173e5f5b8f1Sdanielk1977do_test minmax3-2.6 {
174e5f5b8f1Sdanielk1977  execsql { SELECT min(b) FROM t2 WHERE a = 1 AND b<2; }
175e5f5b8f1Sdanielk1977} {1}
176e5f5b8f1Sdanielk1977do_test minmax3-2.7 {
177e5f5b8f1Sdanielk1977  execsql { SELECT min(b) FROM t2 WHERE a = 1 AND b<1; }
178e5f5b8f1Sdanielk1977} {{}}
179e5f5b8f1Sdanielk1977do_test minmax3-2.8 {
180e5f5b8f1Sdanielk1977  execsql { SELECT min(b) FROM t2 WHERE a = 3 AND b<1; }
181e5f5b8f1Sdanielk1977} {{}}
182a9d1ccb9Sdanielk1977
1831d9da70aSdrhdo_test minmax3-3.1 {
184473c3522Sdanielk1977  execsql {
185473c3522Sdanielk1977    DROP TABLE t2;
186473c3522Sdanielk1977    CREATE TABLE t2(a, b);
187473c3522Sdanielk1977    CREATE INDEX i3 ON t2(a, b DESC);
188473c3522Sdanielk1977    INSERT INTO t2 VALUES(1, NULL);
189473c3522Sdanielk1977    INSERT INTO t2 VALUES(1, 1);
190473c3522Sdanielk1977    INSERT INTO t2 VALUES(1, 2);
191473c3522Sdanielk1977    INSERT INTO t2 VALUES(1, 3);
192473c3522Sdanielk1977    INSERT INTO t2 VALUES(2, NULL);
193473c3522Sdanielk1977    INSERT INTO t2 VALUES(2, 1);
194473c3522Sdanielk1977    INSERT INTO t2 VALUES(2, 2);
195473c3522Sdanielk1977    INSERT INTO t2 VALUES(2, 3);
196473c3522Sdanielk1977    INSERT INTO t2 VALUES(3, 1);
197473c3522Sdanielk1977    INSERT INTO t2 VALUES(3, 2);
198473c3522Sdanielk1977    INSERT INTO t2 VALUES(3, 3);
199473c3522Sdanielk1977  }
200473c3522Sdanielk1977} {}
2011d9da70aSdrhdo_test minmax3-3.2 {
202473c3522Sdanielk1977  execsql { SELECT min(b) FROM t2 WHERE a = 1; }
203473c3522Sdanielk1977} {1}
2041d9da70aSdrhdo_test minmax3-3.3 {
205473c3522Sdanielk1977  execsql { SELECT min(b) FROM t2 WHERE a = 1 AND b>1; }
206473c3522Sdanielk1977} {2}
2071d9da70aSdrhdo_test minmax3-3.4 {
208473c3522Sdanielk1977  execsql { SELECT min(b) FROM t2 WHERE a = 1 AND b>-1; }
209473c3522Sdanielk1977} {1}
2101d9da70aSdrhdo_test minmax3-3.5 {
211473c3522Sdanielk1977  execsql { SELECT min(b) FROM t2 WHERE a = 1; }
212473c3522Sdanielk1977} {1}
2131d9da70aSdrhdo_test minmax3-3.6 {
214473c3522Sdanielk1977  execsql { SELECT min(b) FROM t2 WHERE a = 1 AND b<2; }
215473c3522Sdanielk1977} {1}
2161d9da70aSdrhdo_test minmax3-3.7 {
217473c3522Sdanielk1977  execsql { SELECT min(b) FROM t2 WHERE a = 1 AND b<1; }
218473c3522Sdanielk1977} {{}}
2191d9da70aSdrhdo_test minmax3-3.8 {
220473c3522Sdanielk1977  execsql { SELECT min(b) FROM t2 WHERE a = 3 AND b<1; }
221473c3522Sdanielk1977} {{}}
222473c3522Sdanielk1977
2231d9da70aSdrhdo_test minmax3-4.1 {
2241d9da70aSdrh  execsql {
2251d9da70aSdrh    CREATE TABLE t4(x);
2261d9da70aSdrh    INSERT INTO t4 VALUES('abc');
2271d9da70aSdrh    INSERT INTO t4 VALUES('BCD');
2281d9da70aSdrh    SELECT max(x) FROM t4;
2291d9da70aSdrh  }
2301d9da70aSdrh} {abc}
2311d9da70aSdrhdo_test minmax3-4.2 {
2321d9da70aSdrh  execsql {
2331d9da70aSdrh    SELECT max(x COLLATE nocase) FROM t4;
2341d9da70aSdrh  }
2351d9da70aSdrh} {BCD}
2361d9da70aSdrhdo_test minmax3-4.3 {
2371d9da70aSdrh  execsql {
2381d9da70aSdrh    SELECT max(x), max(x COLLATE nocase) FROM t4;
2391d9da70aSdrh  }
2401d9da70aSdrh} {abc BCD}
2411d9da70aSdrhdo_test minmax3-4.4 {
2421d9da70aSdrh  execsql {
2431d9da70aSdrh    SELECT max(x COLLATE binary), max(x COLLATE nocase) FROM t4;
2441d9da70aSdrh  }
2451d9da70aSdrh} {abc BCD}
2461d9da70aSdrhdo_test minmax3-4.5 {
2471d9da70aSdrh  execsql {
2481d9da70aSdrh    SELECT max(x COLLATE nocase), max(x COLLATE rtrim) FROM t4;
2491d9da70aSdrh  }
2501d9da70aSdrh} {BCD abc}
2511d9da70aSdrhdo_test minmax3-4.6 {
2521d9da70aSdrh  execsql {
2531d9da70aSdrh    SELECT max(x COLLATE nocase), max(x) FROM t4;
2541d9da70aSdrh  }
2551d9da70aSdrh} {BCD abc}
2561d9da70aSdrhdo_test minmax3-4.10 {
2571d9da70aSdrh  execsql {
2581d9da70aSdrh    SELECT min(x) FROM t4;
2591d9da70aSdrh  }
2601d9da70aSdrh} {BCD}
2611d9da70aSdrhdo_test minmax3-4.11 {
2621d9da70aSdrh  execsql {
2631d9da70aSdrh    SELECT min(x COLLATE nocase) FROM t4;
2641d9da70aSdrh  }
2651d9da70aSdrh} {abc}
2661d9da70aSdrhdo_test minmax3-4.12 {
2671d9da70aSdrh  execsql {
2681d9da70aSdrh    SELECT min(x), min(x COLLATE nocase) FROM t4;
2691d9da70aSdrh  }
2701d9da70aSdrh} {BCD abc}
2711d9da70aSdrhdo_test minmax3-4.13 {
2721d9da70aSdrh  execsql {
2731d9da70aSdrh    SELECT min(x COLLATE binary), min(x COLLATE nocase) FROM t4;
2741d9da70aSdrh  }
2751d9da70aSdrh} {BCD abc}
2761d9da70aSdrhdo_test minmax3-4.14 {
2771d9da70aSdrh  execsql {
2781d9da70aSdrh    SELECT min(x COLLATE nocase), min(x COLLATE rtrim) FROM t4;
2791d9da70aSdrh  }
2801d9da70aSdrh} {abc BCD}
2811d9da70aSdrhdo_test minmax3-4.15 {
2821d9da70aSdrh  execsql {
2831d9da70aSdrh    SELECT min(x COLLATE nocase), min(x) FROM t4;
2841d9da70aSdrh  }
2851d9da70aSdrh} {abc BCD}
2861d9da70aSdrh
2871d9da70aSdrh
288a9d1ccb9Sdanielk1977finish_test
289