xref: /sqlite-3.40.0/test/attach.test (revision ef5ecb41)
1# 2003 April 4
2#
3# The author disclaims copyright to this source code.  In place of
4# a legal notice, here is a blessing:
5#
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.
9#
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.
14#
15# $Id: attach.test,v 1.23 2004/06/09 00:48:15 drh Exp $
16#
17
18set testdir [file dirname $argv0]
19source $testdir/tester.tcl
20
21for {set i 2} {$i<=15} {incr i} {
22  file delete -force test$i.db
23  file delete -force test$i.db-journal
24}
25
26set btree_trace 0
27do_test attach-1.1 {
28  execsql {
29    CREATE TABLE t1(a,b);
30    INSERT INTO t1 VALUES(1,2);
31    INSERT INTO t1 VALUES(3,4);
32    SELECT * FROM t1;
33  }
34} {1 2 3 4}
35do_test attach-1.2 {
36  sqlite db2 test2.db
37  execsql {
38    CREATE TABLE t2(x,y);
39    INSERT INTO t2 VALUES(1,'x');
40    INSERT INTO t2 VALUES(2,'y');
41    SELECT * FROM t2;
42  } db2
43} {1 x 2 y}
44do_test attach-1.3 {
45  execsql {
46    ATTACH DATABASE 'test2.db' AS two;
47    SELECT * FROM two.t2;
48  }
49} {1 x 2 y}
50do_test attach-1.4 {
51  execsql {
52    SELECT * FROM t2;
53  }
54} {1 x 2 y}
55do_test attach-1.5 {
56  execsql {
57    DETACH DATABASE two;
58    SELECT * FROM t1;
59  }
60} {1 2 3 4}
61do_test attach-1.6 {
62  catchsql {
63    SELECT * FROM t2;
64  }
65} {1 {no such table: t2}}
66do_test attach-1.7 {
67  catchsql {
68    SELECT * FROM two.t2;
69  }
70} {1 {no such table: two.t2}}
71do_test attach-1.8 {
72  catchsql {
73    ATTACH DATABASE 'test3.db' AS three;
74  }
75} {0 {}}
76do_test attach-1.9 {
77  catchsql {
78    SELECT * FROM three.sqlite_master;
79  }
80} {0 {}}
81do_test attach-1.10 {
82  catchsql {
83    DETACH DATABASE three;
84  }
85} {0 {}}
86do_test attach-1.11 {
87  execsql {
88    ATTACH 'test.db' AS db2;
89    ATTACH 'test.db' AS db3;
90    ATTACH 'test.db' AS db4;
91    ATTACH 'test.db' AS db5;
92    ATTACH 'test.db' AS db6;
93    ATTACH 'test.db' AS db7;
94    ATTACH 'test.db' AS db8;
95    ATTACH 'test.db' AS db9;
96  }
97} {}
98proc db_list {db} {
99  set list {}
100  foreach {idx name file} [execsql {PRAGMA database_list} $db] {
101    lappend list $idx $name
102  }
103  return $list
104}
105do_test attach-1.11b {
106  db_list db
107} {0 main 1 temp 2 db2 3 db3 4 db4 5 db5 6 db6 7 db7 8 db8 9 db9}
108do_test attach-1.12 {
109  catchsql {
110    ATTACH 'test.db' as db2;
111  }
112} {1 {database db2 is already in use}}
113do_test attach-1.13 {
114  catchsql {
115    ATTACH 'test.db' as db5;
116  }
117} {1 {database db5 is already in use}}
118do_test attach-1.14 {
119  catchsql {
120    ATTACH 'test.db' as db9;
121  }
122} {1 {database db9 is already in use}}
123do_test attach-1.15 {
124  catchsql {
125    ATTACH 'test.db' as main;
126  }
127} {1 {database main is already in use}}
128do_test attach-1.16 {
129  catchsql {
130    ATTACH 'test.db' as temp;
131  }
132} {1 {database temp is already in use}}
133do_test attach-1.17 {
134  catchsql {
135    ATTACH 'test.db' as MAIN;
136  }
137} {1 {database MAIN is already in use}}
138do_test attach-1.18 {
139  catchsql {
140    ATTACH 'test.db' as db10;
141    ATTACH 'test.db' as db11;
142  }
143} {0 {}}
144do_test attach-1.19 {
145  catchsql {
146    ATTACH 'test.db' as db12;
147  }
148} {1 {too many attached databases - max 10}}
149do_test attach-1.20.1 {
150  execsql {
151    DETACH db5;
152  }
153  db_list db
154} {0 main 1 temp 2 db2 3 db3 4 db4 5 db11 6 db6 7 db7 8 db8 9 db9 10 db10}
155integrity_check attach-1.20.2
156do_test attach-1.21 {
157  catchsql {
158    ATTACH 'test.db' as db12;
159  }
160} {0 {}}
161do_test attach-1.22 {
162  catchsql {
163    ATTACH 'test.db' as db13;
164  }
165} {1 {too many attached databases - max 10}}
166do_test attach-1.23 {
167  catchsql {
168    DETACH db14;
169  }
170} {1 {no such database: db14}}
171do_test attach-1.24 {
172  catchsql {
173    DETACH db12;
174  }
175} {0 {}}
176do_test attach-1.25 {
177  catchsql {
178    DETACH db12;
179  }
180} {1 {no such database: db12}}
181do_test attach-1.26 {
182  catchsql {
183    DETACH main;
184  }
185} {1 {cannot detach database main}}
186do_test attach-1.27 {
187  catchsql {
188    DETACH Temp;
189  }
190} {1 {cannot detach database Temp}}
191do_test attach-1.28 {
192  catchsql {
193    DETACH db11;
194    DETACH db10;
195    DETACH db9;
196    DETACH db8;
197    DETACH db7;
198    DETACH db6;
199    DETACH db4;
200    DETACH db3;
201    DETACH db2;
202  }
203} {0 {}}
204do_test attach-1.29 {
205  db_list db
206} {0 main 1 temp}
207
208do_test attach-2.1 {
209  execsql {
210    CREATE TABLE tx(x1,x2,y1,y2);
211    CREATE TRIGGER r1 AFTER UPDATE ON t2 FOR EACH ROW BEGIN
212      INSERT INTO tx(x1,x2,y1,y2) VALUES(OLD.x,NEW.x,OLD.y,NEW.y);
213    END;
214    SELECT * FROM tx;
215  } db2;
216} {}
217do_test attach-2.2 {
218  execsql {
219    UPDATE t2 SET x=x+10;
220    SELECT * FROM tx;
221  } db2;
222} {1 11 x x 2 12 y y}
223do_test attach-2.3 {
224  execsql {
225    CREATE TABLE tx(x1,x2,y1,y2);
226    SELECT * FROM tx;
227  }
228} {}
229do_test attach-2.4 {
230  execsql {
231    ATTACH 'test2.db' AS db2;
232  }
233} {}
234do_test attach-2.5 {
235  execsql {
236    UPDATE db2.t2 SET x=x+10;
237    SELECT * FROM db2.tx;
238  }
239} {1 11 x x 2 12 y y 11 21 x x 12 22 y y}
240do_test attach-2.6 {
241  execsql {
242    SELECT * FROM main.tx;
243  }
244} {}
245do_test attach-2.7 {
246  execsql {
247    SELECT type, name, tbl_name FROM db2.sqlite_master;
248  }
249} {table t2 t2 table tx tx trigger r1 t2}
250do_test attach-2.8 {
251  db_list db
252} {0 main 1 temp 2 db2}
253do_test attach-2.9 {
254  execsql {
255    CREATE INDEX i2 ON t2(x);
256    SELECT * FROM t2 WHERE x>5;
257  } db2
258} {21 x 22 y}
259do_test attach-2.10 {
260  execsql {
261    SELECT type, name, tbl_name FROM sqlite_master;
262  } db2
263} {table t2 t2 table tx tx trigger r1 t2 index i2 t2}
264#do_test attach-2.11 {
265#  catchsql {
266#    SELECT * FROM t2 WHERE x>5;
267#  }
268#} {1 {database schema has changed}}
269do_test attach-2.12 {
270  db_list db
271} {0 main 1 temp 2 db2}
272do_test attach-2.13 {
273  catchsql {
274    SELECT * FROM t2 WHERE x>5;
275  }
276} {0 {21 x 22 y}}
277do_test attach-2.14 {
278  execsql {
279    SELECT type, name, tbl_name FROM sqlite_master;
280  }
281} {table t1 t1 table tx tx}
282do_test attach-2.15 {
283  execsql {
284    SELECT type, name, tbl_name FROM db2.sqlite_master;
285  }
286} {table t2 t2 table tx tx trigger r1 t2 index i2 t2}
287do_test attach-2.16 {
288  db close
289  sqlite db test.db
290  execsql {
291    ATTACH 'test2.db' AS db2;
292    SELECT type, name, tbl_name FROM db2.sqlite_master;
293  }
294} {table t2 t2 table tx tx trigger r1 t2 index i2 t2}
295
296do_test attach-3.1 {
297  db close
298  db2 close
299  sqlite db test.db
300  sqlite db2 test2.db
301  execsql {
302    SELECT * FROM t1
303  }
304} {1 2 3 4}
305do_test attach-3.2 {
306  catchsql {
307    SELECT * FROM t2
308  }
309} {1 {no such table: t2}}
310do_test attach-3.3 {
311  catchsql {
312    ATTACH DATABASE 'test2.db' AS db2;
313    SELECT * FROM t2
314  }
315} {0 {21 x 22 y}}
316
317# Even though 'db' has started a transaction, it should not yet have
318# a lock on test2.db so 'db2' should be readable.
319do_test attach-3.4 {
320  execsql BEGIN
321  catchsql {
322    SELECT * FROM t2;
323  } db2;
324} {0 {21 x 22 y}}
325
326# Reading from test2.db from db within a transaction should not
327# prevent test2.db from being read by db2.
328do_test attach-3.5 {
329  execsql {SELECT * FROM t2}
330  catchsql {
331    SELECT * FROM t2;
332  } db2;
333} {0 {21 x 22 y}}
334
335# Making a change to test2.db through db  causes test2.db to get
336# a reserved lock.  It should still be accessible through db2.
337do_test attach-3.6 {
338  execsql {
339    UPDATE t2 SET x=x+1 WHERE x=50;
340  }
341  catchsql {
342    SELECT * FROM t2;
343  } db2;
344} {0 {21 x 22 y}}
345
346do_test attach-3.7 {
347  execsql ROLLBACK
348  execsql {SELECT * FROM t2} db2
349} {21 x 22 y}
350
351# Start transactions on both db and db2.  Once again, just because
352# we make a change to test2.db using db2, only a RESERVED lock is
353# obtained, so test2.db should still be readable using db.
354#
355do_test attach-3.8 {
356  execsql BEGIN
357  execsql BEGIN db2
358  execsql {UPDATE t2 SET x=0 WHERE 0} db2
359  catchsql {SELECT * FROM t2}
360} {0 {21 x 22 y}}
361
362# It is also still accessible from db2.
363do_test attach-3.9 {
364  catchsql {SELECT * FROM t2} db2
365} {0 {21 x 22 y}}
366
367do_test attach-3.10 {
368  execsql {SELECT * FROM t1}
369} {1 2 3 4}
370
371do_test attach-3.11 {
372  catchsql {UPDATE t1 SET a=a+1}
373} {0 {}}
374do_test attach-3.12 {
375  execsql {SELECT * FROM t1}
376} {2 2 4 4}
377
378# db2 has a RESERVED lock on test2.db, so db cannot write to any tables
379# in test2.db.
380do_test attach-3.13 {
381  catchsql {UPDATE t2 SET x=x+1 WHERE x=50}
382} {1 {database is locked}}
383
384# Change for version 3. Transaction is no longer rolled back
385# for a locked database.
386execsql {ROLLBACK}
387
388# db is able to reread its schema because db2 still only holds a
389# reserved lock.
390do_test attach-3.14 {
391  catchsql {SELECT * FROM t1}
392} {0 {1 2 3 4}}
393do_test attach-3.15 {
394  execsql COMMIT db2
395  execsql {SELECT * FROM t1}
396} {1 2 3 4}
397
398#set btree_trace 1
399
400# Ticket #323
401do_test attach-4.1 {
402  execsql {DETACH db2}
403  db2 close
404  sqlite db2 test2.db
405  execsql {
406    CREATE TABLE t3(x,y);
407    CREATE UNIQUE INDEX t3i1 ON t3(x);
408    INSERT INTO t3 VALUES(1,2);
409    SELECT * FROM t3;
410  } db2;
411} {1 2}
412do_test attach-4.2 {
413  execsql {
414    CREATE TABLE t3(a,b);
415    CREATE UNIQUE INDEX t3i1b ON t3(a);
416    INSERT INTO t3 VALUES(9,10);
417    SELECT * FROM t3;
418  }
419} {9 10}
420do_test attach-4.3 {
421  execsql {
422    ATTACH DATABASE 'test2.db' AS db2;
423    SELECT * FROM db2.t3;
424  }
425} {1 2}
426do_test attach-4.4 {
427  execsql {
428    SELECT * FROM main.t3;
429  }
430} {9 10}
431do_test attach-4.5 {
432  execsql {
433    INSERT INTO db2.t3 VALUES(9,10);
434    SELECT * FROM db2.t3;
435  }
436} {1 2 9 10}
437do_test attach-4.6 {
438  execsql {
439    DETACH db2;
440  }
441  execsql {
442    CREATE TABLE t4(x);
443    CREATE TRIGGER t3r3 AFTER INSERT ON t3 BEGIN
444      INSERT INTO t4 VALUES('db2.' || NEW.x);
445    END;
446    INSERT INTO t3 VALUES(6,7);
447    SELECT * FROM t4;
448  } db2
449} {db2.6}
450do_test attach-4.7 {
451  execsql {
452    CREATE TABLE t4(y);
453    CREATE TRIGGER t3r3 AFTER INSERT ON t3 BEGIN
454      INSERT INTO t4 VALUES('main.' || NEW.a);
455    END;
456    INSERT INTO main.t3 VALUES(11,12);
457    SELECT * FROM main.t4;
458  }
459} {main.11}
460
461# This one is tricky.  On the UNION ALL select, we have to make sure
462# the schema for both main and db2 is valid before starting to execute
463# the first query of the UNION ALL.  If we wait to test the validity of
464# the schema for main until after the first query has run, that test will
465# fail and the query will abort but we will have already output some
466# results.  When the query is retried, the results will be repeated.
467#
468do_test attach-4.8 {
469  execsql {
470    ATTACH DATABASE 'test2.db' AS db2;
471    INSERT INTO db2.t3 VALUES(13,14);
472    SELECT * FROM db2.t4 UNION ALL SELECT * FROM main.t4;
473  }
474} {db2.6 db2.13 main.11}
475
476do_test attach-4.9 {
477  execsql {
478    INSERT INTO main.t3 VALUES(15,16);
479    SELECT * FROM db2.t4 UNION ALL SELECT * FROM main.t4;
480  }
481} {db2.6 db2.13 main.11 main.15}
482do_test attach-4.10 {
483  execsql {
484    DETACH DATABASE db2;
485  }
486  execsql {
487    CREATE VIEW v3 AS SELECT x*100+y FROM t3;
488    SELECT * FROM v3;
489  } db2
490} {102 910 607 1314}
491do_test attach-4.11 {
492  execsql {
493    CREATE VIEW v3 AS SELECT a*100+b FROM t3;
494    SELECT * FROM v3;
495  }
496} {910 1112 1516}
497do_test attach-4.12 {
498  execsql {
499    ATTACH DATABASE 'test2.db' AS db2;
500    SELECT * FROM db2.v3;
501  }
502} {102 910 607 1314}
503do_test attach-4.13 {
504  execsql {
505    SELECT * FROM main.v3;
506  }
507} {910 1112 1516}
508
509# Tests for the sqliteFix...() routines in attach.c
510#
511do_test attach-5.1 {
512  db close
513  sqlite db test.db
514  db2 close
515  file delete -force test2.db
516  sqlite db2 test2.db
517  catchsql {
518    ATTACH DATABASE 'test.db' AS orig;
519    CREATE TRIGGER r1 AFTER INSERT ON orig.t1 BEGIN;
520      SELECT 'no-op';
521    END;
522  } db2
523} {1 {trigger r1 cannot reference objects in database orig}}
524do_test attach-5.2 {
525  catchsql {
526    CREATE TABLE t5(x,y);
527    CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
528      SELECT 'no-op';
529    END;
530  } db2
531} {0 {}}
532do_test attach-5.3 {
533  catchsql {
534    DROP TRIGGER r5;
535    CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
536      SELECT 'no-op' FROM orig.t1;
537    END;
538  } db2
539} {1 {trigger r5 cannot reference objects in database orig}}
540do_test attach-5.4 {
541  catchsql {
542    CREATE TEMP TABLE t6(p,q,r);
543    CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
544      SELECT 'no-op' FROM temp.t6;
545    END;
546  } db2
547} {1 {trigger r5 cannot reference objects in database temp}}
548do_test attach-5.5 {
549  catchsql {
550    CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
551      SELECT 'no-op' || (SELECT * FROM temp.t6);
552    END;
553  } db2
554} {1 {trigger r5 cannot reference objects in database temp}}
555do_test attach-5.6 {
556  catchsql {
557    CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
558      SELECT 'no-op' FROM t1 WHERE x<(SELECT min(x) FROM temp.t6);
559    END;
560  } db2
561} {1 {trigger r5 cannot reference objects in database temp}}
562do_test attach-5.7 {
563  catchsql {
564    CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
565      SELECT 'no-op' FROM t1 GROUP BY 1 HAVING x<(SELECT min(x) FROM temp.t6);
566    END;
567  } db2
568} {1 {trigger r5 cannot reference objects in database temp}}
569do_test attach-5.7 {
570  catchsql {
571    CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
572      SELECT max(1,x,(SELECT min(x) FROM temp.t6)) FROM t1;
573    END;
574  } db2
575} {1 {trigger r5 cannot reference objects in database temp}}
576do_test attach-5.8 {
577  catchsql {
578    CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
579      INSERT INTO t1 VALUES((SELECT min(x) FROM temp.t6),5);
580    END;
581  } db2
582} {1 {trigger r5 cannot reference objects in database temp}}
583do_test attach-5.9 {
584  catchsql {
585    CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN
586      DELETE FROM t1 WHERE x<(SELECT min(x) FROM temp.t6);
587    END;
588  } db2
589} {1 {trigger r5 cannot reference objects in database temp}}
590
591# Check to make sure we get a sensible error if unable to open
592# the file that we are trying to attach.
593#
594do_test attach-6.1 {
595  catchsql {
596    ATTACH DATABASE 'no-such-file' AS nosuch;
597  }
598} {0 {}}
599if {$tcl_platform(platform)=="unix"} {
600  do_test attach-6.2 {
601    sqlite dbx cannot-read
602    dbx eval {CREATE TABLE t1(a,b,c)}
603    dbx close
604    file attributes cannot-read -permission 0000
605    catchsql {
606      ATTACH DATABASE 'cannot-read' AS noread;
607    }
608  } {1 {unable to open database: cannot-read}}
609  file delete -force cannot-read
610}
611
612for {set i 2} {$i<=15} {incr i} {
613  catch {db$i close}
614}
615db close
616file delete -force test2.db
617file delete -force no-such-file
618
619
620finish_test
621