sqlite/test/e_fkey.test
dan 598d2028e2 Add test cases to test file "e_fkey.test".
FossilOrigin-Name: 23e0f61a4f24315bf31f632f43b60ec232f348fb
2009-10-08 17:42:28 +00:00

567 lines
16 KiB
Plaintext

# 2009 October 7
#
# 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 tests to verify the "testable statements" in the
# foreignkeys.in document.
#
set testdir [file dirname $argv0]
source $testdir/tester.tcl
ifcapable {!foreignkey} { finish_test ; return }
execsql "PRAGMA foreign_keys = ON"
#-------------------------------------------------------------------------
# /* EV: R-36018-21755 */
# /* EV: R-25384-39337 */
#
# Test that parent keys are not checked when tables are created.
#
# Child keys are checked to ensure all component columns exist. If parent
# key columns are explicitly specified, SQLite checks to make sure there
# are the same number of columns in the child and parent keys. (TODO: This
# is tested but does not correspond to any testable statement.)
#
# /* EV: R-50163-54229 */
#
# Also test that the above statements are true regardless of whether or not
# foreign keys are enabled.
#
foreach {tn zCreateTbl lRes} {
1 "CREATE TABLE t1(a, b REFERENCES t1)" {0 {}}
2 "CREATE TABLE t1(a, b REFERENCES t2)" {0 {}}
3 "CREATE TABLE t1(a, b, FOREIGN KEY(a,b) REFERENCES t1)" {0 {}}
4 "CREATE TABLE t1(a, b, FOREIGN KEY(a,b) REFERENCES t2)" {0 {}}
5 "CREATE TABLE t1(a, b, FOREIGN KEY(a,b) REFERENCES t2)" {0 {}}
6 "CREATE TABLE t1(a, b, FOREIGN KEY(a,b) REFERENCES t2(n,d))" {0 {}}
7 "CREATE TABLE t1(a, b, FOREIGN KEY(a,b) REFERENCES t1(a,b))" {0 {}}
A "CREATE TABLE t1(a, b, FOREIGN KEY(c,b) REFERENCES t2)"
{1 {unknown column "c" in foreign key definition}}
B "CREATE TABLE t1(a, b, FOREIGN KEY(c,b) REFERENCES t2(d))"
{1 {number of columns in foreign key does not match the number of columns in the referenced table}}
} {
do_test e_fkey-5.$tn.off {
drop_all_tables
execsql {PRAGMA foreign_keys = OFF}
catchsql $zCreateTbl
} $lRes
do_test e_fkey-5.$tn.on {
drop_all_tables
execsql {PRAGMA foreign_keys = ON}
catchsql $zCreateTbl
} $lRes
}
#-------------------------------------------------------------------------
# /* EV: R-47952-62498 */
#
proc test_efkey_6 {tn zAlter isError} {
drop_all_tables
do_test e_fkey-6.$tn.1 "
execsql { CREATE TABLE tbl(a, b) }
[list catchsql $zAlter]
" [lindex {{0 {}} {1 {Cannot add a REFERENCES column with non-NULL default value}}} $isError]
}
test_efkey_6 1 "ALTER TABLE tbl ADD COLUMN c REFERENCES xx" 0
test_efkey_6 2 "ALTER TABLE tbl ADD COLUMN c DEFAULT NULL REFERENCES xx" 0
test_efkey_6 3 "ALTER TABLE tbl ADD COLUMN c DEFAULT 0 REFERENCES xx" 1
#-------------------------------------------------------------------------
# /* EV: R-47080-02069 */
#
# Test that ALTER TABLE adjusts REFERENCES clauses when the parent table
# is RENAMED.
#
# /* EV: R-63827-54774 */
#
# Test that these adjustments are visible in the sqlite_master table.
#
do_test e_fkey-7.1 {
drop_all_tables
execsql {
CREATE TABLE 'p 1 "parent one"'(a REFERENCES 'p 1 "parent one"', b, PRIMARY KEY(b));
CREATE TABLE c1(c, d REFERENCES 'p 1 "parent one"' ON UPDATE CASCADE);
CREATE TABLE c2(e, f, FOREIGN KEY(f) REFERENCES 'p 1 "parent one"' ON UPDATE CASCADE);
CREATE TABLE c3(e, 'f col 2', FOREIGN KEY('f col 2') REFERENCES 'p 1 "parent one"' ON UPDATE CASCADE);
INSERT INTO 'p 1 "parent one"' VALUES(1, 1);
INSERT INTO c1 VALUES(1, 1);
INSERT INTO c2 VALUES(1, 1);
INSERT INTO c3 VALUES(1, 1);
-- CREATE TABLE q(a, b, PRIMARY KEY(b));
}
} {}
do_test e_fkey-7.2 {
execsql { ALTER TABLE 'p 1 "parent one"' RENAME TO p }
} {}
do_test e_fkey-7.3 {
execsql {
UPDATE p SET a = 'xxx', b = 'xxx';
SELECT * FROM p;
SELECT * FROM c1;
SELECT * FROM c2;
SELECT * FROM c3;
}
} {xxx xxx 1 xxx 1 xxx 1 xxx}
do_test e_fkey-7.4 {
execsql { SELECT sql FROM sqlite_master WHERE type = 'table'}
} [list \
{CREATE TABLE "p"(a REFERENCES "p", b, PRIMARY KEY(b))} \
{CREATE TABLE c1(c, d REFERENCES "p" ON UPDATE CASCADE)} \
{CREATE TABLE c2(e, f, FOREIGN KEY(f) REFERENCES "p" ON UPDATE CASCADE)} \
{CREATE TABLE c3(e, 'f col 2', FOREIGN KEY('f col 2') REFERENCES "p" ON UPDATE CASCADE)} \
]
#-------------------------------------------------------------------------
# /* EV: R-14208-23986 */
# /* EV: R-11078-03945 */
#
# Check that a DROP TABLE does an implicit DELETE FROM. Which does not
# cause any triggers to fire, but does fire foreign key actions.
#
do_test e_fkey-8.1 {
drop_all_tables
execsql {
CREATE TABLE p(a, b, PRIMARY KEY(a, b));
CREATE TABLE c1(c, d, FOREIGN KEY(c, d) REFERENCES p ON DELETE SET NULL);
CREATE TABLE c2(c, d, FOREIGN KEY(c, d) REFERENCES p ON DELETE SET DEFAULT);
CREATE TABLE c3(c, d, FOREIGN KEY(c, d) REFERENCES p ON DELETE CASCADE);
CREATE TABLE c4(c, d, FOREIGN KEY(c, d) REFERENCES p ON DELETE RESTRICT);
CREATE TABLE c5(c, d, FOREIGN KEY(c, d) REFERENCES p ON DELETE NO ACTION);
CREATE TABLE c6(c, d,
FOREIGN KEY(c, d) REFERENCES p ON DELETE RESTRICT
DEFERRABLE INITIALLY DEFERRED
);
CREATE TABLE c7(c, d,
FOREIGN KEY(c, d) REFERENCES p ON DELETE NO ACTION
DEFERRABLE INITIALLY DEFERRED
);
CREATE TABLE log(msg);
CREATE TRIGGER tt AFTER DELETE ON p BEGIN
INSERT INTO log VALUES('delete ' || old.rowid);
END;
}
} {}
do_test e_fkey-8.2 {
execsql {
INSERT INTO p VALUES('a', 'b');
INSERT INTO c1 VALUES('a', 'b');
INSERT INTO c2 VALUES('a', 'b');
INSERT INTO c3 VALUES('a', 'b');
BEGIN;
DROP TABLE p;
SELECT * FROM c1;
}
} {{} {}}
do_test e_fkey-8.3 {
execsql { SELECT * FROM c2 }
} {{} {}}
do_test e_fkey-8.4 {
execsql { SELECT * FROM c3 }
} {}
do_test e_fkey-8.5 {
execsql { SELECT * FROM log }
} {}
do_test e_fkey-8.6 {
execsql ROLLBACK
} {}
do_test e_fkey-8.7 {
execsql {
BEGIN;
DELETE FROM p;
SELECT * FROM log;
ROLLBACK;
}
} {{delete 1}}
#-------------------------------------------------------------------------
# /* EV: R-32768-47925 */
#
# If an IMMEDIATE foreign key fails as a result of a DROP TABLE, the
# DROP TABLE command fails.
#
do_test e_fkey-9.1 {
execsql {
DELETE FROM c1;
DELETE FROM c2;
DELETE FROM c3;
}
execsql { INSERT INTO c5 VALUES('a', 'b') }
catchsql { DROP TABLE p }
} {1 {foreign key constraint failed}}
do_test e_fkey-9.2 {
execsql { SELECT * FROM p }
} {a b}
do_test e_fkey-9.3 {
catchsql {
BEGIN;
DROP TABLE p;
}
} {1 {foreign key constraint failed}}
do_test e_fkey-9.4 {
execsql {
SELECT * FROM p;
SELECT * FROM c5;
ROLLBACK;
}
} {a b a b}
#-------------------------------------------------------------------------
# /* EV: R-05903-08460 */
#
# If a DEFERRED foreign key fails as a result of a DROP TABLE, attempting
# to commit the transaction fails unless the violation is fixed.
#
do_test e_fkey-10.1 {
execsql {
DELETE FROM c1 ; DELETE FROM c2 ; DELETE FROM c3 ;
DELETE FROM c4 ; DELETE FROM c5 ; DELETE FROM c6 ;
DELETE FROM c7
}
} {}
do_test e_fkey-10.2 {
execsql { INSERT INTO c7 VALUES('a', 'b') }
execsql {
BEGIN;
DROP TABLE p;
}
} {}
do_test e_fkey-10.3 {
catchsql COMMIT
} {1 {foreign key constraint failed}}
do_test e_fkey-10.4 {
execsql { CREATE TABLE p(a, b, PRIMARY KEY(a, b)) }
catchsql COMMIT
} {1 {foreign key constraint failed}}
do_test e_fkey-10.5 {
execsql { INSERT INTO p VALUES('a', 'b') }
execsql COMMIT
} {}
#-------------------------------------------------------------------------
# /* EV: R-57242-37005 */
#
# Any "foreign key mismatch" errors encountered while running an implicit
# "DELETE FROM tbl" are ignored.
#
drop_all_tables
do_test e_fkey-11.1 {
execsql {
PRAGMA foreign_keys = OFF;
CREATE TABLE p(a PRIMARY KEY, b REFERENCES nosuchtable);
CREATE TABLE c1(c, d, FOREIGN KEY(c, d) REFERENCES a);
CREATE TABLE c2(c REFERENCES p(b), d);
CREATE TABLE c3(c REFERENCES p ON DELETE SET NULL, d);
INSERT INTO p VALUES(1, 2);
INSERT INTO c1 VALUES(1, 2);
INSERT INTO c2 VALUES(1, 2);
INSERT INTO c3 VALUES(1, 2);
}
} {}
do_test e_fkey-11.2 {
execsql { PRAGMA foreign_keys = ON }
catchsql { DELETE FROM p }
} {1 {no such table: main.nosuchtable}}
do_test e_fkey-11.3 {
execsql {
BEGIN;
DROP TABLE p;
SELECT * FROM c3;
ROLLBACK;
}
} {{} 2}
do_test e_fkey-11.4 {
execsql { CREATE TABLE nosuchtable(x PRIMARY KEY) }
catchsql { DELETE FROM p }
} {1 {foreign key mismatch}}
do_test e_fkey-11.5 {
execsql { DROP TABLE c1 }
catchsql { DELETE FROM p }
} {1 {foreign key mismatch}}
do_test e_fkey-11.6 {
execsql { DROP TABLE c2 }
execsql { DELETE FROM p }
} {}
#-------------------------------------------------------------------------
# /* EV: R-54142-41346 */
#
# Test that the special behaviours of ALTER and DROP TABLE are only
# activated when foreign keys are enabled. Special behaviours are:
#
# 1. ADD COLUMN not allowing a REFERENCES clause with a non-NULL
# default value.
# 2. Modifying foreign key definitions when a parent table is RENAMEd.
# 3. Running an implicit DELETE FROM command as part of DROP TABLE.
#
do_test e_fkey-12.1.1 {
drop_all_tables
execsql { CREATE TABLE t1(a, b) }
catchsql { ALTER TABLE t1 ADD COLUMN c DEFAULT 'xxx' REFERENCES t2 }
} {1 {Cannot add a REFERENCES column with non-NULL default value}}
do_test e_fkey-12.1.2 {
execsql { PRAGMA foreign_keys = OFF }
execsql { ALTER TABLE t1 ADD COLUMN c DEFAULT 'xxx' REFERENCES t2 }
execsql { SELECT sql FROM sqlite_master WHERE name = 't1' }
} {{CREATE TABLE t1(a, b, c DEFAULT 'xxx' REFERENCES t2)}}
do_test e_fkey-12.1.3 {
execsql { PRAGMA foreign_keys = ON }
} {}
do_test e_fkey-12.2.1 {
drop_all_tables
execsql {
CREATE TABLE p(a UNIQUE);
CREATE TABLE c(b REFERENCES p(a));
BEGIN;
ALTER TABLE p RENAME TO parent;
SELECT sql FROM sqlite_master WHERE name = 'c';
ROLLBACK;
}
} {{CREATE TABLE c(b REFERENCES "parent"(a))}}
do_test e_fkey-12.2.2 {
execsql {
PRAGMA foreign_keys = OFF;
ALTER TABLE p RENAME TO parent;
SELECT sql FROM sqlite_master WHERE name = 'c';
}
} {{CREATE TABLE c(b REFERENCES p(a))}}
do_test e_fkey-12.2.3 {
execsql { PRAGMA foreign_keys = ON }
} {}
do_test e_fkey-12.3.1 {
drop_all_tables
execsql {
CREATE TABLE p(a UNIQUE);
CREATE TABLE c(b REFERENCES p(a) ON DELETE SET NULL);
INSERT INTO p VALUES('x');
INSERT INTO c VALUES('x');
BEGIN;
DROP TABLE p;
SELECT * FROM c;
ROLLBACK;
}
} {{}}
do_test e_fkey-12.3.2 {
execsql {
PRAGMA foreign_keys = OFF;
DROP TABLE p;
SELECT * FROM c;
}
} {x}
do_test e_fkey-12.3.3 {
execsql { PRAGMA foreign_keys = ON }
} {}
#-------------------------------------------------------------------------
# /* EV: R-24728-13230 */
# /* EV: R-24450-46174 */
#
# Test that MATCH clauses are parsed, but SQLite treats every foreign key
# constraint as if it were "MATCH SIMPLE".
#
foreach zMatch [list SIMPLE PARTIAL FULL Simple parTIAL FuLL ] {
drop_all_tables
do_test e_fkey-1.$zMatch.1 {
execsql "
CREATE TABLE p(a, b, c, PRIMARY KEY(b, c));
CREATE TABLE c(d, e, f, FOREIGN KEY(e, f) REFERENCES p MATCH $zMatch);
"
} {}
do_test e_fkey-1.$zMatch.2 {
execsql { INSERT INTO p VALUES(1, 2, 3) }
# MATCH SIMPLE behaviour: Allow any child key that contains one or more
# NULL value to be inserted. Non-NULL values do not have to map to any
# parent key values, so long as at least one field of the child key is
# NULL.
execsql { INSERT INTO c VALUES('w', 2, 3) }
execsql { INSERT INTO c VALUES('x', 'x', NULL) }
execsql { INSERT INTO c VALUES('y', NULL, 'x') }
execsql { INSERT INTO c VALUES('z', NULL, NULL) }
# Check that the FK is enforced properly if there are no NULL values
# in the child key columns.
catchsql { INSERT INTO c VALUES('a', 2, 4) }
} {1 {foreign key constraint failed}}
}
#-------------------------------------------------------------------------
# /* EV: R-21599-16038 */
#
# Test that SQLite does not support the SET CONSTRAINT statement. And
# that it is possible to create both immediate and deferred constraints.
#
drop_all_tables
do_test e_fkey-2.1 {
catchsql { SET CONSTRAINTS ALL IMMEDIATE }
} {1 {near "SET": syntax error}}
do_test e_fkey-2.2 {
catchsql { SET CONSTRAINTS ALL DEFERRED }
} {1 {near "SET": syntax error}}
do_test e_fkey-2.3 {
execsql {
CREATE TABLE p(a, b, PRIMARY KEY(a, b));
CREATE TABLE cd(c, d,
FOREIGN KEY(c, d) REFERENCES p DEFERRABLE INITIALLY DEFERRED);
CREATE TABLE ci(c, d,
FOREIGN KEY(c, d) REFERENCES p DEFERRABLE INITIALLY IMMEDIATE);
BEGIN;
}
} {}
do_test e_fkey-2.4 {
catchsql { INSERT INTO ci VALUES('x', 'y') }
} {1 {foreign key constraint failed}}
do_test e_fkey-2.5 {
catchsql { INSERT INTO cd VALUES('x', 'y') }
} {0 {}}
do_test e_fkey-2.6 {
catchsql { COMMIT }
} {1 {foreign key constraint failed}}
do_test e_fkey-2.7 {
execsql {
DELETE FROM cd;
COMMIT;
}
} {}
#-------------------------------------------------------------------------
# /* EV: R-42264-30503 */
#
# Test that the maximum recursion depth of foreign key action programs is
# governed by the SQLITE_MAX_TRIGGER_DEPTH and SQLITE_LIMIT_TRIGGER_DEPTH
# settings.
#
proc test_on_delete_recursion {limit} {
drop_all_tables
execsql {
BEGIN;
CREATE TABLE t0(a PRIMARY KEY, b);
INSERT INTO t0 VALUES('x0', NULL);
}
for {set i 1} {$i <= $limit} {incr i} {
execsql "
CREATE TABLE t$i (
a PRIMARY KEY, b REFERENCES t[expr $i-1] ON DELETE CASCADE
);
INSERT INTO t$i VALUES('x$i', 'x[expr $i-1]');
"
}
execsql COMMIT
catchsql "
DELETE FROM t0;
SELECT count(*) FROM t$limit;
"
}
proc test_on_update_recursion {limit} {
drop_all_tables
execsql {
BEGIN;
CREATE TABLE t0(a PRIMARY KEY);
INSERT INTO t0 VALUES('xxx');
}
for {set i 1} {$i <= $limit} {incr i} {
set j [expr $i-1]
execsql "
CREATE TABLE t$i (a PRIMARY KEY REFERENCES t$j ON UPDATE CASCADE);
INSERT INTO t$i VALUES('xxx');
"
}
execsql COMMIT
catchsql "
UPDATE t0 SET a = 'yyy';
SELECT NOT (a='yyy') FROM t$limit;
"
}
do_test e_fkey-3.1.1 {
test_on_delete_recursion $SQLITE_MAX_TRIGGER_DEPTH
} {0 0}
do_test e_fkey-3.1.2 {
test_on_delete_recursion [expr $SQLITE_MAX_TRIGGER_DEPTH+1]
} {1 {too many levels of trigger recursion}}
do_test e_fkey-3.1.3 {
sqlite3_limit db SQLITE_LIMIT_TRIGGER_DEPTH 5
test_on_delete_recursion 5
} {0 0}
do_test e_fkey-3.1.4 {
test_on_delete_recursion 6
} {1 {too many levels of trigger recursion}}
do_test e_fkey-3.1.5 {
sqlite3_limit db SQLITE_LIMIT_TRIGGER_DEPTH 1000000
} {5}
do_test e_fkey-3.2.1 {
test_on_update_recursion $SQLITE_MAX_TRIGGER_DEPTH
} {0 0}
do_test e_fkey-3.2.2 {
test_on_update_recursion [expr $SQLITE_MAX_TRIGGER_DEPTH+1]
} {1 {too many levels of trigger recursion}}
do_test e_fkey-3.2.3 {
sqlite3_limit db SQLITE_LIMIT_TRIGGER_DEPTH 5
test_on_update_recursion 5
} {0 0}
do_test e_fkey-3.2.4 {
test_on_update_recursion 6
} {1 {too many levels of trigger recursion}}
do_test e_fkey-3.2.5 {
sqlite3_limit db SQLITE_LIMIT_TRIGGER_DEPTH 1000000
} {5}
#-------------------------------------------------------------------------
# /* EV: R-51769-32730 */
#
# The setting of the recursive_triggers pragma does not affect foreign
# key actions.
#
foreach recursive_triggers_setting [list 0 1 ON OFF] {
drop_all_tables
execsql "PRAGMA recursive_triggers = $recursive_triggers_setting"
do_test e_fkey-4.$recursive_triggers_setting.1 {
execsql {
CREATE TABLE t1(a PRIMARY KEY, b REFERENCES t1 ON DELETE CASCADE);
INSERT INTO t1 VALUES(1, NULL);
INSERT INTO t1 VALUES(2, 1);
INSERT INTO t1 VALUES(3, 2);
INSERT INTO t1 VALUES(4, 3);
INSERT INTO t1 VALUES(5, 4);
SELECT count(*) FROM t1;
}
} {5}
do_test e_fkey-4.$recursive_triggers_setting.2 {
execsql { SELECT count(*) FROM t1 WHERE a = 1 }
} {1}
do_test e_fkey-4.$recursive_triggers_setting.3 {
execsql {
DELETE FROM t1 WHERE a = 1;
SELECT count(*) FROM t1;
}
} {0}
}
finish_test