xref: /sqlite-3.40.0/test/select2.test (revision ed754ce2)
1b19a2bc6Sdrh# 2001 September 15
2bed8690fSdrh#
3b19a2bc6Sdrh# The author disclaims copyright to this source code.  In place of
4b19a2bc6Sdrh# a legal notice, here is a blessing:
5bed8690fSdrh#
6b19a2bc6Sdrh#    May you do good and not evil.
7b19a2bc6Sdrh#    May you find forgiveness for yourself and forgive others.
8b19a2bc6Sdrh#    May you share freely, never taking more than you give.
9bed8690fSdrh#
10bed8690fSdrh#***********************************************************************
11bed8690fSdrh# This file implements regression tests for SQLite library.  The
12bed8690fSdrh# focus of this file is testing the SELECT statement.
13bed8690fSdrh#
14ef731a7bSdrh# $Id: select2.test,v 1.28 2009/01/15 15:23:59 drh Exp $
15bed8690fSdrh
16bed8690fSdrhset testdir [file dirname $argv0]
17bed8690fSdrhsource $testdir/tester.tcl
18bed8690fSdrh
19d75f54edSdrh# Create a table with some data
20d75f54edSdrh#
21bed8690fSdrhexecsql {CREATE TABLE tbl1(f1 int, f2 int)}
225f3b4ab5Sdrhexecsql {BEGIN}
23bed8690fSdrhfor {set i 0} {$i<=30} {incr i} {
245f3b4ab5Sdrh  execsql "INSERT INTO tbl1 VALUES([expr {$i%9}],[expr {$i%10}])"
25bed8690fSdrh}
265f3b4ab5Sdrhexecsql {COMMIT}
27bed8690fSdrh
28bed8690fSdrh# Do a second query inside a first.
29bed8690fSdrh#
30bed8690fSdrhdo_test select2-1.1 {
31bed8690fSdrh  set sql {SELECT DISTINCT f1 FROM tbl1 ORDER BY f1}
32bed8690fSdrh  set r {}
33cbb18d22Sdanielk1977  catch {unset data}
34bed8690fSdrh  db eval $sql data {
35bed8690fSdrh    set f1 $data(f1)
36bed8690fSdrh    lappend r $f1:
37bed8690fSdrh    set sql2 "SELECT f2 FROM tbl1 WHERE f1=$f1 ORDER BY f2"
38bed8690fSdrh    db eval $sql2 d2 {
39bed8690fSdrh      lappend r $d2(f2)
40bed8690fSdrh    }
41bed8690fSdrh  }
42bed8690fSdrh  set r
43bed8690fSdrh} {0: 0 7 8 9 1: 0 1 8 9 2: 0 1 2 9 3: 0 1 2 3 4: 2 3 4 5: 3 4 5 6: 4 5 6 7: 5 6 7 8: 6 7 8}
44bed8690fSdrh
45bed8690fSdrhdo_test select2-1.2 {
46bed8690fSdrh  set sql {SELECT DISTINCT f1 FROM tbl1 WHERE f1>3 AND f1<5}
47bed8690fSdrh  set r {}
48bed8690fSdrh  db eval $sql data {
49bed8690fSdrh    set f1 $data(f1)
50bed8690fSdrh    lappend r $f1:
51bed8690fSdrh    set sql2 "SELECT f2 FROM tbl1 WHERE f1=$f1 ORDER BY f2"
52bed8690fSdrh    db eval $sql2 d2 {
53bed8690fSdrh      lappend r $d2(f2)
54bed8690fSdrh    }
55bed8690fSdrh  }
56bed8690fSdrh  set r
57bed8690fSdrh} {4: 2 3 4}
589c9eb741Sdanielk1977unset data
59bed8690fSdrh
60190765c4Sdrh# Create a largish table. Do this twice, once using the TCL cache and once
61190765c4Sdrh# without.  Compare the performance to make sure things go faster with the
62190765c4Sdrh# cache turned on.
63d75f54edSdrh#
64190765c4Sdrhifcapable tclvar {
65190765c4Sdrh  do_test select2-2.0.1 {
66190765c4Sdrh    set t1 [time {
675f3b4ab5Sdrh      execsql {CREATE TABLE tbl2(f1 int, f2 int, f3 int); BEGIN;}
68d75f54edSdrh      for {set i 1} {$i<=30000} {incr i} {
69190765c4Sdrh        set i2 [expr {$i*2}]
70190765c4Sdrh        set i3 [expr {$i*3}]
71190765c4Sdrh        db eval {INSERT INTO tbl2 VALUES($i,$i2,$i3)}
72d75f54edSdrh      }
735f3b4ab5Sdrh      execsql {COMMIT}
74190765c4Sdrh    }]
759636c4e1Sdanielk1977    list
7619a775c2Sdrh  } {}
77190765c4Sdrh  puts "time with cache: $::t1"
78190765c4Sdrh}
79190765c4Sdrhcatch {execsql {DROP TABLE tbl2}}
80190765c4Sdrhdo_test select2-2.0.2 {
81190765c4Sdrh  set t2 [time {
82190765c4Sdrh    execsql {CREATE TABLE tbl2(f1 int, f2 int, f3 int); BEGIN;}
83190765c4Sdrh    for {set i 1} {$i<=30000} {incr i} {
84190765c4Sdrh      set i2 [expr {$i*2}]
85190765c4Sdrh      set i3 [expr {$i*3}]
86190765c4Sdrh      execsql "INSERT INTO tbl2 VALUES($i,$i2,$i3)"
87190765c4Sdrh    }
88190765c4Sdrh    execsql {COMMIT}
89190765c4Sdrh  }]
909636c4e1Sdanielk1977  list
91190765c4Sdrh} {}
92190765c4Sdrhputs "time without cache: $t2"
93ef731a7bSdrh#ifcapable tclvar {
94ef731a7bSdrh#  do_test select2-2.0.3 {
95ef731a7bSdrh#    expr {[lindex $t1 0]<[lindex $t2 0]}
96ef731a7bSdrh#  } 1
97ef731a7bSdrh#}
98d75f54edSdrh
99d75f54edSdrhdo_test select2-2.1 {
100d75f54edSdrh  execsql {SELECT count(*) FROM tbl2}
101d75f54edSdrh} {30000}
102d75f54edSdrhdo_test select2-2.2 {
103d75f54edSdrh  execsql {SELECT count(*) FROM tbl2 WHERE f2>1000}
104d75f54edSdrh} {29500}
105d75f54edSdrh
106d75f54edSdrhdo_test select2-3.1 {
107e840972fSdrh  execsql {SELECT f1 FROM tbl2 WHERE 1000=f2}
108d75f54edSdrh} {500}
109d75f54edSdrh
11019a775c2Sdrhdo_test select2-3.2a {
111d75f54edSdrh  execsql {CREATE INDEX idx1 ON tbl2(f2)}
11219a775c2Sdrh} {}
11319a775c2Sdrhdo_test select2-3.2b {
1143d1bfeaaSdanielk1977  execsql {SELECT f1 FROM tbl2 WHERE 1000=f2}
115d75f54edSdrh} {500}
116e840972fSdrhdo_test select2-3.2c {
1173d1bfeaaSdanielk1977  execsql {SELECT f1 FROM tbl2 WHERE f2=1000}
118e840972fSdrh} {500}
119e840972fSdrhdo_test select2-3.2d {
120487ab3caSdrh  set sqlite_search_count 0
1213d1bfeaaSdanielk1977  execsql {SELECT * FROM tbl2 WHERE 1000=f2}
122487ab3caSdrh  set sqlite_search_count
123487ab3caSdrh} {3}
124767c2001Sdrhdo_test select2-3.2e {
125487ab3caSdrh  set sqlite_search_count 0
1263d1bfeaaSdanielk1977  execsql {SELECT * FROM tbl2 WHERE f2=1000}
127487ab3caSdrh  set sqlite_search_count
128487ab3caSdrh} {3}
129d75f54edSdrh
130d75f54edSdrh# Make sure queries run faster with an index than without
131d75f54edSdrh#
132487ab3caSdrhdo_test select2-3.3 {
133d75f54edSdrh  execsql {DROP INDEX idx1}
134487ab3caSdrh  set sqlite_search_count 0
135487ab3caSdrh  execsql {SELECT f1 FROM tbl2 WHERE f2==2000}
136487ab3caSdrh  set sqlite_search_count
137487ab3caSdrh} {29999}
138d75f54edSdrh
139dd579122Sdrh# Make sure we can optimize functions in the WHERE clause that
140dd579122Sdrh# use fields from two or more different table.  (Bug #6)
141dd579122Sdrh#
142dd579122Sdrhdo_test select2-4.1 {
143dd579122Sdrh  execsql {
144dd579122Sdrh    CREATE TABLE aa(a);
145dd579122Sdrh    CREATE TABLE bb(b);
146dd579122Sdrh    INSERT INTO aa VALUES(1);
147dd579122Sdrh    INSERT INTO aa VALUES(3);
148dd579122Sdrh    INSERT INTO bb VALUES(2);
149dd579122Sdrh    INSERT INTO bb VALUES(4);
150dd579122Sdrh    SELECT * FROM aa, bb WHERE max(a,b)>2;
151dd579122Sdrh  }
152dd579122Sdrh} {1 4 3 2 3 4}
1533f6b5489Sdrhdo_test select2-4.2 {
1543f6b5489Sdrh  execsql {
1553f6b5489Sdrh    INSERT INTO bb VALUES(0);
156*ed754ce2Sdrh    SELECT * FROM aa CROSS JOIN bb WHERE b;
1573f6b5489Sdrh  }
1583f6b5489Sdrh} {1 2 1 4 3 2 3 4}
1593f6b5489Sdrhdo_test select2-4.3 {
1603f6b5489Sdrh  execsql {
161*ed754ce2Sdrh    SELECT * FROM aa CROSS JOIN bb WHERE NOT b;
1623f6b5489Sdrh  }
1633f6b5489Sdrh} {1 0 3 0}
1643f6b5489Sdrhdo_test select2-4.4 {
1653f6b5489Sdrh  execsql {
1663f6b5489Sdrh    SELECT * FROM aa, bb WHERE min(a,b);
1673f6b5489Sdrh  }
1683f6b5489Sdrh} {1 2 1 4 3 2 3 4}
1693f6b5489Sdrhdo_test select2-4.5 {
1703f6b5489Sdrh  execsql {
1713f6b5489Sdrh    SELECT * FROM aa, bb WHERE NOT min(a,b);
1723f6b5489Sdrh  }
1733f6b5489Sdrh} {1 0 3 0}
1743f6b5489Sdrhdo_test select2-4.6 {
1753f6b5489Sdrh  execsql {
1763f6b5489Sdrh    SELECT * FROM aa, bb WHERE CASE WHEN a=b-1 THEN 1 END;
1773f6b5489Sdrh  }
1783f6b5489Sdrh} {1 2 3 4}
1793f6b5489Sdrhdo_test select2-4.7 {
1803f6b5489Sdrh  execsql {
1813f6b5489Sdrh    SELECT * FROM aa, bb WHERE CASE WHEN a=b-1 THEN 0 ELSE 1 END;
1823f6b5489Sdrh  }
1833f6b5489Sdrh} {1 4 1 0 3 2 3 0}
184dd579122Sdrh
185bed8690fSdrhfinish_test
186