mirror of
https://github.com/sqlite/sqlite.git
synced 2025-11-16 23:02:26 +03:00
Merge orderby-planning with this branch.
FossilOrigin-Name: d9549de31741239ece060e448b592ce8fc5b8042
This commit is contained in:
@@ -103,12 +103,21 @@ do_test analyze3-1.1.1 {
|
||||
}
|
||||
} {1}
|
||||
|
||||
do_execsql_test analyze3-1.1.x {
|
||||
SELECT count(*) FROM t1 WHERE x>200 AND x<300;
|
||||
SELECT count(*) FROM t1 WHERE x>0 AND x<1100;
|
||||
} {99 1000}
|
||||
|
||||
# The first of the following two SELECT statements visits 99 rows. So
|
||||
# it is better to use the index. But the second visits every row in
|
||||
# the table (1000 in total) so it is better to do a full-table scan.
|
||||
#
|
||||
do_eqp_test analyze3-1.1.2 {
|
||||
SELECT sum(y) FROM t1 WHERE x>200 AND x<300
|
||||
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (x>? AND x<?)}}
|
||||
do_eqp_test analyze3-1.1.3 {
|
||||
SELECT sum(y) FROM t1 WHERE x>0 AND x<1100
|
||||
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (x>? AND x<?)}}
|
||||
} {0 0 0 {SCAN TABLE t1}}
|
||||
|
||||
do_test analyze3-1.1.4 {
|
||||
sf_execsql { SELECT sum(y) FROM t1 WHERE x>200 AND x<300 }
|
||||
@@ -125,17 +134,17 @@ do_test analyze3-1.1.6 {
|
||||
} {199 0 14850}
|
||||
do_test analyze3-1.1.7 {
|
||||
sf_execsql { SELECT sum(y) FROM t1 WHERE x>0 AND x<1100 }
|
||||
} {2000 0 499500}
|
||||
} {999 999 499500}
|
||||
do_test analyze3-1.1.8 {
|
||||
set l [string range "0" 0 end]
|
||||
set u [string range "1100" 0 end]
|
||||
sf_execsql { SELECT sum(y) FROM t1 WHERE x>$l AND x<$u }
|
||||
} {2000 0 499500}
|
||||
} {999 999 499500}
|
||||
do_test analyze3-1.1.9 {
|
||||
set l [expr int(0)]
|
||||
set u [expr int(1100)]
|
||||
sf_execsql { SELECT sum(y) FROM t1 WHERE x>$l AND x<$u }
|
||||
} {2000 0 499500}
|
||||
} {999 999 499500}
|
||||
|
||||
|
||||
# The following tests are similar to the block above. The difference is
|
||||
@@ -152,12 +161,17 @@ do_test analyze3-1.2.1 {
|
||||
ANALYZE;
|
||||
}
|
||||
} {}
|
||||
do_execsql_test analyze3-2.1.x {
|
||||
SELECT count(*) FROM t2 WHERE x>1 AND x<2;
|
||||
SELECT count(*) FROM t2 WHERE x>0 AND x<99;
|
||||
} {200 990}
|
||||
do_eqp_test analyze3-1.2.2 {
|
||||
SELECT sum(y) FROM t2 WHERE x>1 AND x<2
|
||||
} {0 0 0 {SEARCH TABLE t2 USING INDEX i2 (x>? AND x<?)}}
|
||||
do_eqp_test analyze3-1.2.3 {
|
||||
SELECT sum(y) FROM t2 WHERE x>0 AND x<99
|
||||
} {0 0 0 {SEARCH TABLE t2 USING INDEX i2 (x>? AND x<?)}}
|
||||
} {0 0 0 {SCAN TABLE t2}}
|
||||
|
||||
do_test analyze3-1.2.4 {
|
||||
sf_execsql { SELECT sum(y) FROM t2 WHERE x>12 AND x<20 }
|
||||
} {161 0 4760}
|
||||
@@ -173,17 +187,17 @@ do_test analyze3-1.2.6 {
|
||||
} {161 0 integer integer 4760}
|
||||
do_test analyze3-1.2.7 {
|
||||
sf_execsql { SELECT sum(y) FROM t2 WHERE x>0 AND x<99 }
|
||||
} {1981 0 490555}
|
||||
} {999 999 490555}
|
||||
do_test analyze3-1.2.8 {
|
||||
set l [string range "0" 0 end]
|
||||
set u [string range "99" 0 end]
|
||||
sf_execsql {SELECT typeof($l), typeof($u), sum(y) FROM t2 WHERE x>$l AND x<$u}
|
||||
} {1981 0 text text 490555}
|
||||
} {999 999 text text 490555}
|
||||
do_test analyze3-1.2.9 {
|
||||
set l [expr int(0)]
|
||||
set u [expr int(99)]
|
||||
sf_execsql {SELECT typeof($l), typeof($u), sum(y) FROM t2 WHERE x>$l AND x<$u}
|
||||
} {1981 0 integer integer 490555}
|
||||
} {999 999 integer integer 490555}
|
||||
|
||||
# Same tests a third time. This time, column x has INTEGER affinity and
|
||||
# is not the leftmost column of the table. This triggered a bug causing
|
||||
@@ -199,12 +213,16 @@ do_test analyze3-1.3.1 {
|
||||
ANALYZE;
|
||||
}
|
||||
} {}
|
||||
do_execsql_test analyze3-1.3.x {
|
||||
SELECT count(*) FROM t3 WHERE x>200 AND x<300;
|
||||
SELECT count(*) FROM t3 WHERE x>0 AND x<1100
|
||||
} {99 1000}
|
||||
do_eqp_test analyze3-1.3.2 {
|
||||
SELECT sum(y) FROM t3 WHERE x>200 AND x<300
|
||||
} {0 0 0 {SEARCH TABLE t3 USING INDEX i3 (x>? AND x<?)}}
|
||||
do_eqp_test analyze3-1.3.3 {
|
||||
SELECT sum(y) FROM t3 WHERE x>0 AND x<1100
|
||||
} {0 0 0 {SEARCH TABLE t3 USING INDEX i3 (x>? AND x<?)}}
|
||||
} {0 0 0 {SCAN TABLE t3}}
|
||||
|
||||
do_test analyze3-1.3.4 {
|
||||
sf_execsql { SELECT sum(y) FROM t3 WHERE x>200 AND x<300 }
|
||||
@@ -221,17 +239,17 @@ do_test analyze3-1.3.6 {
|
||||
} {199 0 14850}
|
||||
do_test analyze3-1.3.7 {
|
||||
sf_execsql { SELECT sum(y) FROM t3 WHERE x>0 AND x<1100 }
|
||||
} {2000 0 499500}
|
||||
} {999 999 499500}
|
||||
do_test analyze3-1.3.8 {
|
||||
set l [string range "0" 0 end]
|
||||
set u [string range "1100" 0 end]
|
||||
sf_execsql { SELECT sum(y) FROM t3 WHERE x>$l AND x<$u }
|
||||
} {2000 0 499500}
|
||||
} {999 999 499500}
|
||||
do_test analyze3-1.3.9 {
|
||||
set l [expr int(0)]
|
||||
set u [expr int(1100)]
|
||||
sf_execsql { SELECT sum(y) FROM t3 WHERE x>$l AND x<$u }
|
||||
} {2000 0 499500}
|
||||
} {999 999 499500}
|
||||
|
||||
#-------------------------------------------------------------------------
|
||||
# Test that the values of bound SQL variables may be used for the LIKE
|
||||
|
||||
@@ -566,7 +566,7 @@ foreach {tn schema} {
|
||||
drop_all_tables
|
||||
do_test 13.1 {
|
||||
execsql {
|
||||
CREATE TABLE t1(a, b, c);
|
||||
CREATE TABLE t1(a, b, c, d);
|
||||
CREATE INDEX i1 ON t1(a);
|
||||
CREATE INDEX i2 ON t1(b, c);
|
||||
}
|
||||
@@ -577,16 +577,16 @@ do_test 13.1 {
|
||||
execsql ANALYZE
|
||||
} {}
|
||||
do_eqp_test 13.2.1 {
|
||||
SELECT * FROM t1 WHERE a='abc' AND rowid<15 AND b<20
|
||||
SELECT * FROM t1 WHERE a='abc' AND rowid<15 AND b<12
|
||||
} {/SEARCH TABLE t1 USING INDEX i1/}
|
||||
do_eqp_test 13.2.2 {
|
||||
SELECT * FROM t1 WHERE a='abc' AND rowid<'15' AND b<20
|
||||
SELECT * FROM t1 WHERE a='abc' AND rowid<'15' AND b<12
|
||||
} {/SEARCH TABLE t1 USING INDEX i1/}
|
||||
do_eqp_test 13.3.1 {
|
||||
SELECT * FROM t1 WHERE a='abc' AND rowid<100 AND b<20
|
||||
SELECT * FROM t1 WHERE a='abc' AND rowid<100 AND b<12
|
||||
} {/SEARCH TABLE t1 USING INDEX i2/}
|
||||
do_eqp_test 13.3.2 {
|
||||
SELECT * FROM t1 WHERE a='abc' AND rowid<'100' AND b<20
|
||||
SELECT * FROM t1 WHERE a='abc' AND rowid<'100' AND b<12
|
||||
} {/SEARCH TABLE t1 USING INDEX i2/}
|
||||
|
||||
#-------------------------------------------------------------------------
|
||||
|
||||
@@ -97,6 +97,8 @@ do_test autoindex1-210 {
|
||||
PRAGMA automatic_index=ON;
|
||||
ANALYZE;
|
||||
UPDATE sqlite_stat1 SET stat='10000' WHERE tbl='t1';
|
||||
-- Table t2 actually contains 8 rows.
|
||||
UPDATE sqlite_stat1 SET stat='16' WHERE tbl='t2';
|
||||
ANALYZE sqlite_master;
|
||||
SELECT b, (SELECT d FROM t2 WHERE c=a) FROM t1;
|
||||
}
|
||||
|
||||
251
test/cost.test
Normal file
251
test/cost.test
Normal file
@@ -0,0 +1,251 @@
|
||||
# 2014-04-26
|
||||
#
|
||||
# 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.
|
||||
#
|
||||
#***********************************************************************
|
||||
#
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
set testprefix cost
|
||||
|
||||
|
||||
do_execsql_test 1.1 {
|
||||
CREATE TABLE t3(id INTEGER PRIMARY KEY, b NOT NULL);
|
||||
CREATE TABLE t4(c, d, e);
|
||||
CREATE UNIQUE INDEX i3 ON t3(b);
|
||||
CREATE UNIQUE INDEX i4 ON t4(c, d);
|
||||
}
|
||||
do_eqp_test 1.2 {
|
||||
SELECT e FROM t3, t4 WHERE b=c ORDER BY b, d;
|
||||
} {
|
||||
0 0 0 {SCAN TABLE t3 USING COVERING INDEX i3}
|
||||
0 1 1 {SEARCH TABLE t4 USING INDEX i4 (c=?)}
|
||||
}
|
||||
|
||||
|
||||
do_execsql_test 2.1 {
|
||||
CREATE TABLE t1(a, b);
|
||||
CREATE INDEX i1 ON t1(a);
|
||||
}
|
||||
|
||||
# It is better to use an index for ORDER BY than sort externally, even
|
||||
# if the index is a non-covering index.
|
||||
do_eqp_test 2.2 {
|
||||
SELECT * FROM t1 ORDER BY a;
|
||||
} {
|
||||
0 0 0 {SCAN TABLE t1 USING INDEX i1}
|
||||
}
|
||||
|
||||
do_execsql_test 3.1 {
|
||||
CREATE TABLE t5(a INTEGER PRIMARY KEY,b,c,d,e,f,g);
|
||||
CREATE INDEX t5b ON t5(b);
|
||||
CREATE INDEX t5c ON t5(c);
|
||||
CREATE INDEX t5d ON t5(d);
|
||||
CREATE INDEX t5e ON t5(e);
|
||||
CREATE INDEX t5f ON t5(f);
|
||||
CREATE INDEX t5g ON t5(g);
|
||||
}
|
||||
|
||||
do_eqp_test 3.2 {
|
||||
SELECT a FROM t5
|
||||
WHERE b IS NULL OR c IS NULL OR d IS NULL
|
||||
ORDER BY a;
|
||||
} {
|
||||
0 0 0 {SEARCH TABLE t5 USING INDEX t5b (b=?)}
|
||||
0 0 0 {SEARCH TABLE t5 USING INDEX t5c (c=?)}
|
||||
0 0 0 {SEARCH TABLE t5 USING INDEX t5d (d=?)}
|
||||
0 0 0 {USE TEMP B-TREE FOR ORDER BY}
|
||||
}
|
||||
|
||||
#-------------------------------------------------------------------------
|
||||
# If there is no likelihood() or stat3 data, SQLite assumes that a closed
|
||||
# range scan (e.g. one constrained by "col BETWEEN ? AND ?" constraint)
|
||||
# visits 1/64 of the rows in a table.
|
||||
#
|
||||
# Note: 1/63 =~ 0.016
|
||||
# Note: 1/65 =~ 0.015
|
||||
#
|
||||
reset_db
|
||||
do_execsql_test 4.1 {
|
||||
CREATE TABLE t1(a, b);
|
||||
CREATE INDEX i1 ON t1(a);
|
||||
CREATE INDEX i2 ON t1(b);
|
||||
}
|
||||
do_eqp_test 4.2 {
|
||||
SELECT * FROM t1 WHERE likelihood(a=?, 0.014) AND b BETWEEN ? AND ?;
|
||||
} {
|
||||
0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}
|
||||
}
|
||||
do_eqp_test 4.3 {
|
||||
SELECT * FROM t1 WHERE likelihood(a=?, 0.016) AND b BETWEEN ? AND ?;
|
||||
} {
|
||||
0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b>? AND b<?)}
|
||||
}
|
||||
|
||||
|
||||
#-------------------------------------------------------------------------
|
||||
#
|
||||
reset_db
|
||||
do_execsql_test 5.1 {
|
||||
CREATE TABLE t2(x, y);
|
||||
CREATE INDEX t2i1 ON t2(x);
|
||||
}
|
||||
|
||||
do_eqp_test 5.2 {
|
||||
SELECT * FROM t2 ORDER BY x, y;
|
||||
} {
|
||||
0 0 0 {SCAN TABLE t2 USING INDEX t2i1}
|
||||
0 0 0 {USE TEMP B-TREE FOR RIGHT PART OF ORDER BY}
|
||||
}
|
||||
|
||||
do_eqp_test 5.3 {
|
||||
SELECT * FROM t2 WHERE x BETWEEN ? AND ? ORDER BY rowid;
|
||||
} {
|
||||
0 0 0 {SEARCH TABLE t2 USING INDEX t2i1 (x>? AND x<?)}
|
||||
0 0 0 {USE TEMP B-TREE FOR ORDER BY}
|
||||
}
|
||||
|
||||
# where7.test, where8.test:
|
||||
#
|
||||
do_execsql_test 6.1 {
|
||||
CREATE TABLE t3(a INTEGER PRIMARY KEY, b, c);
|
||||
CREATE INDEX t3i1 ON t3(b);
|
||||
CREATE INDEX t3i2 ON t3(c);
|
||||
}
|
||||
|
||||
do_eqp_test 6.2 {
|
||||
SELECT a FROM t3 WHERE (b BETWEEN 2 AND 4) OR c=100 ORDER BY a
|
||||
} {
|
||||
0 0 0 {SEARCH TABLE t3 USING INDEX t3i1 (b>? AND b<?)}
|
||||
0 0 0 {SEARCH TABLE t3 USING INDEX t3i2 (c=?)}
|
||||
0 0 0 {USE TEMP B-TREE FOR ORDER BY}
|
||||
}
|
||||
|
||||
#-------------------------------------------------------------------------
|
||||
#
|
||||
reset_db
|
||||
do_execsql_test 7.1 {
|
||||
CREATE TABLE t1(a INTEGER PRIMARY KEY,b,c,d,e,f,g);
|
||||
CREATE INDEX t1b ON t1(b);
|
||||
CREATE INDEX t1c ON t1(c);
|
||||
CREATE INDEX t1d ON t1(d);
|
||||
CREATE INDEX t1e ON t1(e);
|
||||
CREATE INDEX t1f ON t1(f);
|
||||
CREATE INDEX t1g ON t1(g);
|
||||
}
|
||||
|
||||
do_eqp_test 7.2 {
|
||||
SELECT a FROM t1
|
||||
WHERE (b>=950 AND b<=1010) OR (b IS NULL AND c NOT NULL)
|
||||
ORDER BY a
|
||||
} {
|
||||
0 0 0 {SEARCH TABLE t1 USING INDEX t1b (b>? AND b<?)}
|
||||
0 0 0 {SEARCH TABLE t1 USING INDEX t1b (b=?)}
|
||||
0 0 0 {USE TEMP B-TREE FOR ORDER BY}
|
||||
}
|
||||
|
||||
do_eqp_test 7.3 {
|
||||
SELECT rowid FROM t1
|
||||
WHERE (+b IS NULL AND c NOT NULL AND d NOT NULL)
|
||||
OR (b NOT NULL AND c IS NULL AND d NOT NULL)
|
||||
OR (b NOT NULL AND c NOT NULL AND d IS NULL)
|
||||
} {
|
||||
0 0 0 {SCAN TABLE t1}
|
||||
}
|
||||
|
||||
do_eqp_test 7.4 {
|
||||
SELECT rowid FROM t1 WHERE (+b IS NULL AND c NOT NULL) OR c IS NULL
|
||||
} {
|
||||
0 0 0 {SCAN TABLE t1}
|
||||
}
|
||||
|
||||
#-------------------------------------------------------------------------
|
||||
#
|
||||
reset_db
|
||||
do_execsql_test 8.1 {
|
||||
CREATE TABLE composer(
|
||||
cid INTEGER PRIMARY KEY,
|
||||
cname TEXT
|
||||
);
|
||||
CREATE TABLE album(
|
||||
aid INTEGER PRIMARY KEY,
|
||||
aname TEXT
|
||||
);
|
||||
CREATE TABLE track(
|
||||
tid INTEGER PRIMARY KEY,
|
||||
cid INTEGER REFERENCES composer,
|
||||
aid INTEGER REFERENCES album,
|
||||
title TEXT
|
||||
);
|
||||
CREATE INDEX track_i1 ON track(cid);
|
||||
CREATE INDEX track_i2 ON track(aid);
|
||||
}
|
||||
|
||||
do_eqp_test 8.2 {
|
||||
SELECT DISTINCT aname
|
||||
FROM album, composer, track
|
||||
WHERE cname LIKE '%bach%'
|
||||
AND unlikely(composer.cid=track.cid)
|
||||
AND unlikely(album.aid=track.aid);
|
||||
} {
|
||||
0 0 2 {SCAN TABLE track}
|
||||
0 1 0 {SEARCH TABLE album USING INTEGER PRIMARY KEY (rowid=?)}
|
||||
0 2 1 {SEARCH TABLE composer USING INTEGER PRIMARY KEY (rowid=?)}
|
||||
0 0 0 {USE TEMP B-TREE FOR DISTINCT}
|
||||
}
|
||||
|
||||
#-------------------------------------------------------------------------
|
||||
#
|
||||
do_execsql_test 9.1 {
|
||||
CREATE TABLE t1(
|
||||
a,b,c,d,e, f,g,h,i,j,
|
||||
k,l,m,n,o, p,q,r,s,t
|
||||
);
|
||||
CREATE INDEX i1 ON t1(k,l,m,n,o,p,q,r,s,t);
|
||||
}
|
||||
do_test 9.2 {
|
||||
for {set i 0} {$i < 100} {incr i} {
|
||||
execsql { INSERT INTO t1 DEFAULT VALUES }
|
||||
}
|
||||
execsql {
|
||||
ANALYZE;
|
||||
CREATE INDEX i2 ON t1(a,b,c,d,e,f,g,h,i,j);
|
||||
}
|
||||
} {}
|
||||
|
||||
set L [list a=? b=? c=? d=? e=? f=? g=? h=? i=? j=?]
|
||||
foreach {tn nTerm nRow} {
|
||||
1 1 10
|
||||
2 2 9
|
||||
3 3 8
|
||||
4 4 7
|
||||
5 5 6
|
||||
6 6 5
|
||||
7 7 5
|
||||
8 8 5
|
||||
9 9 5
|
||||
10 10 5
|
||||
} {
|
||||
set w [join [lrange $L 0 [expr $nTerm-1]] " AND "]
|
||||
set p1 [expr ($nRow-1) / 100.0]
|
||||
set p2 [expr ($nRow+1) / 100.0]
|
||||
|
||||
set sql1 "SELECT * FROM t1 WHERE likelihood(k=?, $p1) AND $w"
|
||||
set sql2 "SELECT * FROM t1 WHERE likelihood(k=?, $p2) AND $w"
|
||||
|
||||
do_eqp_test 9.3.$tn.1 $sql1 {/INDEX i1/}
|
||||
do_eqp_test 9.3.$tn.2 $sql2 {/INDEX i2/}
|
||||
}
|
||||
|
||||
|
||||
|
||||
finish_test
|
||||
|
||||
|
||||
|
||||
@@ -884,9 +884,10 @@ do_execsql_test e_createtable-3.3.1 {
|
||||
);
|
||||
} {}
|
||||
|
||||
# EVIDENCE-OF: R-10288-43169 For the purposes of the DEFAULT clause, an
|
||||
# EVIDENCE-OF: R-36381-62919 For the purposes of the DEFAULT clause, an
|
||||
# expression is considered constant provided that it does not contain
|
||||
# any sub-queries or string constants enclosed in double quotes.
|
||||
# any sub-queries, column or table references, or string literals
|
||||
# enclosed in double-quotes instead of single-quotes.
|
||||
#
|
||||
do_createtable_tests 3.4.1 -error {
|
||||
default value of column [x] is not constant
|
||||
|
||||
@@ -135,9 +135,9 @@ reset_db
|
||||
#
|
||||
# This also tests that foreign key constraints are disabled by default.
|
||||
#
|
||||
# EVIDENCE-OF: R-59578-04990 Foreign key constraints are disabled by
|
||||
# EVIDENCE-OF: R-44261-39702 Foreign key constraints are disabled by
|
||||
# default (for backwards compatibility), so must be enabled separately
|
||||
# for each database connection separately.
|
||||
# for each database connection.
|
||||
#
|
||||
drop_all_tables
|
||||
do_test e_fkey-4.1 {
|
||||
@@ -163,9 +163,10 @@ do_test e_fkey-4.2 {
|
||||
} {world}
|
||||
|
||||
#-------------------------------------------------------------------------
|
||||
# EVIDENCE-OF: R-15278-54456 The application can can also use a PRAGMA
|
||||
# EVIDENCE-OF: R-08013-37737 The application can also use a PRAGMA
|
||||
# foreign_keys statement to determine if foreign keys are currently
|
||||
# enabled.
|
||||
|
||||
#
|
||||
# This also tests the example code in section 2 of foreignkeys.in.
|
||||
#
|
||||
@@ -2990,8 +2991,8 @@ if {[clang_sanitize_address]==0} {
|
||||
# The setting of the recursive_triggers pragma does not affect foreign
|
||||
# key actions.
|
||||
#
|
||||
# EVIDENCE-OF: R-51769-32730 The PRAGMA recursive_triggers setting does
|
||||
# not not affect the operation of foreign key actions.
|
||||
# EVIDENCE-OF: R-44355-00270 The PRAGMA recursive_triggers setting does
|
||||
# not affect the operation of foreign key actions.
|
||||
#
|
||||
foreach recursive_triggers_setting [list 0 1 ON OFF] {
|
||||
drop_all_tables
|
||||
|
||||
@@ -312,8 +312,8 @@ do_eqp_test 4.2.3 {
|
||||
} {
|
||||
1 0 0 {SCAN TABLE t1}
|
||||
1 0 0 {USE TEMP B-TREE FOR ORDER BY}
|
||||
2 0 0 {SCAN TABLE t2}
|
||||
2 0 0 {USE TEMP B-TREE FOR ORDER BY}
|
||||
2 0 0 {SCAN TABLE t2 USING INDEX t2i1}
|
||||
2 0 0 {USE TEMP B-TREE FOR RIGHT PART OF ORDER BY}
|
||||
0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION)}
|
||||
}
|
||||
do_eqp_test 4.2.4 {
|
||||
@@ -321,8 +321,8 @@ do_eqp_test 4.2.4 {
|
||||
} {
|
||||
1 0 0 {SCAN TABLE t1}
|
||||
1 0 0 {USE TEMP B-TREE FOR ORDER BY}
|
||||
2 0 0 {SCAN TABLE t2}
|
||||
2 0 0 {USE TEMP B-TREE FOR ORDER BY}
|
||||
2 0 0 {SCAN TABLE t2 USING INDEX t2i1}
|
||||
2 0 0 {USE TEMP B-TREE FOR RIGHT PART OF ORDER BY}
|
||||
0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (INTERSECT)}
|
||||
}
|
||||
do_eqp_test 4.2.5 {
|
||||
@@ -330,8 +330,8 @@ do_eqp_test 4.2.5 {
|
||||
} {
|
||||
1 0 0 {SCAN TABLE t1}
|
||||
1 0 0 {USE TEMP B-TREE FOR ORDER BY}
|
||||
2 0 0 {SCAN TABLE t2}
|
||||
2 0 0 {USE TEMP B-TREE FOR ORDER BY}
|
||||
2 0 0 {SCAN TABLE t2 USING INDEX t2i1}
|
||||
2 0 0 {USE TEMP B-TREE FOR RIGHT PART OF ORDER BY}
|
||||
0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)}
|
||||
}
|
||||
|
||||
|
||||
@@ -145,11 +145,11 @@ 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;
|
||||
UPDATE t2 SET a=NULL WHERE b%2==0;
|
||||
CREATE INDEX t2a1 ON t2(a) WHERE a IS NOT NULL;
|
||||
SELECT count(*) FROM t2 WHERE a IS NOT NULL;
|
||||
}
|
||||
} {800}
|
||||
} {500}
|
||||
do_test index6-2.2 {
|
||||
execsql {
|
||||
EXPLAIN QUERY PLAN
|
||||
@@ -157,6 +157,7 @@ do_test index6-2.2 {
|
||||
}
|
||||
} {/.* TABLE t2 USING INDEX t2a1 .*/}
|
||||
ifcapable stat4||stat3 {
|
||||
execsql ANALYZE
|
||||
do_test index6-2.3stat4 {
|
||||
execsql {
|
||||
EXPLAIN QUERY PLAN
|
||||
|
||||
@@ -80,12 +80,12 @@ do_execsql_test 2.1a {
|
||||
EXPLAIN QUERY PLAN
|
||||
SELECT * FROM t2 WHERE a=0 ORDER BY a, b, c;
|
||||
} {~/B-TREE/}
|
||||
|
||||
do_execsql_test 2.1b {
|
||||
EXPLAIN QUERY PLAN
|
||||
SELECT * FROM t1 WHERE a=0 ORDER BY a, b, c;
|
||||
SELECT * FROM t1 WHERE likelihood(a=0, 0.05) ORDER BY a, b, c;
|
||||
} {/B-TREE/}
|
||||
|
||||
|
||||
do_execsql_test 2.2 {
|
||||
EXPLAIN QUERY PLAN
|
||||
SELECT * FROM t1 WHERE +a=0 ORDER BY a, b, c;
|
||||
|
||||
106
test/orderby7.test
Normal file
106
test/orderby7.test
Normal file
@@ -0,0 +1,106 @@
|
||||
# 2014-04-25
|
||||
#
|
||||
# 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 regression tests for SQLite library. The
|
||||
# focus of this file is testing ORDER BY optimizations on joins
|
||||
# that involve virtual tables.
|
||||
#
|
||||
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
set ::testprefix orderby7
|
||||
|
||||
ifcapable !fts3 {
|
||||
finish_test
|
||||
return
|
||||
}
|
||||
|
||||
do_execsql_test 1.0 {
|
||||
CREATE VIRTUAL TABLE fts USING fts3(content TEXT);
|
||||
INSERT INTO fts(rowid,content)
|
||||
VALUES(1,'this is a test of the fts3 virtual'),
|
||||
(2,'table used as part of a join together'),
|
||||
(3,'with the DISTINCT keyword. There was'),
|
||||
(4,'a bug at one time (2013-06 through 2014-04)'),
|
||||
(5,'that prevented this from working correctly.'),
|
||||
(11,'a row that occurs twice'),
|
||||
(12,'a row that occurs twice');
|
||||
|
||||
CREATE TABLE t1(x TEXT PRIMARY KEY, y);
|
||||
INSERT OR IGNORE INTO t1 SELECT content, rowid+100 FROM fts;
|
||||
} {}
|
||||
do_execsql_test 1.1 {
|
||||
SELECT DISTINCT fts.rowid, t1.y
|
||||
FROM fts, t1
|
||||
WHERE fts MATCH 'that twice'
|
||||
AND content=x
|
||||
ORDER BY y;
|
||||
} {11 111 12 111}
|
||||
do_execsql_test 1.2 {
|
||||
SELECT DISTINCT fts.rowid, t1.x
|
||||
FROM fts, t1
|
||||
WHERE fts MATCH 'that twice'
|
||||
AND content=x
|
||||
ORDER BY 1;
|
||||
} {11 {a row that occurs twice} 12 {a row that occurs twice}}
|
||||
do_execsql_test 1.3 {
|
||||
SELECT DISTINCT t1.x
|
||||
FROM fts, t1
|
||||
WHERE fts MATCH 'that twice'
|
||||
AND content=x
|
||||
ORDER BY 1;
|
||||
} {{a row that occurs twice}}
|
||||
do_execsql_test 1.4 {
|
||||
SELECT t1.x
|
||||
FROM fts, t1
|
||||
WHERE fts MATCH 'that twice'
|
||||
AND content=x
|
||||
ORDER BY 1;
|
||||
} {{a row that occurs twice} {a row that occurs twice}}
|
||||
do_execsql_test 1.5 {
|
||||
SELECT DISTINCT t1.x
|
||||
FROM fts, t1
|
||||
WHERE fts MATCH 'that twice'
|
||||
AND content=x;
|
||||
} {{a row that occurs twice}}
|
||||
do_execsql_test 1.6 {
|
||||
SELECT t1.x
|
||||
FROM fts, t1
|
||||
WHERE fts MATCH 'that twice'
|
||||
AND content=x;
|
||||
} {{a row that occurs twice} {a row that occurs twice}}
|
||||
|
||||
do_execsql_test 2.1 {
|
||||
SELECT DISTINCT t1.x
|
||||
FROM fts, t1
|
||||
WHERE fts.rowid=11
|
||||
AND content=x
|
||||
ORDER BY fts.rowid;
|
||||
} {{a row that occurs twice}}
|
||||
do_execsql_test 2.2 {
|
||||
SELECT DISTINCT t1.*
|
||||
FROM fts, t1
|
||||
WHERE fts.rowid=11
|
||||
AND content=x
|
||||
ORDER BY fts.rowid;
|
||||
} {{a row that occurs twice} 111}
|
||||
do_execsql_test 2.3 {
|
||||
SELECT DISTINCT t1.*
|
||||
FROM fts, t1
|
||||
WHERE fts.rowid=11
|
||||
AND content=x
|
||||
ORDER BY t1.y
|
||||
} {{a row that occurs twice} 111}
|
||||
|
||||
|
||||
|
||||
|
||||
finish_test
|
||||
@@ -21,6 +21,7 @@
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
set testprefix selectA
|
||||
|
||||
ifcapable !compound {
|
||||
finish_test
|
||||
@@ -1310,4 +1311,68 @@ do_execsql_test selectA-3.98 {
|
||||
SELECT n FROM xyz ORDER BY +n;
|
||||
} {MAD MAD+ MAD++}
|
||||
|
||||
#-------------------------------------------------------------------------
|
||||
# At one point the following code exposed a temp register reuse problem.
|
||||
#
|
||||
proc f {args} { return 1 }
|
||||
db func f f
|
||||
|
||||
do_execsql_test 4.1.1 {
|
||||
CREATE TABLE t4(a, b);
|
||||
CREATE TABLE t5(c, d);
|
||||
|
||||
INSERT INTO t5 VALUES(1, 'x');
|
||||
INSERT INTO t5 VALUES(2, 'x');
|
||||
INSERT INTO t4 VALUES(3, 'x');
|
||||
INSERT INTO t4 VALUES(4, 'x');
|
||||
|
||||
CREATE INDEX i1 ON t4(a);
|
||||
CREATE INDEX i2 ON t5(c);
|
||||
}
|
||||
|
||||
do_eqp_test 4.1.2 {
|
||||
SELECT c, d FROM t5
|
||||
UNION ALL
|
||||
SELECT a, b FROM t4 WHERE f()==f()
|
||||
ORDER BY 1,2
|
||||
} {
|
||||
1 0 0 {SCAN TABLE t5 USING INDEX i2}
|
||||
1 0 0 {USE TEMP B-TREE FOR RIGHT PART OF ORDER BY}
|
||||
2 0 0 {SCAN TABLE t4 USING INDEX i1}
|
||||
2 0 0 {USE TEMP B-TREE FOR RIGHT PART OF ORDER BY}
|
||||
0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION ALL)}
|
||||
}
|
||||
|
||||
do_execsql_test 4.1.3 {
|
||||
SELECT c, d FROM t5
|
||||
UNION ALL
|
||||
SELECT a, b FROM t4 WHERE f()==f()
|
||||
ORDER BY 1,2
|
||||
} {
|
||||
1 x 2 x 3 x 4 x
|
||||
}
|
||||
|
||||
do_execsql_test 4.2.1 {
|
||||
CREATE TABLE t6(a, b);
|
||||
CREATE TABLE t7(c, d);
|
||||
|
||||
INSERT INTO t7 VALUES(2, 9);
|
||||
INSERT INTO t6 VALUES(3, 0);
|
||||
INSERT INTO t6 VALUES(4, 1);
|
||||
INSERT INTO t7 VALUES(5, 6);
|
||||
INSERT INTO t6 VALUES(6, 0);
|
||||
INSERT INTO t7 VALUES(7, 6);
|
||||
|
||||
CREATE INDEX i6 ON t6(a);
|
||||
CREATE INDEX i7 ON t7(c);
|
||||
}
|
||||
|
||||
do_execsql_test 4.2.2 {
|
||||
SELECT c, f(d,c,d,c,d) FROM t7
|
||||
UNION ALL
|
||||
SELECT a, b FROM t6
|
||||
ORDER BY 1,2
|
||||
} {/2 . 3 . 4 . 5 . 6 . 7 ./}
|
||||
|
||||
|
||||
finish_test
|
||||
|
||||
57
test/show_speedtest1_rtree.tcl
Normal file
57
test/show_speedtest1_rtree.tcl
Normal file
@@ -0,0 +1,57 @@
|
||||
#!/usr/bin/tclsh
|
||||
#
|
||||
# This script displays the field of rectangles used by --testset rtree
|
||||
# of speedtest1. Run this script as follows:
|
||||
#
|
||||
# rm test.db
|
||||
# ./speedtest1 --testset rtree --size 25 test.db
|
||||
# sqlite3 --separator ' ' test.db 'SELECT * FROM rt1' >data.txt
|
||||
# wish show_speedtest1_rtree.tcl
|
||||
#
|
||||
# The filename "data.txt" is hard coded into this script and so that name
|
||||
# must be used on lines 3 and 4 above. Elsewhere, different filenames can
|
||||
# be used. The --size N parameter can be adjusted as desired.
|
||||
#
|
||||
package require Tk
|
||||
set f [open data.txt rb]
|
||||
set data [read $f]
|
||||
close $f
|
||||
canvas .c
|
||||
frame .b
|
||||
button .b.b1 -text X-Y -command refill-xy
|
||||
button .b.b2 -text X-Z -command refill-xz
|
||||
button .b.b3 -text Y-Z -command refill-yz
|
||||
pack .b.b1 .b.b2 .b.b3 -side left
|
||||
pack .c -side top -fill both -expand 1
|
||||
pack .b -side top
|
||||
proc resize_canvas_to_fit {} {
|
||||
foreach {x0 y0 x1 y1} [.c bbox all] break
|
||||
set w [expr {$x1-$x0}]
|
||||
set h [expr {$y1-$y0}]
|
||||
.c config -width $w -height $h
|
||||
}
|
||||
proc refill-xy {} {
|
||||
.c delete all
|
||||
foreach {id x0 x1 y0 y1 z0 z1} $::data {
|
||||
.c create rectangle $x0 $y0 $x1 $y1
|
||||
}
|
||||
.c scale all 0 0 0.05 0.05
|
||||
resize_canvas_to_fit
|
||||
}
|
||||
proc refill-xz {} {
|
||||
.c delete all
|
||||
foreach {id x0 x1 y0 y1 z0 z1} $::data {
|
||||
.c create rectangle $x0 $z0 $x1 $z1
|
||||
}
|
||||
.c scale all 0 0 0.05 0.05
|
||||
resize_canvas_to_fit
|
||||
}
|
||||
proc refill-yz {} {
|
||||
.c delete all
|
||||
foreach {id x0 x1 y0 y1 z0 z1} $::data {
|
||||
.c create rectangle $y0 $z0 $y1 $z1
|
||||
}
|
||||
.c scale all 0 0 0.05 0.05
|
||||
resize_canvas_to_fit
|
||||
}
|
||||
refill-xy
|
||||
@@ -74,6 +74,7 @@ do_execsql_test skipscan2-1.4 {
|
||||
-- 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';
|
||||
UPDATE sqlite_stat1 SET stat='10000 1' WHERE idx='sqlite_autoindex_people_1';
|
||||
ANALYZE sqlite_master;
|
||||
}
|
||||
db cache flush
|
||||
|
||||
@@ -30,6 +30,7 @@ static const char zHelp[] =
|
||||
" --threads N Use up to N threads for sorting\n"
|
||||
" --utf16be Set text encoding to UTF-16BE\n"
|
||||
" --utf16le Set text encoding to UTF-16LE\n"
|
||||
" --verify Run additional verification steps.\n"
|
||||
" --without-rowid Use WITHOUT ROWID where appropriate\n"
|
||||
;
|
||||
|
||||
@@ -52,6 +53,7 @@ static struct Global {
|
||||
int bReprepare; /* True to reprepare the SQL on each rerun */
|
||||
int bSqlOnly; /* True to print the SQL once only */
|
||||
int bExplain; /* Print SQL with EXPLAIN prefix */
|
||||
int bVerify; /* Try to verify that results are correct */
|
||||
int szTest; /* Scale factor for test iterations */
|
||||
const char *zWR; /* Might be WITHOUT ROWID */
|
||||
const char *zNN; /* Might be NOT NULL */
|
||||
@@ -932,6 +934,183 @@ void testset_cte(void){
|
||||
|
||||
}
|
||||
|
||||
/* Generate two numbers between 1 and mx. The first number is less than
|
||||
** the second. Usually the numbers are near each other but can sometimes
|
||||
** be far apart.
|
||||
*/
|
||||
static void twoCoords(
|
||||
int p1, int p2, /* Parameters adjusting sizes */
|
||||
unsigned mx, /* Range of 1..mx */
|
||||
unsigned *pX0, unsigned *pX1 /* OUT: write results here */
|
||||
){
|
||||
unsigned d, x0, x1, span;
|
||||
|
||||
span = mx/100 + 1;
|
||||
if( speedtest1_random()%3==0 ) span *= p1;
|
||||
if( speedtest1_random()%p2==0 ) span = mx/2;
|
||||
d = speedtest1_random()%span + 1;
|
||||
x0 = speedtest1_random()%(mx-d) + 1;
|
||||
x1 = x0 + d;
|
||||
*pX0 = x0;
|
||||
*pX1 = x1;
|
||||
}
|
||||
|
||||
/* The following routine is an R-Tree geometry callback. It returns
|
||||
** true if the object overlaps a slice on the Y coordinate between the
|
||||
** two values given as arguments. In other words
|
||||
**
|
||||
** SELECT count(*) FROM rt1 WHERE id MATCH xslice(10,20);
|
||||
**
|
||||
** Is the same as saying:
|
||||
**
|
||||
** SELECT count(*) FROM rt1 WHERE y1>=10 AND y0<=20;
|
||||
*/
|
||||
static int xsliceGeometryCallback(
|
||||
sqlite3_rtree_geometry *p,
|
||||
int nCoord,
|
||||
double *aCoord,
|
||||
int *pRes
|
||||
){
|
||||
*pRes = aCoord[3]>=p->aParam[0] && aCoord[2]<=p->aParam[1];
|
||||
return SQLITE_OK;
|
||||
}
|
||||
|
||||
/*
|
||||
** A testset for the R-Tree virtual table
|
||||
*/
|
||||
void testset_rtree(int p1, int p2){
|
||||
unsigned i, n;
|
||||
unsigned mxCoord;
|
||||
unsigned x0, x1, y0, y1, z0, z1;
|
||||
unsigned iStep;
|
||||
int *aCheck = sqlite3_malloc( sizeof(int)*g.szTest*100 );
|
||||
|
||||
mxCoord = 15000;
|
||||
n = g.szTest*100;
|
||||
speedtest1_begin_test(100, "%d INSERTs into an r-tree", n);
|
||||
speedtest1_exec("BEGIN");
|
||||
speedtest1_exec("CREATE VIRTUAL TABLE rt1 USING rtree(id,x0,x1,y0,y1,z0,z1)");
|
||||
speedtest1_prepare("INSERT INTO rt1(id,x0,x1,y0,y1,z0,z1)"
|
||||
"VALUES(?1,?2,?3,?4,?5,?6,?7)");
|
||||
for(i=1; i<=n; i++){
|
||||
twoCoords(p1, p2, mxCoord, &x0, &x1);
|
||||
twoCoords(p1, p2, mxCoord, &y0, &y1);
|
||||
twoCoords(p1, p2, mxCoord, &z0, &z1);
|
||||
sqlite3_bind_int(g.pStmt, 1, i);
|
||||
sqlite3_bind_int(g.pStmt, 2, x0);
|
||||
sqlite3_bind_int(g.pStmt, 3, x1);
|
||||
sqlite3_bind_int(g.pStmt, 4, y0);
|
||||
sqlite3_bind_int(g.pStmt, 5, y1);
|
||||
sqlite3_bind_int(g.pStmt, 6, z0);
|
||||
sqlite3_bind_int(g.pStmt, 7, z1);
|
||||
speedtest1_run();
|
||||
}
|
||||
speedtest1_exec("COMMIT");
|
||||
speedtest1_end_test();
|
||||
|
||||
speedtest1_begin_test(101, "Copy from rtree to a regular table");
|
||||
speedtest1_exec("CREATE TABLE t1(id INTEGER PRIMARY KEY,x0,x1,y0,y1,z0,z1)");
|
||||
speedtest1_exec("INSERT INTO t1 SELECT * FROM rt1");
|
||||
speedtest1_end_test();
|
||||
|
||||
n = g.szTest*20;
|
||||
speedtest1_begin_test(110, "%d one-dimensional intersect slice queries", n);
|
||||
speedtest1_prepare("SELECT count(*) FROM rt1 WHERE x0>=?1 AND x1<=?2");
|
||||
iStep = mxCoord/n;
|
||||
for(i=0; i<n; i++){
|
||||
sqlite3_bind_int(g.pStmt, 1, i*iStep);
|
||||
sqlite3_bind_int(g.pStmt, 2, (i+1)*iStep);
|
||||
speedtest1_run();
|
||||
aCheck[i] = atoi(g.zResult);
|
||||
}
|
||||
speedtest1_end_test();
|
||||
|
||||
if( g.bVerify ){
|
||||
n = g.szTest*20;
|
||||
speedtest1_begin_test(111, "Verify result from 1-D intersect slice queries");
|
||||
speedtest1_prepare("SELECT count(*) FROM t1 WHERE x0>=?1 AND x1<=?2");
|
||||
iStep = mxCoord/n;
|
||||
for(i=0; i<n; i++){
|
||||
sqlite3_bind_int(g.pStmt, 1, i*iStep);
|
||||
sqlite3_bind_int(g.pStmt, 2, (i+1)*iStep);
|
||||
speedtest1_run();
|
||||
if( aCheck[i]!=atoi(g.zResult) ){
|
||||
fatal_error("Count disagree step %d: %d..%d. %d vs %d",
|
||||
i, i*iStep, (i+1)*iStep, aCheck[i], atoi(g.zResult));
|
||||
}
|
||||
}
|
||||
speedtest1_end_test();
|
||||
}
|
||||
|
||||
n = g.szTest*20;
|
||||
speedtest1_begin_test(120, "%d one-dimensional overlap slice queries", n);
|
||||
speedtest1_prepare("SELECT count(*) FROM rt1 WHERE y1>=?1 AND y0<=?2");
|
||||
iStep = mxCoord/n;
|
||||
for(i=0; i<n; i++){
|
||||
sqlite3_bind_int(g.pStmt, 1, i*iStep);
|
||||
sqlite3_bind_int(g.pStmt, 2, (i+1)*iStep);
|
||||
speedtest1_run();
|
||||
aCheck[i] = atoi(g.zResult);
|
||||
}
|
||||
speedtest1_end_test();
|
||||
|
||||
if( g.bVerify ){
|
||||
n = g.szTest*20;
|
||||
speedtest1_begin_test(121, "Verify result from 1-D overlap slice queries");
|
||||
speedtest1_prepare("SELECT count(*) FROM t1 WHERE y1>=?1 AND y0<=?2");
|
||||
iStep = mxCoord/n;
|
||||
for(i=0; i<n; i++){
|
||||
sqlite3_bind_int(g.pStmt, 1, i*iStep);
|
||||
sqlite3_bind_int(g.pStmt, 2, (i+1)*iStep);
|
||||
speedtest1_run();
|
||||
if( aCheck[i]!=atoi(g.zResult) ){
|
||||
fatal_error("Count disagree step %d: %d..%d. %d vs %d",
|
||||
i, i*iStep, (i+1)*iStep, aCheck[i], atoi(g.zResult));
|
||||
}
|
||||
}
|
||||
speedtest1_end_test();
|
||||
}
|
||||
|
||||
|
||||
n = g.szTest*20;
|
||||
speedtest1_begin_test(125, "%d custom geometry callback queries", n);
|
||||
sqlite3_rtree_geometry_callback(g.db, "xslice", xsliceGeometryCallback, 0);
|
||||
speedtest1_prepare("SELECT count(*) FROM rt1 WHERE id MATCH xslice(?1,?2)");
|
||||
iStep = mxCoord/n;
|
||||
for(i=0; i<n; i++){
|
||||
sqlite3_bind_int(g.pStmt, 1, i*iStep);
|
||||
sqlite3_bind_int(g.pStmt, 2, (i+1)*iStep);
|
||||
speedtest1_run();
|
||||
if( aCheck[i]!=atoi(g.zResult) ){
|
||||
fatal_error("Count disagree step %d: %d..%d. %d vs %d",
|
||||
i, i*iStep, (i+1)*iStep, aCheck[i], atoi(g.zResult));
|
||||
}
|
||||
}
|
||||
speedtest1_end_test();
|
||||
|
||||
n = g.szTest*80;
|
||||
speedtest1_begin_test(130, "%d three-dimensional intersect box queries", n);
|
||||
speedtest1_prepare("SELECT count(*) FROM rt1 WHERE x1>=?1 AND x0<=?2"
|
||||
" AND y1>=?1 AND y0<=?2 AND z1>=?1 AND z0<=?2");
|
||||
iStep = mxCoord/n;
|
||||
for(i=0; i<n; i++){
|
||||
sqlite3_bind_int(g.pStmt, 1, i*iStep);
|
||||
sqlite3_bind_int(g.pStmt, 2, (i+1)*iStep);
|
||||
speedtest1_run();
|
||||
aCheck[i] = atoi(g.zResult);
|
||||
}
|
||||
speedtest1_end_test();
|
||||
|
||||
n = g.szTest*100;
|
||||
speedtest1_begin_test(140, "%d rowid queries", n);
|
||||
speedtest1_prepare("SELECT * FROM rt1 WHERE id=?1");
|
||||
for(i=1; i<=n; i++){
|
||||
sqlite3_bind_int(g.pStmt, 1, i);
|
||||
speedtest1_run();
|
||||
}
|
||||
speedtest1_end_test();
|
||||
}
|
||||
|
||||
/*
|
||||
** A testset used for debugging speedtest1 itself.
|
||||
*/
|
||||
@@ -1055,6 +1234,8 @@ int main(int argc, char **argv){
|
||||
zEncoding = "utf16le";
|
||||
}else if( strcmp(z,"utf16be")==0 ){
|
||||
zEncoding = "utf16be";
|
||||
}else if( strcmp(z,"verify")==0 ){
|
||||
g.bVerify = 1;
|
||||
}else if( strcmp(z,"without-rowid")==0 ){
|
||||
g.zWR = "WITHOUT ROWID";
|
||||
g.zPK = "PRIMARY KEY";
|
||||
@@ -1151,8 +1332,11 @@ int main(int argc, char **argv){
|
||||
testset_debug1();
|
||||
}else if( strcmp(zTSet,"cte")==0 ){
|
||||
testset_cte();
|
||||
}else if( strcmp(zTSet,"rtree")==0 ){
|
||||
testset_rtree(6, 147);
|
||||
}else{
|
||||
fatal_error("unknown testset: \"%s\"\n", zTSet);
|
||||
fatal_error("unknown testset: \"%s\"\nChoices: main debug1 cte rtree\n",
|
||||
zTSet);
|
||||
}
|
||||
speedtest1_final();
|
||||
|
||||
|
||||
53
test/tkt-f67b41381a.test
Normal file
53
test/tkt-f67b41381a.test
Normal file
@@ -0,0 +1,53 @@
|
||||
# 2014 April 26
|
||||
#
|
||||
# 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 that ticket f67b41381a has been resolved.
|
||||
#
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
set testprefix tkt-f67b41381a
|
||||
|
||||
do_execsql_test 1.0 {
|
||||
CREATE TABLE t1(a);
|
||||
INSERT INTO t1 VALUES(1);
|
||||
ALTER TABLE t1 ADD COLUMN b DEFAULT 2;
|
||||
CREATE TABLE t2(a, b);
|
||||
INSERT INTO t2 SELECT * FROM t1;
|
||||
SELECT * FROM t2;
|
||||
} {1 2}
|
||||
|
||||
db cache size 0
|
||||
foreach {tn tbls xfer} {
|
||||
1 { CREATE TABLE t1(a, b); CREATE TABLE t2(a, b) } 1
|
||||
2 { CREATE TABLE t1(a, b DEFAULT 'x'); CREATE TABLE t2(a, b) } 0
|
||||
3 { CREATE TABLE t1(a, b DEFAULT 'x'); CREATE TABLE t2(a, b DEFAULT 'x') } 1
|
||||
4 { CREATE TABLE t1(a, b DEFAULT NULL); CREATE TABLE t2(a, b) } 0
|
||||
5 { CREATE TABLE t1(a DEFAULT 2, b); CREATE TABLE t2(a DEFAULT 1, b) } 1
|
||||
6 { CREATE TABLE t1(a DEFAULT 1, b); CREATE TABLE t2(a DEFAULT 1, b) } 1
|
||||
7 { CREATE TABLE t1(a DEFAULT 1, b DEFAULT 1);
|
||||
CREATE TABLE t2(a DEFAULT 3, b DEFAULT 1) } 1
|
||||
8 { CREATE TABLE t1(a DEFAULT 1, b DEFAULT 1);
|
||||
CREATE TABLE t2(a DEFAULT 3, b DEFAULT 3) } 0
|
||||
|
||||
} {
|
||||
|
||||
execsql { DROP TABLE t1; DROP TABLE t2 }
|
||||
execsql $tbls
|
||||
|
||||
set res 1
|
||||
db eval { EXPLAIN INSERT INTO t1 SELECT * FROM t2 } {
|
||||
if {$opcode == "Column"} { set res 0 }
|
||||
}
|
||||
|
||||
do_test 2.$tn [list set res] $xfer
|
||||
}
|
||||
|
||||
finish_test
|
||||
@@ -42,7 +42,7 @@ foreach idxmode {ordered unordered} {
|
||||
1 "SELECT * FROM t1 ORDER BY a"
|
||||
{0 0 0 {SCAN TABLE t1 USING INDEX i1}}
|
||||
{0 0 0 {SCAN TABLE t1} 0 0 0 {USE TEMP B-TREE FOR ORDER BY}}
|
||||
2 "SELECT * FROM t1 WHERE a >?"
|
||||
2 "SELECT * FROM t1 WHERE a > 100"
|
||||
{0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a>?)}}
|
||||
{0 0 0 {SCAN TABLE t1}}
|
||||
3 "SELECT * FROM t1 WHERE a = ? ORDER BY rowid"
|
||||
|
||||
@@ -811,7 +811,13 @@ do_test wal2-7.1.1 {
|
||||
do_test wal2-7.1.2 {
|
||||
forcecopy test.db test2.db
|
||||
forcecopy test.db-wal test2.db-wal
|
||||
hexio_write test2.db-wal 48 FF
|
||||
# The first 32 bytes of the WAL file contain the WAL header. Offset 48
|
||||
# is the first byte of the checksum for the first frame in the WAL.
|
||||
# The following three lines replaces the contents of that byte with
|
||||
# a different value.
|
||||
set newval FF
|
||||
if {$newval == [hexio_read test2.db-wal 48 1]} { set newval 00 }
|
||||
hexio_write test2.db-wal 48 $newval
|
||||
} {1}
|
||||
do_test wal2-7.1.3 {
|
||||
sqlite3 db2 test2.db
|
||||
|
||||
@@ -231,6 +231,7 @@ do_execsql_test where3-3.0 {
|
||||
CREATE TABLE t301(a INTEGER PRIMARY KEY,b,c);
|
||||
CREATE INDEX t301c ON t301(c);
|
||||
INSERT INTO t301 VALUES(1,2,3);
|
||||
INSERT INTO t301 VALUES(2,2,3);
|
||||
CREATE TABLE t302(x, y);
|
||||
INSERT INTO t302 VALUES(4,5);
|
||||
ANALYZE;
|
||||
@@ -251,7 +252,7 @@ do_execsql_test where3-3.2 {
|
||||
} {}
|
||||
do_execsql_test where3-3.3 {
|
||||
SELECT * FROM t301 WHERE c=3 AND a IS NOT NULL;
|
||||
} {1 2 3}
|
||||
} {1 2 3 2 2 3}
|
||||
|
||||
if 0 { # Query planner no longer does this
|
||||
# Verify that when there are multiple tables in a join which must be
|
||||
|
||||
@@ -14,6 +14,7 @@
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
set testprefix whereG
|
||||
|
||||
do_execsql_test whereG-1.0 {
|
||||
CREATE TABLE composer(
|
||||
@@ -179,5 +180,46 @@ do_execsql_test whereG-4.0 {
|
||||
ORDER BY x;
|
||||
} {right}
|
||||
|
||||
#-------------------------------------------------------------------------
|
||||
# Test that likelihood() specifications on indexed terms are taken into
|
||||
# account by various forms of loops.
|
||||
#
|
||||
# 5.1.*: open ended range scans
|
||||
# 5.2.*: skip-scans
|
||||
#
|
||||
reset_db
|
||||
|
||||
do_execsql_test 5.1 {
|
||||
CREATE TABLE t1(a, b, c);
|
||||
CREATE INDEX i1 ON t1(a, b);
|
||||
}
|
||||
do_eqp_test 5.1.2 {
|
||||
SELECT * FROM t1 WHERE a>?
|
||||
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a>?)}}
|
||||
do_eqp_test 5.1.3 {
|
||||
SELECT * FROM t1 WHERE likelihood(a>?, 0.9)
|
||||
} {0 0 0 {SCAN TABLE t1}}
|
||||
|
||||
do_test 5.2 {
|
||||
for {set i 0} {$i < 100} {incr i} {
|
||||
execsql { INSERT INTO t1 VALUES('abc', $i, $i); }
|
||||
}
|
||||
execsql { INSERT INTO t1 SELECT 'def', b, c FROM t1; }
|
||||
execsql { ANALYZE }
|
||||
} {}
|
||||
do_eqp_test 5.2.2 {
|
||||
SELECT * FROM t1 WHERE likelihood(b>?, 0.01)
|
||||
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (ANY(a) AND b>?)}}
|
||||
do_eqp_test 5.2.3 {
|
||||
SELECT * FROM t1 WHERE likelihood(b>?, 0.9)
|
||||
} {0 0 0 {SCAN TABLE t1}}
|
||||
|
||||
do_eqp_test 5.3.1 {
|
||||
SELECT * FROM t1 WHERE a=?
|
||||
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}}
|
||||
do_eqp_test 5.3.2 {
|
||||
SELECT * FROM t1 WHERE likelihood(a=?, 0.9)
|
||||
} {0 0 0 {SCAN TABLE t1}}
|
||||
|
||||
finish_test
|
||||
|
||||
|
||||
Reference in New Issue
Block a user