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 script is testing the ATTACH and DETACH commands
13 # and related functionality.
15 # $Id: attach.test,v 1.52 2009/05/29 14:39:08 drh Exp $
18 set testdir [file dirname $argv0]
19 source $testdir/tester.tcl
26 for {set i 2} {$i<=15} {incr i} {
28 forcedelete test$i.db-journal
34 INSERT INTO t1 VALUES(1,2);
35 INSERT INTO t1 VALUES(3,4);
43 INSERT INTO t2 VALUES(1,'x');
44 INSERT INTO t2 VALUES(2,'y');
50 ATTACH DATABASE 'test2.db' AS two;
55 # Tests for the sqlite3_db_filename interface
57 do_test attach-1.3.1 {
58 file tail [sqlite3_db_filename db main]
60 do_test attach-1.3.2 {
61 file tail [sqlite3_db_filename db MAIN]
63 do_test attach-1.3.3 {
64 file tail [sqlite3_db_filename db temp]
66 do_test attach-1.3.4 {
67 file tail [sqlite3_db_filename db two]
69 do_test attach-1.3.5 {
70 file tail [sqlite3_db_filename db three]
88 } {1 {no such table: t2}}
93 } {1 {no such table: two.t2}}
96 ATTACH DATABASE 'test3.db' AS three;
101 SELECT * FROM three.sqlite_master;
104 do_test attach-1.10 {
106 DETACH DATABASE [three];
109 do_test attach-1.11 {
111 ATTACH 'test.db' AS db2;
112 ATTACH 'test.db' AS db3;
113 ATTACH 'test.db' AS db4;
114 ATTACH 'test.db' AS db5;
115 ATTACH 'test.db' AS db6;
116 ATTACH 'test.db' AS db7;
117 ATTACH 'test.db' AS db8;
118 ATTACH 'test.db' AS db9;
123 foreach {idx name file} [execsql {PRAGMA database_list} $db] {
124 lappend list $idx $name
128 ifcapable schema_pragmas {
129 do_test attach-1.11b {
131 } {0 main 2 db2 3 db3 4 db4 5 db5 6 db6 7 db7 8 db8 9 db9}
132 } ;# ifcapable schema_pragmas
133 do_test attach-1.12 {
135 ATTACH 'test.db' as db2;
137 } {1 {database db2 is already in use}}
138 do_test attach-1.12.2 {
141 do_test attach-1.13 {
143 ATTACH 'test.db' as db5;
145 } {1 {database db5 is already in use}}
146 do_test attach-1.14 {
148 ATTACH 'test.db' as db9;
150 } {1 {database db9 is already in use}}
151 do_catchsql_test attach-1.15 {
152 ATTACH 'test.db' as main;
153 } {1 {database main is already in use}}
155 do_test attach-1.16 {
157 ATTACH 'test.db' as temp;
159 } {1 {database temp is already in use}}
161 do_catchsql_test attach-1.17 {
162 ATTACH 'test.db' as MAIN;
163 } {1 {database MAIN is already in use}}
164 do_test attach-1.18 {
166 ATTACH 'test.db' as db10;
167 ATTACH 'test.db' as db11;
170 if {$SQLITE_MAX_ATTACHED==10} {
171 do_test attach-1.19 {
173 ATTACH 'test.db' as db12;
175 } {1 {too many attached databases - max 10}}
176 do_test attach-1.19.1 {
180 do_test attach-1.20.1 {
185 ifcapable schema_pragmas {
186 do_test attach-1.20.2 {
188 } {0 main 2 db2 3 db3 4 db4 5 db6 6 db7 7 db8 8 db9 9 db10 10 db11}
189 } ;# ifcapable schema_pragmas
190 integrity_check attach-1.20.3
192 execsql {select * from temp.sqlite_master}
194 do_test attach-1.21 {
196 ATTACH 'test.db' as db12;
199 if {$SQLITE_MAX_ATTACHED==10} {
200 do_test attach-1.22 {
202 ATTACH 'test.db' as db13;
204 } {1 {too many attached databases - max 10}}
205 do_test attach-1.22.1 {
209 do_test attach-1.23 {
213 } {1 {no such database: db14}}
214 do_test attach-1.24 {
219 do_test attach-1.25 {
223 } {1 {no such database: db12}}
224 do_test attach-1.26 {
228 } {1 {cannot detach database main}}
232 do_test attach-1.27 {
236 } {1 {cannot detach database Temp}}
238 do_test attach-1.27 {
242 } {1 {no such database: Temp}}
245 do_test attach-1.28 {
258 ifcapable schema_pragmas {
260 do_test attach-1.29 {
264 do_test attach-1.29 {
268 } ;# ifcapable schema_pragmas
270 ifcapable {trigger} { # Only do the following tests if triggers are enabled
273 CREATE TABLE tx(x1,x2,y1,y2);
274 CREATE TRIGGER r1 AFTER UPDATE ON t2 FOR EACH ROW BEGIN
275 INSERT INTO tx(x1,x2,y1,y2) VALUES(OLD.x,NEW.x,OLD.y,NEW.y);
282 UPDATE t2 SET x=x+10;
285 } {1 11 x x 2 12 y y}
288 CREATE TABLE tx(x1,x2,y1,y2);
294 ATTACH 'test2.db' AS db2;
299 UPDATE db2.t2 SET x=x+10;
300 SELECT * FROM db2.tx;
302 } {1 11 x x 2 12 y y 11 21 x x 12 22 y y}
305 SELECT * FROM main.tx;
310 SELECT type, name, tbl_name FROM db2.sqlite_master;
312 } {table t2 t2 table tx tx trigger r1 t2}
314 ifcapable schema_pragmas&&tempdb {
317 } {0 main 1 temp 2 db2}
318 } ;# ifcapable schema_pragmas&&tempdb
319 ifcapable schema_pragmas&&!tempdb {
323 } ;# ifcapable schema_pragmas&&!tempdb
327 CREATE INDEX i2 ON t2(x);
328 SELECT * FROM t2 WHERE x>5;
331 do_test attach-2.10 {
333 SELECT type, name, tbl_name FROM sqlite_master;
335 } {table t2 t2 table tx tx trigger r1 t2 index i2 t2}
336 #do_test attach-2.11 {
338 # SELECT * FROM t2 WHERE x>5;
340 #} {1 {database schema has changed}}
341 ifcapable schema_pragmas {
343 do_test attach-2.12 {
345 } {0 main 1 temp 2 db2}
347 do_test attach-2.12 {
351 } ;# ifcapable schema_pragmas
352 do_test attach-2.13 {
354 SELECT * FROM t2 WHERE x>5;
357 do_test attach-2.14 {
359 SELECT type, name, tbl_name FROM sqlite_master;
361 } {table t1 t1 table tx tx}
362 do_test attach-2.15 {
364 SELECT type, name, tbl_name FROM db2.sqlite_master;
366 } {table t2 t2 table tx tx trigger r1 t2 index i2 t2}
367 do_test attach-2.16 {
371 ATTACH 'test2.db' AS db2;
372 SELECT type, name, tbl_name FROM db2.sqlite_master;
374 } {table t2 t2 table tx tx trigger r1 t2 index i2 t2}
375 } ;# End of ifcapable {trigger}
387 # If we are testing a version of the code that lacks trigger support,
388 # adjust the database contents so that they are the same if triggers
390 ifcapable {!trigger} {
393 INSERT INTO t2 VALUES(21, 'x');
394 INSERT INTO t2 VALUES(22, 'y');
395 CREATE TABLE tx(x1,x2,y1,y2);
396 INSERT INTO tx VALUES(1, 11, 'x', 'x');
397 INSERT INTO tx VALUES(2, 12, 'y', 'y');
398 INSERT INTO tx VALUES(11, 21, 'x', 'x');
399 INSERT INTO tx VALUES(12, 22, 'y', 'y');
400 CREATE INDEX i2 ON t2(x);
408 } {1 {no such table: t2}}
411 ATTACH DATABASE 'test2.db' AS db2;
416 # Even though 'db' has started a transaction, it should not yet have
417 # a lock on test2.db so 'db2' should be readable.
425 # Reading from test2.db from db within a transaction should not
426 # prevent test2.db from being read by db2.
428 execsql {SELECT * FROM t2}
434 # Making a change to test2.db through db causes test2.db to get
435 # a reserved lock. It should still be accessible through db2.
438 UPDATE t2 SET x=x+1 WHERE x=50;
447 execsql {SELECT * FROM t2} db2
450 # Start transactions on both db and db2. Once again, just because
451 # we make a change to test2.db using db2, only a RESERVED lock is
452 # obtained, so test2.db should still be readable using db.
457 execsql {UPDATE t2 SET x=0 WHERE 0} db2
458 catchsql {SELECT * FROM t2}
461 # It is also still accessible from db2.
463 catchsql {SELECT * FROM t2} db2
466 do_test attach-3.10 {
467 execsql {SELECT * FROM t1}
470 do_test attach-3.11 {
471 catchsql {UPDATE t1 SET a=a+1}
473 do_test attach-3.12 {
474 execsql {SELECT * FROM t1}
477 # db2 has a RESERVED lock on test2.db, so db cannot write to any tables
479 do_test attach-3.13 {
480 catchsql {UPDATE t2 SET x=x+1 WHERE x=50}
481 } {1 {database is locked}}
483 # Change for version 3. Transaction is no longer rolled back
484 # for a locked database.
487 # db is able to reread its schema because db2 still only holds a
489 do_test attach-3.14 {
490 catchsql {SELECT * FROM t1}
492 do_test attach-3.15 {
494 execsql {SELECT * FROM t1}
503 CREATE TABLE t3(x,y);
504 CREATE UNIQUE INDEX t3i1 ON t3(x);
505 INSERT INTO t3 VALUES(1,2);
511 CREATE TABLE t3(a,b);
512 CREATE UNIQUE INDEX t3i1b ON t3(a);
513 INSERT INTO t3 VALUES(9,10);
519 ATTACH DATABASE 'test2.db' AS db2;
520 SELECT * FROM db2.t3;
525 SELECT * FROM main.t3;
530 INSERT INTO db2.t3 VALUES(9,10);
531 SELECT * FROM db2.t3;
537 ifcapable {trigger} {
541 CREATE TRIGGER t3r3 AFTER INSERT ON t3 BEGIN
542 INSERT INTO t4 VALUES('db2.' || NEW.x);
544 INSERT INTO t3 VALUES(6,7);
551 CREATE TRIGGER t3r3 AFTER INSERT ON t3 BEGIN
552 INSERT INTO t4 VALUES('main.' || NEW.a);
554 INSERT INTO main.t3 VALUES(11,12);
555 SELECT * FROM main.t4;
559 ifcapable {!trigger} {
560 # When we do not have trigger support, set up the table like they
561 # would have been had triggers been there. The tests that follow need
565 INSERT INTO t3 VALUES(6,7);
566 INSERT INTO t4 VALUES('db2.6');
567 INSERT INTO t4 VALUES('db2.13');
571 INSERT INTO main.t3 VALUES(11,12);
572 INSERT INTO t4 VALUES('main.11');
577 # This one is tricky. On the UNION ALL select, we have to make sure
578 # the schema for both main and db2 is valid before starting to execute
579 # the first query of the UNION ALL. If we wait to test the validity of
580 # the schema for main until after the first query has run, that test will
581 # fail and the query will abort but we will have already output some
582 # results. When the query is retried, the results will be repeated.
587 ATTACH DATABASE 'test2.db' AS db2;
588 INSERT INTO db2.t3 VALUES(13,14);
589 SELECT * FROM db2.t4 UNION ALL SELECT * FROM main.t4;
591 } {db2.6 db2.13 main.11}
594 ifcapable {!trigger} {execsql {INSERT INTO main.t4 VALUES('main.15')}}
596 INSERT INTO main.t3 VALUES(15,16);
597 SELECT * FROM db2.t4 UNION ALL SELECT * FROM main.t4;
599 } {db2.6 db2.13 main.11 main.15}
600 } ;# ifcapable compound
602 ifcapable !compound {
603 ifcapable {!trigger} {execsql {INSERT INTO main.t4 VALUES('main.15')}}
605 ATTACH DATABASE 'test2.db' AS db2;
606 INSERT INTO db2.t3 VALUES(13,14);
607 INSERT INTO main.t3 VALUES(15,16);
609 } ;# ifcapable !compound
612 do_test attach-4.10 {
617 CREATE VIEW v3 AS SELECT x*100+y FROM t3;
621 do_test attach-4.11 {
623 CREATE VIEW v3 AS SELECT a*100+b FROM t3;
627 do_test attach-4.12 {
629 ATTACH DATABASE 'test2.db' AS db2;
630 SELECT * FROM db2.v3;
633 do_test attach-4.13 {
635 SELECT * FROM main.v3;
640 # Tests for the sqliteFix...() routines in attach.c
642 ifcapable {trigger} {
650 ATTACH DATABASE 'test.db' AS orig;
651 CREATE TRIGGER r1 AFTER INSERT ON orig.t1 BEGIN
655 } {1 {trigger r1 cannot reference objects in database orig}}
658 CREATE TABLE t5(x,y);
659 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
667 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
668 SELECT 'no-op' FROM orig.t1;
671 } {1 {trigger r5 cannot reference objects in database orig}}
675 CREATE TEMP TABLE t6(p,q,r);
676 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
677 SELECT 'no-op' FROM temp.t6;
680 } {1 {trigger r5 cannot reference objects in database temp}}
685 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
686 SELECT 'no-op' || (SELECT * FROM temp.t6);
689 } {1 {trigger r5 cannot reference objects in database temp}}
692 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
693 SELECT 'no-op' FROM t1 WHERE x<(SELECT min(x) FROM temp.t6);
696 } {1 {trigger r5 cannot reference objects in database temp}}
699 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
700 SELECT 'no-op' FROM t1 GROUP BY 1 HAVING x<(SELECT min(x) FROM temp.t6);
703 } {1 {trigger r5 cannot reference objects in database temp}}
706 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
707 SELECT max(1,x,(SELECT min(x) FROM temp.t6)) FROM t1;
710 } {1 {trigger r5 cannot reference objects in database temp}}
713 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
714 INSERT INTO t1 VALUES((SELECT min(x) FROM temp.t6),5);
717 } {1 {trigger r5 cannot reference objects in database temp}}
720 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
721 DELETE FROM t1 WHERE x<(SELECT min(x) FROM temp.t6);
724 } {1 {trigger r5 cannot reference objects in database temp}}
726 ifcapable json1&&vtab {
727 do_test attach-5.10 {
734 CREATE TABLE t2(a,b);
735 CREATE TRIGGER x1 AFTER INSERT ON t1 BEGIN
736 INSERT INTO t2(a,b) SELECT key, value FROM json_each(NEW.x);
738 INSERT INTO t1(x) VALUES('{"a":1}');
742 do_test attach-5.11 {
746 ATTACH 'test.db' AS aux;
747 INSERT INTO aux.t1(x) VALUES('{"b":2}');
748 SELECT * FROM aux.t2;
754 # Check to make sure we get a sensible error if unable to open
755 # the file that we are trying to attach.
759 ATTACH DATABASE 'no-such-file' AS nosuch;
762 if {$tcl_platform(platform)=="unix"} {
764 sqlite3 dbx cannot-read
765 dbx eval {CREATE TABLE t1(a,b,c)}
767 file attributes cannot-read -permission 0000
768 if {[file writable cannot-read]} {
769 puts "\n**** Tests do not work when run as root ****"
770 forcedelete cannot-read
774 ATTACH DATABASE 'cannot-read' AS noread;
776 } {1 {unable to open database: cannot-read}}
777 do_test attach-6.2.2 {
780 forcedelete cannot-read
783 # Check the error message if we try to access a database that has
787 CREATE TABLE no_such_db.t1(a, b, c);
789 } {1 {unknown database no_such_db}}
790 for {set i 2} {$i<=15} {incr i} {
795 forcedelete no-such-file
799 forcedelete test.db test.db-journal
802 DETACH RAISE ( IGNORE ) IN ( SELECT "AAAAAA" . * ORDER BY
803 REGISTER LIMIT "AAAAAA" . "AAAAAA" OFFSET RAISE ( IGNORE ) NOT NULL )
805 } {1 {no such table: AAAAAA}}
808 # Create a malformed file (a file that is not a valid database)
809 # and try to attach it
812 set fd [open test2.db w]
813 puts $fd "This file is not a valid SQLite database"
816 ATTACH 'test2.db' AS t2;
818 } {1 {file is not a database}}
825 db2 eval {CREATE TABLE t1(x); BEGIN EXCLUSIVE}
827 ATTACH 'test2.db' AS t2;
829 } {1 {database is locked}}
836 # Test that it is possible to attach the same database more than
837 # once when not in shared-cache mode. That this is not possible in
838 # shared-cache mode is tested in shared7.test.
842 ATTACH 'test4.db' AS aux1;
843 CREATE TABLE aux1.t1(a, b);
844 INSERT INTO aux1.t1 VALUES(1, 2);
845 ATTACH 'test4.db' AS aux2;
846 SELECT * FROM aux2.t1;
852 INSERT INTO aux1.t1 VALUES(3, 4);
853 INSERT INTO aux2.t1 VALUES(5, 6);
855 } {1 {database is locked}}
859 SELECT * FROM aux2.t1;
863 # Ticket [abe728bbc311d81334dae9762f0db87c07a98f79].
864 # Multi-database commit on an attached TEMP database.
866 do_test attach-10.1 {
869 ATTACH ':memory:' AS inmem;
871 CREATE TABLE noname.noname(x);
872 CREATE TABLE inmem.inmem(y);
873 CREATE TABLE main.main(z);
875 SELECT name FROM noname.sqlite_master;
876 SELECT name FROM inmem.sqlite_master;
879 do_test attach-10.2 {
881 PRAGMA database_list;
883 } {4 noname {} 5 inmem {}}
885 # Attach with a very long URI filename.
888 sqlite3 db test.db -uri 1
889 do_execsql_test attach-11.1 {
890 ATTACH printf('file:%09000x/x.db?mode=memory&cache=shared',1) AS aux1;
891 CREATE TABLE aux1.t1(x,y);
892 INSERT INTO aux1.t1(x,y) VALUES(1,2),(3,4);
893 SELECT * FROM aux1.t1;
896 # Ticket https://sqlite.org/src/tktview/a4e06e75a9ab61a1 2017-07-15
897 # False positive when running integrity_check on a connection with
898 # attached databases.
902 do_execsql_test attach-12.1 {
903 CREATE TABLE Table1 (col TEXT NOT NULL PRIMARY KEY);
904 ATTACH ':memory:' AS db2;
905 CREATE TABLE db2.Table2(col1 INTEGER, col2 INTEGER, col3 INTEGER, col4);
906 CREATE UNIQUE INDEX db2.idx_col1_unique ON Table2 (col1);
907 CREATE UNIQUE INDEX db2.idx_col23_unique ON Table2 (col2, col3);
908 CREATE INDEX db2.idx_col2 ON Table2 (col2);
909 INSERT INTO Table2 VALUES(1,2,3,4);
910 PRAGMA integrity_check;
913 # 2021-03-10 Forum post https://sqlite.org/forum/forumpost/a006d86f72
916 do_test attach-13.1 {
918 db eval {CREATE TABLE base(x);}
919 for {set i 0} {$i<$SQLITE_MAX_ATTACHED} {incr i} {
920 db eval "ATTACH ':memory:' AS a$i"
922 set m "a[expr {$SQLITE_MAX_ATTACHED-1}]"
923 db eval "CREATE TABLE $m.t1(a INTEGER PRIMARY KEY, b);"
924 db eval "CREATE TABLE $m.t2(a INTEGER PRIMARY KEY, b);"
925 db eval {SELECT a FROM t1 WHERE b IN (SELECT a FROM t2);}