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.44 2007/05/09 20:31:30 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 sqlite3 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} 105ifcapable schema_pragmas { 106do_test attach-1.11b { 107 db_list db 108} {0 main 2 db2 3 db3 4 db4 5 db5 6 db6 7 db7 8 db8 9 db9} 109} ;# ifcapable schema_pragmas 110do_test attach-1.12 { 111 catchsql { 112 ATTACH 'test.db' as db2; 113 } 114} {1 {database db2 is already in use}} 115do_test attach-1.13 { 116 catchsql { 117 ATTACH 'test.db' as db5; 118 } 119} {1 {database db5 is already in use}} 120do_test attach-1.14 { 121 catchsql { 122 ATTACH 'test.db' as db9; 123 } 124} {1 {database db9 is already in use}} 125do_test attach-1.15 { 126 catchsql { 127 ATTACH 'test.db' as main; 128 } 129} {1 {database main is already in use}} 130ifcapable tempdb { 131 do_test attach-1.16 { 132 catchsql { 133 ATTACH 'test.db' as temp; 134 } 135 } {1 {database temp is already in use}} 136} 137do_test attach-1.17 { 138 catchsql { 139 ATTACH 'test.db' as MAIN; 140 } 141} {1 {database MAIN is already in use}} 142do_test attach-1.18 { 143 catchsql { 144 ATTACH 'test.db' as db10; 145 ATTACH 'test.db' as db11; 146 } 147} {0 {}} 148do_test attach-1.19 { 149 catchsql { 150 ATTACH 'test.db' as db12; 151 } 152} {1 {too many attached databases - max 10}} 153do_test attach-1.20.1 { 154 execsql { 155 DETACH db5; 156 } 157} {} 158ifcapable schema_pragmas { 159do_test attach-1.20.2 { 160 db_list db 161} {0 main 2 db2 3 db3 4 db4 5 db6 6 db7 7 db8 8 db9 9 db10 10 db11} 162} ;# ifcapable schema_pragmas 163integrity_check attach-1.20.3 164ifcapable tempdb { 165 execsql {select * from sqlite_temp_master} 166} 167do_test attach-1.21 { 168 catchsql { 169 ATTACH 'test.db' as db12; 170 } 171} {0 {}} 172do_test attach-1.22 { 173 catchsql { 174 ATTACH 'test.db' as db13; 175 } 176} {1 {too many attached databases - max 10}} 177do_test attach-1.23 { 178 catchsql { 179 DETACH "db14"; 180 } 181} {1 {no such database: db14}} 182do_test attach-1.24 { 183 catchsql { 184 DETACH db12; 185 } 186} {0 {}} 187do_test attach-1.25 { 188 catchsql { 189 DETACH db12; 190 } 191} {1 {no such database: db12}} 192do_test attach-1.26 { 193 catchsql { 194 DETACH main; 195 } 196} {1 {cannot detach database main}} 197 198ifcapable tempdb { 199 do_test attach-1.27 { 200 catchsql { 201 DETACH Temp; 202 } 203 } {1 {cannot detach database Temp}} 204} else { 205 do_test attach-1.27 { 206 catchsql { 207 DETACH Temp; 208 } 209 } {1 {no such database: Temp}} 210} 211 212do_test attach-1.28 { 213 catchsql { 214 DETACH db11; 215 DETACH db10; 216 DETACH db9; 217 DETACH db8; 218 DETACH db7; 219 DETACH db6; 220 DETACH db4; 221 DETACH db3; 222 DETACH db2; 223 } 224} {0 {}} 225ifcapable schema_pragmas { 226 ifcapable tempdb { 227 do_test attach-1.29 { 228 db_list db 229 } {0 main 1 temp} 230 } else { 231 do_test attach-1.29 { 232 db_list db 233 } {0 main} 234 } 235} ;# ifcapable schema_pragmas 236 237ifcapable {trigger} { # Only do the following tests if triggers are enabled 238do_test attach-2.1 { 239 execsql { 240 CREATE TABLE tx(x1,x2,y1,y2); 241 CREATE TRIGGER r1 AFTER UPDATE ON t2 FOR EACH ROW BEGIN 242 INSERT INTO tx(x1,x2,y1,y2) VALUES(OLD.x,NEW.x,OLD.y,NEW.y); 243 END; 244 SELECT * FROM tx; 245 } db2; 246} {} 247do_test attach-2.2 { 248 execsql { 249 UPDATE t2 SET x=x+10; 250 SELECT * FROM tx; 251 } db2; 252} {1 11 x x 2 12 y y} 253do_test attach-2.3 { 254 execsql { 255 CREATE TABLE tx(x1,x2,y1,y2); 256 SELECT * FROM tx; 257 } 258} {} 259do_test attach-2.4 { 260 execsql { 261 ATTACH 'test2.db' AS db2; 262 } 263} {} 264do_test attach-2.5 { 265 execsql { 266 UPDATE db2.t2 SET x=x+10; 267 SELECT * FROM db2.tx; 268 } 269} {1 11 x x 2 12 y y 11 21 x x 12 22 y y} 270do_test attach-2.6 { 271 execsql { 272 SELECT * FROM main.tx; 273 } 274} {} 275do_test attach-2.7 { 276 execsql { 277 SELECT type, name, tbl_name FROM db2.sqlite_master; 278 } 279} {table t2 t2 table tx tx trigger r1 t2} 280 281ifcapable schema_pragmas&&tempdb { 282 do_test attach-2.8 { 283 db_list db 284 } {0 main 1 temp 2 db2} 285} ;# ifcapable schema_pragmas&&tempdb 286ifcapable schema_pragmas&&!tempdb { 287 do_test attach-2.8 { 288 db_list db 289 } {0 main 2 db2} 290} ;# ifcapable schema_pragmas&&!tempdb 291 292do_test attach-2.9 { 293 execsql { 294 CREATE INDEX i2 ON t2(x); 295 SELECT * FROM t2 WHERE x>5; 296 } db2 297} {21 x 22 y} 298do_test attach-2.10 { 299 execsql { 300 SELECT type, name, tbl_name FROM sqlite_master; 301 } db2 302} {table t2 t2 table tx tx trigger r1 t2 index i2 t2} 303#do_test attach-2.11 { 304# catchsql { 305# SELECT * FROM t2 WHERE x>5; 306# } 307#} {1 {database schema has changed}} 308ifcapable schema_pragmas { 309 ifcapable tempdb { 310 do_test attach-2.12 { 311 db_list db 312 } {0 main 1 temp 2 db2} 313 } else { 314 do_test attach-2.12 { 315 db_list db 316 } {0 main 2 db2} 317 } 318} ;# ifcapable schema_pragmas 319do_test attach-2.13 { 320 catchsql { 321 SELECT * FROM t2 WHERE x>5; 322 } 323} {0 {21 x 22 y}} 324do_test attach-2.14 { 325 execsql { 326 SELECT type, name, tbl_name FROM sqlite_master; 327 } 328} {table t1 t1 table tx tx} 329do_test attach-2.15 { 330 execsql { 331 SELECT type, name, tbl_name FROM db2.sqlite_master; 332 } 333} {table t2 t2 table tx tx trigger r1 t2 index i2 t2} 334do_test attach-2.16 { 335 db close 336 sqlite3 db test.db 337 execsql { 338 ATTACH 'test2.db' AS db2; 339 SELECT type, name, tbl_name FROM db2.sqlite_master; 340 } 341} {table t2 t2 table tx tx trigger r1 t2 index i2 t2} 342} ;# End of ifcapable {trigger} 343 344do_test attach-3.1 { 345 db close 346 db2 close 347 sqlite3 db test.db 348 sqlite3 db2 test2.db 349 execsql { 350 SELECT * FROM t1 351 } 352} {1 2 3 4} 353 354# If we are testing a version of the code that lacks trigger support, 355# adjust the database contents so that they are the same if triggers 356# had been enabled. 357ifcapable {!trigger} { 358 db2 eval { 359 DELETE FROM t2; 360 INSERT INTO t2 VALUES(21, 'x'); 361 INSERT INTO t2 VALUES(22, 'y'); 362 CREATE TABLE tx(x1,x2,y1,y2); 363 INSERT INTO tx VALUES(1, 11, 'x', 'x'); 364 INSERT INTO tx VALUES(2, 12, 'y', 'y'); 365 INSERT INTO tx VALUES(11, 21, 'x', 'x'); 366 INSERT INTO tx VALUES(12, 22, 'y', 'y'); 367 CREATE INDEX i2 ON t2(x); 368 } 369} 370 371do_test attach-3.2 { 372 catchsql { 373 SELECT * FROM t2 374 } 375} {1 {no such table: t2}} 376do_test attach-3.3 { 377 catchsql { 378 ATTACH DATABASE 'test2.db' AS db2; 379 SELECT * FROM t2 380 } 381} {0 {21 x 22 y}} 382 383# Even though 'db' has started a transaction, it should not yet have 384# a lock on test2.db so 'db2' should be readable. 385do_test attach-3.4 { 386 execsql BEGIN 387 catchsql { 388 SELECT * FROM t2; 389 } db2; 390} {0 {21 x 22 y}} 391 392# Reading from test2.db from db within a transaction should not 393# prevent test2.db from being read by db2. 394do_test attach-3.5 { 395 execsql {SELECT * FROM t2} 396btree_breakpoint 397 catchsql { 398 SELECT * FROM t2; 399 } db2; 400} {0 {21 x 22 y}} 401 402# Making a change to test2.db through db causes test2.db to get 403# a reserved lock. It should still be accessible through db2. 404do_test attach-3.6 { 405 execsql { 406 UPDATE t2 SET x=x+1 WHERE x=50; 407 } 408 catchsql { 409 SELECT * FROM t2; 410 } db2; 411} {0 {21 x 22 y}} 412 413do_test attach-3.7 { 414 execsql ROLLBACK 415 execsql {SELECT * FROM t2} db2 416} {21 x 22 y} 417 418# Start transactions on both db and db2. Once again, just because 419# we make a change to test2.db using db2, only a RESERVED lock is 420# obtained, so test2.db should still be readable using db. 421# 422do_test attach-3.8 { 423 execsql BEGIN 424 execsql BEGIN db2 425 execsql {UPDATE t2 SET x=0 WHERE 0} db2 426 catchsql {SELECT * FROM t2} 427} {0 {21 x 22 y}} 428 429# It is also still accessible from db2. 430do_test attach-3.9 { 431 catchsql {SELECT * FROM t2} db2 432} {0 {21 x 22 y}} 433 434do_test attach-3.10 { 435 execsql {SELECT * FROM t1} 436} {1 2 3 4} 437 438do_test attach-3.11 { 439 catchsql {UPDATE t1 SET a=a+1} 440} {0 {}} 441do_test attach-3.12 { 442 execsql {SELECT * FROM t1} 443} {2 2 4 4} 444 445# db2 has a RESERVED lock on test2.db, so db cannot write to any tables 446# in test2.db. 447do_test attach-3.13 { 448 catchsql {UPDATE t2 SET x=x+1 WHERE x=50} 449} {1 {database is locked}} 450 451# Change for version 3. Transaction is no longer rolled back 452# for a locked database. 453execsql {ROLLBACK} 454 455# db is able to reread its schema because db2 still only holds a 456# reserved lock. 457do_test attach-3.14 { 458 catchsql {SELECT * FROM t1} 459} {0 {1 2 3 4}} 460do_test attach-3.15 { 461 execsql COMMIT db2 462 execsql {SELECT * FROM t1} 463} {1 2 3 4} 464 465#set btree_trace 1 466 467# Ticket #323 468do_test attach-4.1 { 469 execsql {DETACH db2} 470 db2 close 471 sqlite3 db2 test2.db 472 execsql { 473 CREATE TABLE t3(x,y); 474 CREATE UNIQUE INDEX t3i1 ON t3(x); 475 INSERT INTO t3 VALUES(1,2); 476 SELECT * FROM t3; 477 } db2; 478} {1 2} 479do_test attach-4.2 { 480 execsql { 481 CREATE TABLE t3(a,b); 482 CREATE UNIQUE INDEX t3i1b ON t3(a); 483 INSERT INTO t3 VALUES(9,10); 484 SELECT * FROM t3; 485 } 486} {9 10} 487do_test attach-4.3 { 488 execsql { 489 ATTACH DATABASE 'test2.db' AS db2; 490 SELECT * FROM db2.t3; 491 } 492} {1 2} 493do_test attach-4.4 { 494 execsql { 495 SELECT * FROM main.t3; 496 } 497} {9 10} 498do_test attach-4.5 { 499 execsql { 500 INSERT INTO db2.t3 VALUES(9,10); 501 SELECT * FROM db2.t3; 502 } 503} {1 2 9 10} 504execsql { 505 DETACH db2; 506} 507ifcapable {trigger} { 508 do_test attach-4.6 { 509 execsql { 510 CREATE TABLE t4(x); 511 CREATE TRIGGER t3r3 AFTER INSERT ON t3 BEGIN 512 INSERT INTO t4 VALUES('db2.' || NEW.x); 513 END; 514 INSERT INTO t3 VALUES(6,7); 515 SELECT * FROM t4; 516 } db2 517 } {db2.6} 518 do_test attach-4.7 { 519 execsql { 520 CREATE TABLE t4(y); 521 CREATE TRIGGER t3r3 AFTER INSERT ON t3 BEGIN 522 INSERT INTO t4 VALUES('main.' || NEW.a); 523 END; 524 INSERT INTO main.t3 VALUES(11,12); 525 SELECT * FROM main.t4; 526 } 527 } {main.11} 528} 529ifcapable {!trigger} { 530 # When we do not have trigger support, set up the table like they 531 # would have been had triggers been there. The tests that follow need 532 # this setup. 533 execsql { 534 CREATE TABLE t4(x); 535 INSERT INTO t3 VALUES(6,7); 536 INSERT INTO t4 VALUES('db2.6'); 537 INSERT INTO t4 VALUES('db2.13'); 538 } db2 539 execsql { 540 CREATE TABLE t4(y); 541 INSERT INTO main.t3 VALUES(11,12); 542 INSERT INTO t4 VALUES('main.11'); 543 } 544} 545 546 547# This one is tricky. On the UNION ALL select, we have to make sure 548# the schema for both main and db2 is valid before starting to execute 549# the first query of the UNION ALL. If we wait to test the validity of 550# the schema for main until after the first query has run, that test will 551# fail and the query will abort but we will have already output some 552# results. When the query is retried, the results will be repeated. 553# 554ifcapable compound { 555do_test attach-4.8 { 556 execsql { 557 ATTACH DATABASE 'test2.db' AS db2; 558 INSERT INTO db2.t3 VALUES(13,14); 559 SELECT * FROM db2.t4 UNION ALL SELECT * FROM main.t4; 560 } 561} {db2.6 db2.13 main.11} 562 563do_test attach-4.9 { 564 ifcapable {!trigger} {execsql {INSERT INTO main.t4 VALUES('main.15')}} 565 execsql { 566 INSERT INTO main.t3 VALUES(15,16); 567 SELECT * FROM db2.t4 UNION ALL SELECT * FROM main.t4; 568 } 569} {db2.6 db2.13 main.11 main.15} 570} ;# ifcapable compound 571 572ifcapable !compound { 573 ifcapable {!trigger} {execsql {INSERT INTO main.t4 VALUES('main.15')}} 574 execsql { 575 ATTACH DATABASE 'test2.db' AS db2; 576 INSERT INTO db2.t3 VALUES(13,14); 577 INSERT INTO main.t3 VALUES(15,16); 578 } 579} ;# ifcapable !compound 580 581ifcapable view { 582do_test attach-4.10 { 583 execsql { 584 DETACH DATABASE db2; 585 } 586 execsql { 587 CREATE VIEW v3 AS SELECT x*100+y FROM t3; 588 SELECT * FROM v3; 589 } db2 590} {102 910 607 1314} 591do_test attach-4.11 { 592 execsql { 593 CREATE VIEW v3 AS SELECT a*100+b FROM t3; 594 SELECT * FROM v3; 595 } 596} {910 1112 1516} 597do_test attach-4.12 { 598 execsql { 599 ATTACH DATABASE 'test2.db' AS db2; 600 SELECT * FROM db2.v3; 601 } 602} {102 910 607 1314} 603do_test attach-4.13 { 604 execsql { 605 SELECT * FROM main.v3; 606 } 607} {910 1112 1516} 608} ;# ifcapable view 609 610# Tests for the sqliteFix...() routines in attach.c 611# 612ifcapable {trigger} { 613do_test attach-5.1 { 614 db close 615 sqlite3 db test.db 616 db2 close 617 file delete -force test2.db 618 sqlite3 db2 test2.db 619 catchsql { 620 ATTACH DATABASE 'test.db' AS orig; 621 CREATE TRIGGER r1 AFTER INSERT ON orig.t1 BEGIN 622 SELECT 'no-op'; 623 END; 624 } db2 625} {1 {trigger r1 cannot reference objects in database orig}} 626do_test attach-5.2 { 627 catchsql { 628 CREATE TABLE t5(x,y); 629 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN 630 SELECT 'no-op'; 631 END; 632 } db2 633} {0 {}} 634do_test attach-5.3 { 635 catchsql { 636 DROP TRIGGER r5; 637 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN 638 SELECT 'no-op' FROM orig.t1; 639 END; 640 } db2 641} {1 {trigger r5 cannot reference objects in database orig}} 642ifcapable tempdb { 643 do_test attach-5.4 { 644 catchsql { 645 CREATE TEMP TABLE t6(p,q,r); 646 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN 647 SELECT 'no-op' FROM temp.t6; 648 END; 649 } db2 650 } {1 {trigger r5 cannot reference objects in database temp}} 651} 652ifcapable subquery { 653 do_test attach-5.5 { 654 catchsql { 655 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN 656 SELECT 'no-op' || (SELECT * FROM temp.t6); 657 END; 658 } db2 659 } {1 {trigger r5 cannot reference objects in database temp}} 660 do_test attach-5.6 { 661 catchsql { 662 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN 663 SELECT 'no-op' FROM t1 WHERE x<(SELECT min(x) FROM temp.t6); 664 END; 665 } db2 666 } {1 {trigger r5 cannot reference objects in database temp}} 667 do_test attach-5.7 { 668 catchsql { 669 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN 670 SELECT 'no-op' FROM t1 GROUP BY 1 HAVING x<(SELECT min(x) FROM temp.t6); 671 END; 672 } db2 673 } {1 {trigger r5 cannot reference objects in database temp}} 674 do_test attach-5.7 { 675 catchsql { 676 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN 677 SELECT max(1,x,(SELECT min(x) FROM temp.t6)) FROM t1; 678 END; 679 } db2 680 } {1 {trigger r5 cannot reference objects in database temp}} 681 do_test attach-5.8 { 682 catchsql { 683 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN 684 INSERT INTO t1 VALUES((SELECT min(x) FROM temp.t6),5); 685 END; 686 } db2 687 } {1 {trigger r5 cannot reference objects in database temp}} 688 do_test attach-5.9 { 689 catchsql { 690 CREATE TRIGGER r5 AFTER INSERT ON t5 BEGIN 691 DELETE FROM t1 WHERE x<(SELECT min(x) FROM temp.t6); 692 END; 693 } db2 694 } {1 {trigger r5 cannot reference objects in database temp}} 695} ;# endif subquery 696} ;# endif trigger 697 698# Check to make sure we get a sensible error if unable to open 699# the file that we are trying to attach. 700# 701do_test attach-6.1 { 702 catchsql { 703 ATTACH DATABASE 'no-such-file' AS nosuch; 704 } 705} {0 {}} 706if {$tcl_platform(platform)=="unix"} { 707 do_test attach-6.2 { 708 sqlite3 dbx cannot-read 709 dbx eval {CREATE TABLE t1(a,b,c)} 710 dbx close 711 file attributes cannot-read -permission 0000 712 if {[file writable cannot-read]} { 713 puts "\n**** Tests do not work when run as root ****" 714 file delete -force cannot-read 715 exit 1 716 } 717 catchsql { 718 ATTACH DATABASE 'cannot-read' AS noread; 719 } 720 } {1 {unable to open database: cannot-read}} 721 file delete -force cannot-read 722} 723 724# Check the error message if we try to access a database that has 725# not been attached. 726do_test attach-6.3 { 727 catchsql { 728 CREATE TABLE no_such_db.t1(a, b, c); 729 } 730} {1 {unknown database no_such_db}} 731for {set i 2} {$i<=15} {incr i} { 732 catch {db$i close} 733} 734db close 735file delete -force test2.db 736file delete -force no-such-file 737 738do_test attach-7.1 { 739 file delete -force test.db test.db-journal 740 sqlite3 db test.db 741 catchsql { 742 DETACH RAISE ( IGNORE ) IN ( SELECT "AAAAAA" . * ORDER BY 743 REGISTER LIMIT "AAAAAA" . "AAAAAA" OFFSET RAISE ( IGNORE ) NOT NULL ) 744 } 745} {1 {invalid name: "RAISE ( IGNORE ) IN ( SELECT "AAAAAA" . * ORDER BY 746 REGISTER LIMIT "AAAAAA" . "AAAAAA" OFFSET RAISE ( IGNORE ) NOT NULL )"}} 747finish_test 748