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 #***********************************************************************
11 # This file implements regression tests for SQLite library. The
12 # focus of this file is creating and dropping virtual tables.
14 # $Id: vtab1.test,v 1.57 2008/08/01 17:51:47 danielk1977 Exp $
16 set testdir [file dirname $argv0]
17 source $testdir/tester.tcl
20 ifcapable !vtab||!schema_pragmas {
25 #----------------------------------------------------------------------
26 # Organization of tests in this file:
28 # vtab1-1.*: Error conditions and other issues surrounding creation/connection
29 # of a virtual module.
30 # vtab1-2.*: Test sqlite3_declare_vtab() and the xConnect/xDisconnect methods.
31 # vtab1-3.*: Table scans and WHERE clauses.
32 # vtab1-4.*: Table scans and ORDER BY clauses.
33 # vtab1-5.*: Test queries that include joins. This brings the
34 # sqlite3_index_info.estimatedCost variable into play.
35 # vtab1-6.*: Test UPDATE/INSERT/DELETE on vtables.
36 # vtab1-7.*: Test sqlite3_last_insert_rowid().
38 # This file uses the "echo" module (see src/test8.c). Refer to comments
39 # in that file for the special behaviour of the Tcl $echo_module variable.
42 # * How to test the sqlite3_index_constraint_usage.omit field?
45 # vtab1-14.*: Test 'IN' constraints - i.e. "SELECT * FROM t1 WHERE id IN(...)"
47 # vtab1-18.*: Check that the LIKE optimization is not applied when the lhs
48 # is a virtual table column.
52 #----------------------------------------------------------------------
53 # Test cases vtab1.1.*
56 # We cannot create a virtual table if the module has not been registered.
60 CREATE VIRTUAL TABLE t1 USING echo;
62 } {1 {no such module: echo}}
65 CREATE VIRTUAL TABLE IF NOT EXISTS t1 USING echo;
67 } {1 {no such module: echo}}
70 SELECT name FROM sqlite_master ORDER BY 1
75 register_echo_module [sqlite3_connection_pointer db]
77 # Once a module has been registered, virtual tables using that module
78 # may be created. However if a module xCreate() fails to call
79 # sqlite3_declare_vtab() an error will be raised and the table not created.
81 # The "echo" module does not invoke sqlite3_declare_vtab() if it is
82 # passed zero arguments.
86 CREATE VIRTUAL TABLE t1 USING echo;
88 } {1 {vtable constructor did not declare schema: t1}}
91 CREATE VIRTUAL TABLE IF NOT EXISTS t1 USING echo;
93 } {1 {vtable constructor did not declare schema: t1}}
96 SELECT name FROM sqlite_master ORDER BY 1
100 # The "echo" module xCreate method returns an error and does not create
101 # the virtual table if it is passed an argument that does not correspond
102 # to an existing real table in the same database.
104 do_test vtab1-1.5.1 {
106 CREATE VIRTUAL TABLE t1 USING echo(no_such_table);
108 } {1 {vtable constructor failed: t1}}
109 do_test vtab1-1.5.2 {
111 CREATE VIRTUAL TABLE IF NOT EXISTS t1 USING echo(no_such_table);
113 } {1 {vtable constructor failed: t1}}
116 SELECT name FROM sqlite_master ORDER BY 1
120 # Ticket #2156. Using the sqlite3_prepare_v2() API, make sure that
121 # a CREATE VIRTUAL TABLE statement can be used multiple times.
123 do_test vtab1-1.2152.1 {
124 set DB [sqlite3_connection_pointer db]
125 set sql {CREATE VIRTUAL TABLE t2152a USING echo(t2152b)}
126 set STMT [sqlite3_prepare_v2 $DB $sql -1 TAIL]
129 do_test vtab-1.2152.2 {
133 do_test vtab-1.2152.3 {
135 db eval {CREATE TABLE t2152b(x,y)}
138 do_test vtab-1.2152.4 {
139 sqlite3_finalize $STMT
140 db eval {DROP TABLE t2152a; DROP TABLE t2152b}
143 # Test to make sure nothing goes wrong and no memory is leaked if we
144 # select an illegal table-name (i.e a reserved name or the name of a
145 # table that already exists).
147 do_test vtab1-1.7.1 {
149 CREATE VIRTUAL TABLE sqlite_master USING echo;
151 } {1 {object name reserved for internal use: sqlite_master}}
152 do_test vtab1-1.7.2 {
154 CREATE VIRTUAL TABLE IF NOT EXISTS sqlite_master USING echo;
156 } {1 {object name reserved for internal use: sqlite_master}}
157 do_test vtab1-1.8.1 {
159 CREATE TABLE treal(a, b, c);
160 CREATE VIRTUAL TABLE treal USING echo(treal);
162 } {1 {table treal already exists}}
163 do_test vtab1-1.8.2 {
165 CREATE VIRTUAL TABLE IF NOT EXISTS treal USING echo(treal);
171 SELECT name FROM sqlite_master ORDER BY 1
177 CREATE TABLE treal(a, b, c);
178 CREATE VIRTUAL TABLE techo USING echo(treal);
185 } {1 {no such module: echo}}
188 INSERT INTO techo VALUES(1, 2, 3);
190 } {1 {no such module: echo}}
193 UPDATE techo SET a = 10;
195 } {1 {no such module: echo}}
200 } {1 {no such module: echo}}
203 PRAGMA table_info(techo)
205 } {1 {no such module: echo}}
210 } {1 {no such module: echo}}
212 register_echo_module [sqlite3_connection_pointer db]
213 register_echo_module [sqlite3_connection_pointer db]
215 # Test an error message returned from a v-table constructor.
220 CREATE TABLE logmsg(log);
223 CREATE VIRTUAL TABLE techo USING echo(treal, logmsg);
225 } {1 {table 'logmsg' already exists}}
231 SELECT sql FROM sqlite_master;
235 #----------------------------------------------------------------------
236 # Test cases vtab1.2.*
238 # At this point, the database is completely empty. The echo module
239 # has already been registered.
241 # If a single argument is passed to the echo module during table
242 # creation, it is assumed to be the name of a table in the same
243 # database. The echo module attempts to set the schema of the
244 # new virtual table to be the same as the existing database table.
248 CREATE TABLE template(a, b, c);
250 execsql { PRAGMA table_info(template); }
258 CREATE VIRTUAL TABLE t1 USING echo(template);
260 execsql { PRAGMA table_info(t1); }
267 # Test that the database can be unloaded. This should invoke the xDisconnect()
268 # callback for the successfully create virtual table (t1).
271 set echo_module [list]
276 # Re-open the database. This should not cause any virtual methods to
277 # be called. The invocation of xConnect() is delayed until the virtual
278 # table schema is first required by the compiler.
281 set echo_module [list]
287 # Try to query the virtual table schema. This should fail, as the
288 # echo module has not been registered with this database connection.
291 catchsql { PRAGMA table_info(t1); }
292 } {1 {no such module: echo}}
294 # Register the module
295 register_echo_module [sqlite3_connection_pointer db]
297 # Try to query the virtual table schema again. This time it should
298 # invoke the xConnect method and succeed.
301 execsql { PRAGMA table_info(t1); }
309 } {xConnect echo main t1 template}
311 # Drop table t1. This should cause the xDestroy (but not xDisconnect) method
323 PRAGMA table_info(t1);
328 SELECT sql FROM sqlite_master;
330 } [list {CREATE TABLE template(a, b, c)}]
331 # Clean up other test artifacts:
335 SELECT sql FROM sqlite_master;
339 #----------------------------------------------------------------------
340 # Test case vtab1-3 test table scans and the echo module's
341 # xBestIndex/xFilter handling of WHERE conditions.
346 CREATE TABLE treal(a INTEGER, b INTEGER, c);
347 CREATE INDEX treal_idx ON treal(b);
348 CREATE VIRTUAL TABLE t1 USING echo(treal);
351 } [list xCreate echo main t1 treal \
353 xCommit echo(treal) \
356 # Test that a SELECT on t1 doesn't crash. No rows are returned
357 # because the underlying real table is currently empty.
361 SELECT a, b, c FROM t1;
365 # Put some data into the table treal. Then try a few simple SELECT
370 INSERT INTO treal VALUES(1, 2, 3);
371 INSERT INTO treal VALUES(4, 5, 6);
382 SELECT rowid FROM t1;
393 SELECT rowid, * FROM t1;
396 do_test vtab1-3.8.1 {
398 SELECT a AS d, b AS e, c AS f FROM t1;
402 # Execute some SELECT statements with WHERE clauses on the t1 table.
403 # Then check the echo_module variable (written to by the module methods
404 # in test8.c) to make sure the xBestIndex() and xFilter() methods were
407 do_test vtab1-3.8.2 {
413 } [list xBestIndex {SELECT rowid, a, b, c FROM 'treal'} \
414 xFilter {SELECT rowid, a, b, c FROM 'treal'} ]
418 SELECT * FROM t1 WHERE b = 5;
423 } [list xBestIndex {SELECT rowid, a, b, c FROM 'treal' WHERE b = ?} \
424 xFilter {SELECT rowid, a, b, c FROM 'treal' WHERE b = ?} 5 ]
428 SELECT * FROM t1 WHERE b >= 5 AND b <= 10;
433 } [list xBestIndex {SELECT rowid, a, b, c FROM 'treal' WHERE b >= ? AND b <= ?}\
434 xFilter {SELECT rowid, a, b, c FROM 'treal' WHERE b >= ? AND b <= ?}\
439 SELECT * FROM t1 WHERE b BETWEEN 2 AND 10;
444 } [list xBestIndex {SELECT rowid, a, b, c FROM 'treal' WHERE b >= ? AND b <= ?}\
445 xFilter {SELECT rowid, a, b, c FROM 'treal' WHERE b >= ? AND b <= ?}\
448 # Add a function for the MATCH operator. Everything always matches!
449 #proc test_match {lhs rhs} {
450 # lappend ::echo_module MATCH $lhs $rhs
453 #db function match test_match
459 SELECT * FROM t1 WHERE a MATCH 'string';
461 } {1 {unable to use function MATCH in the requested context}}
464 } [list xBestIndex {SELECT rowid, a, b, c FROM 'treal'} \
465 xFilter {SELECT rowid, a, b, c FROM 'treal'}]
467 # The echo module uses a subquery internally to implement the MATCH operator.
471 SELECT * FROM t1 WHERE b MATCH 'string';
477 {SELECT rowid, a, b, c FROM 'treal' WHERE b LIKE (SELECT '%'||?||'%')} \
479 {SELECT rowid, a, b, c FROM 'treal' WHERE b LIKE (SELECT '%'||?||'%')} \
481 }; #ifcapable subquery
483 #----------------------------------------------------------------------
484 # Test case vtab1-3 test table scans and the echo module's
485 # xBestIndex/xFilter handling of ORDER BY clauses.
487 # This procedure executes the SQL. Then it checks to see if the OP_Sort
488 # opcode was executed. If an OP_Sort did occur, then "sort" is appended
489 # to the result. If no OP_Sort happened, then "nosort" is appended.
491 # This procedure is used to check to make sure sorting is or is not
492 # occurring as expected.
495 set ::sqlite_sort_count 0
496 set data [execsql $sql]
497 if {$::sqlite_sort_count} {set x sort} {set x nosort}
505 SELECT b FROM t1 ORDER BY b;
510 } [list xBestIndex {SELECT rowid, NULL, b, NULL FROM 'treal' ORDER BY b ASC} \
511 xFilter {SELECT rowid, NULL, b, NULL FROM 'treal' ORDER BY b ASC} ]
515 SELECT b FROM t1 ORDER BY b DESC;
520 } [list xBestIndex {SELECT rowid, NULL, b, NULL FROM 'treal' ORDER BY b DESC} \
521 xFilter {SELECT rowid, NULL, b, NULL FROM 'treal' ORDER BY b DESC} ]
525 SELECT b FROM t1 ORDER BY b||'';
530 } [list xBestIndex {SELECT rowid, NULL, b, NULL FROM 'treal'} \
531 xFilter {SELECT rowid, NULL, b, NULL FROM 'treal'} ]
538 #----------------------------------------------------------------------
539 # Test cases vtab1-5 test SELECT queries that include joins on virtual
544 for {set ii 0} {$ii < [llength $log]} {incr ii} {
545 if {[lindex $log $ii] eq "xFilter"} {
547 lappend out [lindex $log [expr $ii+1]]
555 CREATE TABLE t1(a, b, c);
556 CREATE TABLE t2(d, e, f);
557 INSERT INTO t1 VALUES(1, 'red', 'green');
558 INSERT INTO t1 VALUES(2, 'blue', 'black');
559 INSERT INTO t2 VALUES(1, 'spades', 'clubs');
560 INSERT INTO t2 VALUES(2, 'hearts', 'diamonds');
561 CREATE VIRTUAL TABLE et1 USING echo(t1);
562 CREATE VIRTUAL TABLE et2 USING echo(t2);
569 SELECT * FROM et1, et2;
572 1 red green 1 spades clubs \
573 1 red green 2 hearts diamonds \
574 2 blue black 1 spades clubs \
575 2 blue black 2 hearts diamonds \
580 xFilter {SELECT rowid, a, b, c FROM 't1'} \
581 xFilter {SELECT rowid, d, e, f FROM 't2'} \
582 xFilter {SELECT rowid, d, e, f FROM 't2'} \
587 SELECT * FROM et1, et2 WHERE et2.d = 2;
590 1 red green 2 hearts diamonds \
591 2 blue black 2 hearts diamonds \
596 xFilter {SELECT rowid, a, b, c FROM 't1'} \
597 xFilter {SELECT rowid, d, e, f FROM 't2'} \
598 xFilter {SELECT rowid, d, e, f FROM 't2'} \
602 CREATE INDEX i1 ON t2(d);
607 register_echo_module [sqlite3_connection_pointer db]
611 SELECT * FROM et1, et2 WHERE et2.d = 2;
614 1 red green 2 hearts diamonds \
615 2 blue black 2 hearts diamonds \
618 filter $::echo_module
620 xFilter {SELECT rowid, a, b, c FROM 't1'} \
621 xFilter {SELECT rowid, d, e, f FROM 't2' WHERE d = ?} \
622 xFilter {SELECT rowid, d, e, f FROM 't2' WHERE d = ?} \
632 #----------------------------------------------------------------------
633 # Test cases vtab1-6 test INSERT, UPDATE and DELETE operations
636 execsql { SELECT sql FROM sqlite_master }
640 CREATE TABLE treal(a PRIMARY KEY, b, c);
641 CREATE VIRTUAL TABLE techo USING echo(treal);
642 SELECT name FROM sqlite_master WHERE type = 'table';
645 do_test vtab1-6-3.1.1 {
647 PRAGMA count_changes=ON;
648 INSERT INTO techo VALUES(1, 2, 3);
651 do_test vtab1-6-3.1.2 {
654 do_test vtab1-6-3.2 {
659 do_test vtab1-6-4.1 {
661 UPDATE techo SET a = 5;
665 do_test vtab1-6-4.2 {
670 do_test vtab1-6-4.3 {
672 UPDATE techo SET a=6 WHERE a<0;
676 do_test vtab1-6-4.4 {
682 do_test vtab1-6-5.1 {
684 UPDATE techo set a = a||b||c;
688 do_test vtab1-6-5.2 {
694 do_test vtab1-6-6.1 {
696 UPDATE techo set rowid = 10;
700 do_test vtab1-6-6.2 {
702 SELECT rowid FROM techo;
706 do_test vtab1-6-7.1.1 {
708 INSERT INTO techo VALUES(11,12,13);
711 do_test vtab1-6-7.1.2 {
714 do_test vtab1-6-7.2 {
716 SELECT * FROM techo ORDER BY a;
719 do_test vtab1-6-7.3 {
721 UPDATE techo SET b=b+1000
725 do_test vtab1-6-7.4 {
727 SELECT * FROM techo ORDER BY a;
729 } {11 1012 13 523 1002 3}
732 do_test vtab1-6-8.1 {
734 DELETE FROM techo WHERE a=5;
738 do_test vtab1-6-8.2 {
740 SELECT * FROM techo ORDER BY a;
742 } {11 1012 13 523 1002 3}
743 do_test vtab1-6-8.3 {
749 do_test vtab1-6-8.4 {
751 SELECT * FROM techo ORDER BY a;
754 execsql {PRAGMA count_changes=OFF}
757 forcedelete test2.db-journal
760 CREATE TABLE techo(a PRIMARY KEY, b, c);
762 proc check_echo_table {tn} {
763 set ::data1 [execsql {SELECT rowid, * FROM techo}]
764 set ::data2 [execsql {SELECT rowid, * FROM techo} db2]
766 string equal $::data1 $::data2
771 {INSERT INTO techo VALUES('abc', 'def', 'ghi')} \
772 {INSERT INTO techo SELECT a||'.'||rowid, b, c FROM techo} \
773 {INSERT INTO techo SELECT a||'x'||rowid, b, c FROM techo} \
774 {INSERT INTO techo SELECT a||'y'||rowid, b, c FROM techo} \
775 {DELETE FROM techo WHERE (oid % 3) = 0} \
776 {UPDATE techo set rowid = 100 WHERE rowid = 1} \
777 {INSERT INTO techo(a, b) VALUES('hello', 'world')} \
778 {DELETE FROM techo} \
782 check_echo_table vtab1-6.8.[incr tn]
789 #----------------------------------------------------------------------
790 # Test cases vtab1-7 tests that the value returned by
791 # sqlite3_last_insert_rowid() is set correctly when rows are inserted
792 # into virtual tables.
795 CREATE TABLE real_abc(a PRIMARY KEY, b, c);
796 CREATE VIRTUAL TABLE echo_abc USING echo(real_abc);
801 INSERT INTO echo_abc VALUES(1, 2, 3);
802 SELECT last_insert_rowid();
807 INSERT INTO echo_abc(rowid) VALUES(31427);
808 SELECT last_insert_rowid();
813 INSERT INTO echo_abc SELECT a||'.v2', b, c FROM echo_abc;
814 SELECT last_insert_rowid();
819 SELECT rowid, a, b, c FROM echo_abc
827 # Now test that DELETE and UPDATE operations do not modify the value.
830 UPDATE echo_abc SET c = 5 WHERE b = 2;
831 SELECT last_insert_rowid();
836 UPDATE echo_abc SET rowid = 5 WHERE rowid = 1;
837 SELECT last_insert_rowid();
842 DELETE FROM echo_abc WHERE b = 2;
843 SELECT last_insert_rowid();
848 SELECT rowid, a, b, c FROM echo_abc
850 } [list 31427 {} {} {} \
855 DELETE FROM echo_abc WHERE b = 2;
856 SELECT last_insert_rowid();
861 SELECT rowid, a, b, c FROM real_abc
863 } [list 31427 {} {} {} \
868 DELETE FROM echo_abc;
869 SELECT last_insert_rowid();
874 SELECT rowid, a, b, c FROM real_abc
882 ATTACH 'test2.db' AS aux;
883 CREATE VIRTUAL TABLE aux.e2 USING echo(real_abc);
886 } [list xCreate echo aux e2 real_abc \
887 xSync echo(real_abc) \
888 xCommit echo(real_abc) \
906 CREATE TABLE r(a, b, c);
907 CREATE VIRTUAL TABLE e USING echo(r, e_log);
908 SELECT name FROM sqlite_master;
914 SELECT name FROM sqlite_master;
921 CREATE VIRTUAL TABLE e USING echo(r, e_log, virtual 1 2 3 varchar(32));
925 xCreate echo main e r e_log {virtual 1 2 3 varchar(32)} \
933 CREATE VIRTUAL TABLE e2 USING echo(del);
937 register_echo_module [sqlite3_connection_pointer db]
944 } {1 {vtable constructor failed: e2}}
947 set ptr [sqlite3_connection_pointer db]
948 sqlite3_declare_vtab $ptr {CREATE TABLE abc(a, b, c)}
951 } {1 {bad parameter or other API misuse}}
953 set ::echo_module_begin_fail r
955 INSERT INTO e VALUES(1, 2, 3);
957 } {1 {SQL logic error}}
960 EXPLAIN SELECT * FROM e WHERE rowid = 2;
961 EXPLAIN QUERY PLAN SELECT * FROM e WHERE rowid = 2 ORDER BY rowid;
968 SELECT * FROM e WHERE rowid||'' MATCH 'pattern';
972 xBestIndex {SELECT rowid, a, b, c FROM 'r'} \
973 xFilter {SELECT rowid, a, b, c FROM 'r'} \
975 proc match_func {args} {return ""}
978 db function match match_func
980 SELECT * FROM e WHERE match('pattern', rowid, 'pattern2');
984 xBestIndex {SELECT rowid, a, b, c FROM 'r'} \
985 xFilter {SELECT rowid, a, b, c FROM 'r'} \
989 # Testing the xFindFunction interface
991 catch {rename ::echo_glob_overload {}}
994 INSERT INTO r(a,b,c) VALUES(1,'?',99);
995 INSERT INTO r(a,b,c) VALUES(2,3,99);
996 SELECT a GLOB b FROM e
999 proc ::echo_glob_overload {a b} {
1002 do_test vtab1.11-2 {
1004 SELECT a like 'b' FROM e
1007 do_test vtab1.11-3 {
1009 SELECT a glob '2' FROM e
1012 do_test vtab1.11-4 {
1014 SELECT glob('2',a) FROM e
1017 do_test vtab1.11-5 {
1019 SELECT glob(a,'2') FROM e
1023 #----------------------------------------------------------------------
1024 # Test the outcome if a constraint is encountered half-way through
1025 # a multi-row INSERT that is inside a transaction
1027 do_test vtab1.12-1 {
1029 CREATE TABLE b(a, b, c);
1030 CREATE TABLE c(a UNIQUE, b, c);
1031 INSERT INTO b VALUES(1, 'A', 'B');
1032 INSERT INTO b VALUES(2, 'C', 'D');
1033 INSERT INTO b VALUES(3, 'E', 'F');
1034 INSERT INTO c VALUES(3, 'G', 'H');
1035 CREATE VIRTUAL TABLE echo_c USING echo(c);
1039 # First test outside of a transaction.
1040 do_test vtab1.12-2 {
1041 catchsql { INSERT INTO echo_c SELECT * FROM b; }
1042 } {1 {echo-vtab-error: UNIQUE constraint failed: c.a}}
1043 do_test vtab1.12-2.1 {
1045 } {echo-vtab-error: UNIQUE constraint failed: c.a}
1046 do_test vtab1.12-3 {
1047 execsql { SELECT * FROM c }
1050 # Now the real test - wrapped in a transaction.
1051 do_test vtab1.12-4 {
1053 catchsql { INSERT INTO echo_c SELECT * FROM b; }
1054 } {1 {echo-vtab-error: UNIQUE constraint failed: c.a}}
1055 do_test vtab1.12-5 {
1056 execsql { SELECT * FROM c }
1058 do_test vtab1.12-6 {
1060 execsql { SELECT * FROM c }
1063 # At one point (ticket #2759), a WHERE clause of the form "<column> IS NULL"
1064 # on a virtual table was causing an assert() to fail in the compiler.
1066 # "IS NULL" clauses should not be passed through to the virtual table
1067 # implementation. They are handled by SQLite after the vtab returns its
1070 do_test vtab1.13-1 {
1072 SELECT * FROM echo_c WHERE a IS NULL
1075 do_test vtab1.13-2 {
1077 INSERT INTO c VALUES(NULL, 15, 16);
1078 SELECT * FROM echo_c WHERE a IS NULL
1081 do_test vtab1.13-3 {
1083 INSERT INTO c VALUES(15, NULL, 16);
1084 SELECT * FROM echo_c WHERE b IS NULL
1087 do_test vtab1.13-4 {
1088 unset -nocomplain null
1090 SELECT * FROM echo_c WHERE b IS $null
1093 do_test vtab1.13-5 {
1095 SELECT * FROM echo_c WHERE b IS NULL AND a = 15;
1098 do_test vtab1.13-6 {
1100 SELECT * FROM echo_c WHERE NULL IS b AND a IS 15;
1105 do_test vtab1-14.001 {
1106 execsql {SELECT rowid, * FROM echo_c WHERE +rowid IN (1,2,3)}
1107 } {1 3 G H 2 {} 15 16 3 15 {} 16}
1108 do_test vtab1-14.002 {
1109 execsql {SELECT rowid, * FROM echo_c WHERE rowid IN (1,2,3)}
1110 } {1 3 G H 2 {} 15 16 3 15 {} 16}
1111 do_test vtab1-14.003 {
1112 execsql {SELECT rowid, * FROM echo_c WHERE +rowid IN (0,1,5,2,'a',3,NULL)}
1113 } {1 3 G H 2 {} 15 16 3 15 {} 16}
1114 do_test vtab1-14.004 {
1115 execsql {SELECT rowid, * FROM echo_c WHERE rowid IN (0,1,5,'a',2,3,NULL)}
1116 } {1 3 G H 2 {} 15 16 3 15 {} 16}
1117 do_test vtab1-14.005 {
1118 execsql {SELECT rowid, * FROM echo_c WHERE rowid NOT IN (0,1,5,'a',2,3)}
1120 do_test vtab1-14.006 {
1121 execsql {SELECT rowid, * FROM echo_c WHERE rowid NOT IN (0,5,'a',2,3)}
1123 do_test vtab1-14.007 {
1124 execsql {SELECT rowid, * FROM echo_c WHERE +rowid NOT IN (0,5,'a',2,3,NULL)}
1126 do_test vtab1-14.008 {
1127 execsql {SELECT rowid, * FROM echo_c WHERE rowid NOT IN (0,5,'a',2,3,NULL)}
1129 do_test vtab1-14.011 {
1130 execsql {SELECT * FROM echo_c WHERE +a IN (1,3,8,'x',NULL,15,24)}
1132 do_test vtab1-14.012 {
1133 execsql {SELECT * FROM echo_c WHERE a IN (1,3,8,'x',NULL,15,24)}
1135 do_test vtab1-14.013 {
1136 execsql {SELECT * FROM echo_c WHERE a NOT IN (1,8,'x',15,24)}
1138 do_test vtab1-14.014 {
1139 execsql {SELECT * FROM echo_c WHERE a NOT IN (1,8,'x',NULL,15,24)}
1141 do_test vtab1-14.015 {
1142 execsql {SELECT * FROM echo_c WHERE +a NOT IN (1,8,'x',NULL,15,24)}
1147 #do_test vtab1-14.1 {
1148 # execsql { DELETE FROM c }
1149 # set echo_module ""
1150 # execsql { SELECT * FROM echo_c WHERE rowid IN (1, 2, 3) }
1152 #} {/.*xBestIndex {SELECT rowid, . FROM 'c' WHERE rowid = .} xFilter {SELECT rowid, . FROM 'c'} 1/}
1154 do_test vtab1-14.2 {
1156 execsql { SELECT * FROM echo_c WHERE rowid = 1 }
1158 } [list xBestIndex {SELECT rowid, a, b, c FROM 'c' WHERE rowid = ?} \
1159 xFilter {SELECT rowid, a, b, c FROM 'c' WHERE rowid = ?} 1]
1161 do_test vtab1-14.3 {
1163 execsql { SELECT * FROM echo_c WHERE a = 1 }
1165 } [list xBestIndex {SELECT rowid, a, b, c FROM 'c' WHERE a = ?} \
1166 xFilter {SELECT rowid, a, b, c FROM 'c' WHERE a = ?} 1]
1168 #do_test vtab1-14.4 {
1169 # set echo_module ""
1170 # execsql { SELECT * FROM echo_c WHERE a IN (1, 2) }
1172 #} {/xBestIndex {SELECT rowid, . FROM 'c' WHERE a = .} xFilter {SELECT rowid, . FROM 'c' WHERE a = .} 1/}
1174 do_test vtab1-15.1 {
1176 CREATE TABLE t1(a, b, c);
1177 CREATE VIRTUAL TABLE echo_t1 USING echo(t1);
1180 do_test vtab1-15.2 {
1182 INSERT INTO echo_t1(rowid) VALUES(45);
1183 SELECT rowid, * FROM echo_t1;
1186 do_test vtab1-15.3 {
1188 INSERT INTO echo_t1(rowid) VALUES(NULL);
1189 SELECT rowid, * FROM echo_t1;
1191 } {45 {} {} {} 46 {} {} {}}
1192 do_test vtab1-15.4 {
1194 INSERT INTO echo_t1(rowid) VALUES('new rowid');
1196 } {1 {datatype mismatch}}
1198 # The following tests - vtab1-16.* - are designed to test that setting
1199 # sqlite3_vtab.zErrMsg variable can be used by the vtab interface to
1200 # return an error message to the user.
1202 do_test vtab1-16.1 {
1204 CREATE TABLE t2(a PRIMARY KEY, b, c);
1205 INSERT INTO t2 VALUES(1, 2, 3);
1206 INSERT INTO t2 VALUES(4, 5, 6);
1207 CREATE VIRTUAL TABLE echo_t2 USING echo(t2);
1212 foreach method [list \
1220 do_test vtab1-16.$tn {
1221 set echo_module_fail($method,t2) "the $method method has failed"
1222 catchsql { SELECT rowid, * FROM echo_t2 WHERE a >= 1 }
1223 } "1 {echo-vtab-error: the $method method has failed}"
1224 unset echo_module_fail($method,t2)
1228 foreach method [list \
1233 do_test vtab1-16.$tn {
1234 set echo_module_fail($method,t2) "the $method method has failed"
1235 catchsql { INSERT INTO echo_t2 VALUES(7, 8, 9) }
1236 } "1 {echo-vtab-error: the $method method has failed}"
1237 unset echo_module_fail($method,t2)
1241 ifcapable altertable {
1242 do_test vtab1-16.$tn {
1243 set echo_module_fail(xRename,t2) "the xRename method has failed"
1244 catchsql { ALTER TABLE echo_t2 RENAME TO another_name }
1245 } "1 {echo-vtab-error: the xRename method has failed}"
1246 unset echo_module_fail(xRename,t2)
1250 # The following test case exposes an instance in sqlite3_declare_vtab()
1251 # an error message was set using a call similar to sqlite3_mprintf(zErr),
1252 # where zErr is an arbitrary string. This is no good if the string contains
1253 # characters that can be mistaken for printf() formatting directives.
1255 do_test vtab1-17.1 {
1257 PRAGMA writable_schema = 1;
1258 INSERT INTO sqlite_master VALUES(
1259 'table', 't3', 't3', 0, 'INSERT INTO "%s%s" VALUES(1)'
1262 catchsql { CREATE VIRTUAL TABLE t4 USING echo(t3); }
1263 } {1 {vtable constructor failed: t4}}
1265 # This test verifies that ticket 48f29963 is fixed.
1267 do_test vtab1-17.1 {
1269 CREATE TABLE t5(a, b);
1270 CREATE VIRTUAL TABLE e5 USING echo_v2(t5);
1272 INSERT INTO e5 VALUES(1, 2);
1280 do_test vtab1-17.2 {
1281 execsql { DELETE FROM sqlite_master WHERE sql LIKE 'insert%' }
1284 #-------------------------------------------------------------------------
1285 # The following tests - vtab1-18.* - test that the optimization of LIKE
1286 # constraints in where.c plays well with virtual tables.
1288 # 18.1.*: Case-insensitive LIKE.
1289 # 18.2.*: Case-sensitive LIKE.
1291 unset -nocomplain echo_module_begin_fail
1293 do_execsql_test 18.1.0 {
1294 CREATE TABLE t6(a, b TEXT);
1295 CREATE INDEX i6 ON t6(b, a);
1296 INSERT INTO t6 VALUES(1, 'Peter');
1297 INSERT INTO t6 VALUES(2, 'Andrew');
1298 INSERT INTO t6 VALUES(3, '8James');
1299 INSERT INTO t6 VALUES(4, '8John');
1300 INSERT INTO t6 VALUES(5, 'Phillip');
1301 INSERT INTO t6 VALUES(6, 'Bartholomew');
1302 CREATE VIRTUAL TABLE e6 USING echo(t6);
1305 foreach {tn sql res filter} {
1306 1.1 "SELECT a FROM e6 WHERE b>'8James'" {4 2 6 1 5}
1307 {xFilter {SELECT rowid, a, b FROM 't6' WHERE b > ?} 8James}
1309 1.2 "SELECT a FROM e6 WHERE b>='8' AND b<'9'" {3 4}
1310 {xFilter {SELECT rowid, a, b FROM 't6' WHERE b >= ? AND b < ?} 8 9}
1312 1.3 "SELECT a FROM e6 WHERE b LIKE '8J%'" {3 4}
1313 {xFilter {SELECT rowid, a, b FROM 't6' WHERE b like ?} 8J%}
1315 1.4 "SELECT a FROM e6 WHERE b LIKE '8j%'" {3 4}
1316 {xFilter {SELECT rowid, a, b FROM 't6' WHERE b like ?} 8j%}
1319 do_execsql_test 18.$tn.1 $sql $res
1320 do_test 18.$tn.2 { lrange $::echo_module 2 end } $filter
1323 do_execsql_test 18.2.0 { PRAGMA case_sensitive_like = ON }
1324 foreach {tn sql res filter} {
1325 2.1 "SELECT a FROM e6 WHERE b LIKE '8J%'" {3 4}
1326 {xFilter {SELECT rowid, a, b FROM 't6' WHERE b like ?} 8J%}
1328 2.2 "SELECT a FROM e6 WHERE b LIKE '8j%'" {}
1329 {xFilter {SELECT rowid, a, b FROM 't6' WHERE b like ?} 8j%}
1332 do_execsql_test 18.$tn.1 $sql $res
1333 do_test 18.$tn.2 { lrange $::echo_module 2 end } $filter
1335 do_execsql_test 18.2.x { PRAGMA case_sensitive_like = OFF }
1337 #-------------------------------------------------------------------------
1338 # Test that an existing module may not be overridden.
1342 register_echo_module [sqlite3_connection_pointer db2]
1345 register_echo_module [sqlite3_connection_pointer db2]
1351 #-------------------------------------------------------------------------
1352 # Test that the bug fixed by [b0c1ba655d69] really is fixed.
1354 do_execsql_test 20.1 {
1355 CREATE TABLE t7 (a, b);
1356 CREATE TABLE t8 (c, d);
1357 CREATE INDEX i2 ON t7(a);
1358 CREATE INDEX i3 ON t7(b);
1359 CREATE INDEX i4 ON t8(c);
1360 CREATE INDEX i5 ON t8(d);
1362 CREATE VIRTUAL TABLE t7v USING echo(t7);
1363 CREATE VIRTUAL TABLE t8v USING echo(t8);
1367 for {set i 0} {$i < 1000} {incr i} {
1368 db eval {INSERT INTO t7 VALUES($i, $i)}
1369 db eval {INSERT INTO t8 VALUES($i, $i)}
1373 do_execsql_test 20.3 {
1375 SELECT a, b FROM t7 WHERE a=11 OR b=12
1377 SELECT c, d FROM t8 WHERE c=5 OR d=6
1380 } {5 5 6 6 11 11 12 12}
1382 do_execsql_test 20.4 {
1384 SELECT a, b FROM t7v WHERE a=11 OR b=12
1386 SELECT c, d FROM t8v WHERE c=5 OR d=6
1389 } {5 5 6 6 11 11 12 12}
1391 #-------------------------------------------------------------------------
1393 do_execsql_test 21.1 {
1394 CREATE TABLE t9(a,b,c);
1395 CREATE VIRTUAL TABLE t9v USING echo(t9);
1397 INSERT INTO t9 VALUES(1,2,3);
1398 INSERT INTO t9 VALUES(3,2,1);
1399 INSERT INTO t9 VALUES(2,2,2);
1402 do_execsql_test 21.2 {
1403 SELECT * FROM t9v WHERE a<b;
1406 do_execsql_test 21.3 {
1407 SELECT * FROM t9v WHERE a=b;
1410 #-------------------------------------------------------------------------
1411 # At one point executing a CREATE VIRTUAL TABLE statement that specified
1412 # a database name but no virtual table arguments was causing an internal
1413 # buffer overread. Valgrind would report errors while running the following
1414 # tests. Specifically:
1416 # CREATE VIRTUAL TABLE t1 USING fts4; -- Ok - no db name.
1417 # CREATE VIRTUAL TABLE main.t1 USING fts4(x); -- Ok - has vtab arguments.
1418 # CREATE VIRTUAL TABLE main.t1 USING fts4; -- Had the problem.
1421 forcedelete test.db2
1422 set nm [string repeat abcdefghij 100]
1423 do_execsql_test 22.1 {
1424 ATTACH 'test.db2' AS $nm
1427 execsql "SELECT * FROM sqlite_master"
1428 do_execsql_test 22.2 "CREATE VIRTUAL TABLE ${nm}.t1 USING fts4"
1431 set sql "CREATE VIRTUAL TABLE ${nm}.t2 USING fts4"
1432 set stmt [sqlite3_prepare_v2 db $sql -1 dummy]
1437 sqlite3_finalize $stmt
1441 set sql "CREATE VIRTUAL TABLE ${nm}.t3 USING fts4"
1442 set n [string length $sql]
1443 set stmt [sqlite3_prepare db "${sql}xyz" $n dummy]
1448 sqlite3_finalize $stmt
1453 #-------------------------------------------------------------------------
1454 # The following tests verify that a DROP TABLE command on a virtual
1455 # table does not cause other operations to crash.
1457 # 23.1: Dropping a vtab while a SELECT is running on it.
1459 # 23.2: Dropping a vtab while a SELECT that will, but has not yet,
1460 # open a cursor on the vtab, is running. In this case the
1461 # DROP TABLE succeeds and the SELECT hits an error.
1463 # 23.3: Dropping a vtab from within a user-defined-function callback
1464 # in the middle of an "INSERT INTO vtab SELECT ..." statement.
1467 load_static_extension db wholenumber
1468 load_static_extension db eval
1469 register_echo_module db
1472 execsql { CREATE VIRTUAL TABLE t1 USING wholenumber }
1474 db eval { SELECT value FROM t1 WHERE value<10 } {
1476 set res [catchsql { DROP TABLE t1 }]
1480 } {1 {database table is locked}}
1484 CREATE TABLE t2(value);
1485 INSERT INTO t2 VALUES(1), (2), (3);
1488 set res2 [list [catch {
1490 SELECT value FROM t2 UNION ALL
1491 SELECT value FROM t1 WHERE value<10
1493 if {$value == 2} { set res1 [catchsql { DROP TABLE t1 }] }
1497 } {{0 {}} {1 {database table is locked}}}
1500 execsql { CREATE VIRTUAL TABLE t1e USING echo(t2) }
1501 execsql { INSERT INTO t1e SELECT 4 }
1502 catchsql { INSERT INTO t1e SELECT eval('DROP TABLE t1e') }
1503 } {1 {database table is locked}}
1504 do_execsql_test 23.3.2 { SELECT * FROM t1e } {1 2 3 4}
1506 #-------------------------------------------------------------------------
1507 # At one point SQL like this:
1509 # SAVEPOINT xyz; -- Opens SQL transaction
1510 # INSERT INTO vtab -- Write to virtual table
1514 # was not invoking the xRollbackTo() callback for the ROLLBACK TO
1515 # operation. Which meant that virtual tables like FTS3 would incorrectly
1516 # commit the results of the INSERT as part of the "RELEASE xyz" command.
1518 # The following tests check that this has been fixed.
1521 do_execsql_test 24.0 {
1522 CREATE VIRTUAL TABLE t4 USING fts3();
1524 INSERT INTO t4 VALUES('a b c');
1530 do_execsql_test 24.1 { SELECT * FROM t4 WHERE t4 MATCH 'b' } {}
1531 do_execsql_test 24.2 { INSERT INTO t4(t4) VALUES('integrity-check') } {}
1533 do_execsql_test 24.3 {
1535 CREATE VIRTUAL TABLE t5 USING fts3();