xref: /sqlite-3.40.0/test/e_fkey.test (revision 4d7f335e)
1f589450dSdan# 2009 October 7
2f589450dSdan#
3f589450dSdan# The author disclaims copyright to this source code.  In place of
4f589450dSdan# a legal notice, here is a blessing:
5f589450dSdan#
6f589450dSdan#    May you do good and not evil.
7f589450dSdan#    May you find forgiveness for yourself and forgive others.
8f589450dSdan#    May you share freely, never taking more than you give.
9f589450dSdan#
10f589450dSdan#***********************************************************************
11f589450dSdan#
12f589450dSdan# This file implements tests to verify the "testable statements" in the
13f589450dSdan# foreignkeys.in document.
14f589450dSdan#
153bc485e6Sdan# The tests in this file are arranged to mirror the structure of
163bc485e6Sdan# foreignkey.in, with one exception: The statements in section 2, which
173bc485e6Sdan# deals with enabling/disabling foreign key support, is tested first,
183bc485e6Sdan# before section 1. This is because some statements in section 2 deal
193bc485e6Sdan# with builds that do not include complete foreign key support (because
203bc485e6Sdan# either SQLITE_OMIT_TRIGGER or SQLITE_OMIT_FOREIGN_KEY was defined
213bc485e6Sdan# at build time).
223bc485e6Sdan#
23f589450dSdan
24f589450dSdanset testdir [file dirname $argv0]
25f589450dSdansource $testdir/tester.tcl
26f589450dSdan
27d3e17ffbSdanproc eqp {sql {db db}} {
28d3e17ffbSdan  uplevel [subst -nocommands {
29d3e17ffbSdan    set eqpres [list]
30d3e17ffbSdan    $db eval "$sql" {
31d3e17ffbSdan      lappend eqpres [set detail]
32d3e17ffbSdan    }
33d3e17ffbSdan    set eqpres
34d3e17ffbSdan  }]
35d3e17ffbSdan}
36d3e17ffbSdan
37d3e17ffbSdanproc do_detail_test {tn sql res} {
38d3e17ffbSdan  set normalres [list {*}$res]
39d3e17ffbSdan  uplevel [subst -nocommands {
40d3e17ffbSdan    do_test $tn {
41d3e17ffbSdan      eqp { $sql }
42d3e17ffbSdan    } {$normalres}
43d3e17ffbSdan  }]
44d3e17ffbSdan}
45166d9c8aSdan
463bc485e6Sdan###########################################################################
473bc485e6Sdan### SECTION 2: Enabling Foreign Key Support
483bc485e6Sdan###########################################################################
493bc485e6Sdan
503bc485e6Sdan#-------------------------------------------------------------------------
51*4d7f335eSdrh# EVIDENCE-OF: R-37672-59189 In order to use foreign key constraints in
5227298ffdSdan# SQLite, the library must be compiled with neither
53*4d7f335eSdrh# SQLITE_OMIT_FOREIGN_KEY nor SQLITE_OMIT_TRIGGER defined.
543bc485e6Sdan#
553bc485e6Sdanifcapable trigger&&foreignkey {
56c473b48bSdan  do_test e_fkey-1 {
573bc485e6Sdan    execsql {
583bc485e6Sdan      PRAGMA foreign_keys = ON;
593bc485e6Sdan      CREATE TABLE p(i PRIMARY KEY);
603bc485e6Sdan      CREATE TABLE c(j REFERENCES p ON UPDATE CASCADE);
613bc485e6Sdan      INSERT INTO p VALUES('hello');
623bc485e6Sdan      INSERT INTO c VALUES('hello');
633bc485e6Sdan      UPDATE p SET i = 'world';
643bc485e6Sdan      SELECT * FROM c;
653bc485e6Sdan    }
663bc485e6Sdan  } {world}
673bc485e6Sdan}
683bc485e6Sdan
693bc485e6Sdan#-------------------------------------------------------------------------
703bc485e6Sdan# Test the effects of defining OMIT_TRIGGER but not OMIT_FOREIGN_KEY.
713bc485e6Sdan#
72fb04a36cSdrh# EVIDENCE-OF: R-10109-20452 If SQLITE_OMIT_TRIGGER is defined but
7327298ffdSdan# SQLITE_OMIT_FOREIGN_KEY is not, then SQLite behaves as it did prior to
74fb04a36cSdrh# version 3.6.19 (2009-10-14) - foreign key definitions are parsed and
75fb04a36cSdrh# may be queried using PRAGMA foreign_key_list, but foreign key
76fb04a36cSdrh# constraints are not enforced.
773bc485e6Sdan#
783bc485e6Sdan# Specifically, test that "PRAGMA foreign_keys" is a no-op in this case.
793bc485e6Sdan# When using the pragma to query the current setting, 0 rows are returned.
803bc485e6Sdan#
8127298ffdSdan# EVIDENCE-OF: R-22567-44039 The PRAGMA foreign_keys command is a no-op
8227298ffdSdan# in this configuration.
8327298ffdSdan#
8427298ffdSdan# EVIDENCE-OF: R-41784-13339 Tip: If the command "PRAGMA foreign_keys"
8527298ffdSdan# returns no data instead of a single row containing "0" or "1", then
8627298ffdSdan# the version of SQLite you are using does not support foreign keys
8727298ffdSdan# (either because it is older than 3.6.19 or because it was compiled
8827298ffdSdan# with SQLITE_OMIT_FOREIGN_KEY or SQLITE_OMIT_TRIGGER defined).
8927298ffdSdan#
903bc485e6Sdanreset_db
913bc485e6Sdanifcapable !trigger&&foreignkey {
928e9f6aedSdan  do_test e_fkey-2.1 {
933bc485e6Sdan    execsql {
943bc485e6Sdan      PRAGMA foreign_keys = ON;
953bc485e6Sdan      CREATE TABLE p(i PRIMARY KEY);
963bc485e6Sdan      CREATE TABLE c(j REFERENCES p ON UPDATE CASCADE);
973bc485e6Sdan      INSERT INTO p VALUES('hello');
983bc485e6Sdan      INSERT INTO c VALUES('hello');
993bc485e6Sdan      UPDATE p SET i = 'world';
1003bc485e6Sdan      SELECT * FROM c;
1013bc485e6Sdan    }
1023bc485e6Sdan  } {hello}
1038e9f6aedSdan  do_test e_fkey-2.2 {
1043bc485e6Sdan    execsql { PRAGMA foreign_key_list(c) }
1053bc485e6Sdan  } {0 0 p j {} CASCADE {NO ACTION} NONE}
1068e9f6aedSdan  do_test e_fkey-2.3 {
1073bc485e6Sdan    execsql { PRAGMA foreign_keys }
1083bc485e6Sdan  } {}
1093bc485e6Sdan}
1103bc485e6Sdan
1113bc485e6Sdan
1123bc485e6Sdan#-------------------------------------------------------------------------
1133bc485e6Sdan# Test the effects of defining OMIT_FOREIGN_KEY.
1143bc485e6Sdan#
11527298ffdSdan# EVIDENCE-OF: R-58428-36660 If OMIT_FOREIGN_KEY is defined, then
11627298ffdSdan# foreign key definitions cannot even be parsed (attempting to specify a
11727298ffdSdan# foreign key definition is a syntax error).
11827298ffdSdan#
1193bc485e6Sdan# Specifically, test that foreign key constraints cannot even be parsed
1203bc485e6Sdan# in such a build.
1213bc485e6Sdan#
1223bc485e6Sdanreset_db
1233bc485e6Sdanifcapable !foreignkey {
1248e9f6aedSdan  do_test e_fkey-3.1 {
1253bc485e6Sdan    execsql { CREATE TABLE p(i PRIMARY KEY) }
1263bc485e6Sdan    catchsql { CREATE TABLE c(j REFERENCES p ON UPDATE CASCADE) }
1273bc485e6Sdan  } {1 {near "ON": syntax error}}
1288e9f6aedSdan  do_test e_fkey-3.2 {
1293bc485e6Sdan    # This is allowed, as in this build, "REFERENCES" is not a keyword.
1303bc485e6Sdan    # The declared datatype of column j is "REFERENCES p".
1313bc485e6Sdan    execsql { CREATE TABLE c(j REFERENCES p) }
1323bc485e6Sdan  } {}
1338e9f6aedSdan  do_test e_fkey-3.3 {
1343bc485e6Sdan    execsql { PRAGMA table_info(c) }
1353bc485e6Sdan  } {0 j {REFERENCES p} 0 {} 0}
1368e9f6aedSdan  do_test e_fkey-3.4 {
1373bc485e6Sdan    execsql { PRAGMA foreign_key_list(c) }
1383bc485e6Sdan  } {}
1398e9f6aedSdan  do_test e_fkey-3.5 {
1403bc485e6Sdan    execsql { PRAGMA foreign_keys }
1413bc485e6Sdan  } {}
1423bc485e6Sdan}
1433bc485e6Sdan
1443bc485e6Sdanifcapable !foreignkey||!trigger { finish_test ; return }
1453bc485e6Sdanreset_db
1463bc485e6Sdan
1473bc485e6Sdan
1483bc485e6Sdan#-------------------------------------------------------------------------
14927298ffdSdan# EVIDENCE-OF: R-07280-60510 Assuming the library is compiled with
15027298ffdSdan# foreign key constraints enabled, it must still be enabled by the
15127298ffdSdan# application at runtime, using the PRAGMA foreign_keys command.
1523bc485e6Sdan#
1533bc485e6Sdan# This also tests that foreign key constraints are disabled by default.
1543bc485e6Sdan#
1551f8bb4b0Sdrh# EVIDENCE-OF: R-44261-39702 Foreign key constraints are disabled by
15627298ffdSdan# default (for backwards compatibility), so must be enabled separately
1571f8bb4b0Sdrh# for each database connection.
15827298ffdSdan#
1593bc485e6Sdandrop_all_tables
1608e9f6aedSdando_test e_fkey-4.1 {
1613bc485e6Sdan  execsql {
1623bc485e6Sdan    CREATE TABLE p(i PRIMARY KEY);
1633bc485e6Sdan    CREATE TABLE c(j REFERENCES p ON UPDATE CASCADE);
1643bc485e6Sdan    INSERT INTO p VALUES('hello');
1653bc485e6Sdan    INSERT INTO c VALUES('hello');
1663bc485e6Sdan    UPDATE p SET i = 'world';
1673bc485e6Sdan    SELECT * FROM c;
1683bc485e6Sdan  }
1693bc485e6Sdan} {hello}
1708e9f6aedSdando_test e_fkey-4.2 {
1713bc485e6Sdan  execsql {
1723bc485e6Sdan    DELETE FROM c;
1733bc485e6Sdan    DELETE FROM p;
1743bc485e6Sdan    PRAGMA foreign_keys = ON;
1753bc485e6Sdan    INSERT INTO p VALUES('hello');
1763bc485e6Sdan    INSERT INTO c VALUES('hello');
1773bc485e6Sdan    UPDATE p SET i = 'world';
1783bc485e6Sdan    SELECT * FROM c;
1793bc485e6Sdan  }
1803bc485e6Sdan} {world}
1813bc485e6Sdan
1823bc485e6Sdan#-------------------------------------------------------------------------
1831f8bb4b0Sdrh# EVIDENCE-OF: R-08013-37737 The application can also use a PRAGMA
18427298ffdSdan# foreign_keys statement to determine if foreign keys are currently
18527298ffdSdan# enabled.
1861f8bb4b0Sdrh
1873bc485e6Sdan#
18827298ffdSdan# This also tests the example code in section 2 of foreignkeys.in.
18927298ffdSdan#
19027298ffdSdan# EVIDENCE-OF: R-11255-19907
1913bc485e6Sdan#
1923bc485e6Sdanreset_db
1938e9f6aedSdando_test e_fkey-5.1 {
1943bc485e6Sdan  execsql { PRAGMA foreign_keys }
1953bc485e6Sdan} {0}
1968e9f6aedSdando_test e_fkey-5.2 {
1973bc485e6Sdan  execsql {
1983bc485e6Sdan    PRAGMA foreign_keys = ON;
1993bc485e6Sdan    PRAGMA foreign_keys;
2003bc485e6Sdan  }
2013bc485e6Sdan} {1}
2028e9f6aedSdando_test e_fkey-5.3 {
2033bc485e6Sdan  execsql {
2043bc485e6Sdan    PRAGMA foreign_keys = OFF;
2053bc485e6Sdan    PRAGMA foreign_keys;
2063bc485e6Sdan  }
2073bc485e6Sdan} {0}
2083bc485e6Sdan
2093bc485e6Sdan#-------------------------------------------------------------------------
2103bc485e6Sdan# Test that it is not possible to enable or disable foreign key support
2113bc485e6Sdan# while not in auto-commit mode.
2123bc485e6Sdan#
21327298ffdSdan# EVIDENCE-OF: R-46649-58537 It is not possible to enable or disable
21427298ffdSdan# foreign key constraints in the middle of a multi-statement transaction
21527298ffdSdan# (when SQLite is not in autocommit mode). Attempting to do so does not
21627298ffdSdan# return an error; it simply has no effect.
21727298ffdSdan#
2183bc485e6Sdanreset_db
2198e9f6aedSdando_test e_fkey-6.1 {
2203bc485e6Sdan  execsql {
2213bc485e6Sdan    PRAGMA foreign_keys = ON;
2223bc485e6Sdan    CREATE TABLE t1(a UNIQUE, b);
2233bc485e6Sdan    CREATE TABLE t2(c, d REFERENCES t1(a));
2243bc485e6Sdan    INSERT INTO t1 VALUES(1, 2);
2253bc485e6Sdan    INSERT INTO t2 VALUES(2, 1);
2263bc485e6Sdan    BEGIN;
2273bc485e6Sdan      PRAGMA foreign_keys = OFF;
2283bc485e6Sdan  }
2293bc485e6Sdan  catchsql {
2303bc485e6Sdan      DELETE FROM t1
2313bc485e6Sdan  }
232f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
2338e9f6aedSdando_test e_fkey-6.2 {
2343bc485e6Sdan  execsql { PRAGMA foreign_keys }
2353bc485e6Sdan} {1}
2368e9f6aedSdando_test e_fkey-6.3 {
2373bc485e6Sdan  execsql {
2383bc485e6Sdan    COMMIT;
2393bc485e6Sdan    PRAGMA foreign_keys = OFF;
2403bc485e6Sdan    BEGIN;
2413bc485e6Sdan      PRAGMA foreign_keys = ON;
2423bc485e6Sdan      DELETE FROM t1;
2433bc485e6Sdan      PRAGMA foreign_keys;
2443bc485e6Sdan  }
2453bc485e6Sdan} {0}
2468e9f6aedSdando_test e_fkey-6.4 {
2473bc485e6Sdan  execsql COMMIT
2483bc485e6Sdan} {}
249f589450dSdan
2502140429cSdan###########################################################################
2512f01f465Sdan### SECTION 1: Introduction to Foreign Key Constraints
2522f01f465Sdan###########################################################################
2533bc485e6Sdanexecsql "PRAGMA foreign_keys = ON"
2542f01f465Sdan
255e506deb2Sdan#-------------------------------------------------------------------------
256e506deb2Sdan# Verify that the syntax in the first example in section 1 is valid.
257e506deb2Sdan#
25827298ffdSdan# EVIDENCE-OF: R-04042-24825 To do so, a foreign key definition may be
25927298ffdSdan# added by modifying the declaration of the track table to the
26027298ffdSdan# following: CREATE TABLE track( trackid INTEGER, trackname TEXT,
26127298ffdSdan# trackartist INTEGER, FOREIGN KEY(trackartist) REFERENCES
26227298ffdSdan# artist(artistid) );
26327298ffdSdan#
2648e9f6aedSdando_test e_fkey-7.1 {
265e506deb2Sdan  execsql {
266e506deb2Sdan    CREATE TABLE artist(
267e506deb2Sdan      artistid    INTEGER PRIMARY KEY,
268e506deb2Sdan      artistname  TEXT
269e506deb2Sdan    );
270e506deb2Sdan    CREATE TABLE track(
271e506deb2Sdan      trackid     INTEGER,
272e506deb2Sdan      trackname   TEXT,
273e506deb2Sdan      trackartist INTEGER,
274e506deb2Sdan      FOREIGN KEY(trackartist) REFERENCES artist(artistid)
275e506deb2Sdan    );
276e506deb2Sdan  }
277e506deb2Sdan} {}
278e506deb2Sdan
279e506deb2Sdan#-------------------------------------------------------------------------
28027298ffdSdan# EVIDENCE-OF: R-61362-32087 Attempting to insert a row into the track
28127298ffdSdan# table that does not correspond to any row in the artist table will
28227298ffdSdan# fail,
283e506deb2Sdan#
2848e9f6aedSdando_test e_fkey-8.1 {
285e506deb2Sdan  catchsql { INSERT INTO track VALUES(1, 'track 1', 1) }
286f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
2878e9f6aedSdando_test e_fkey-8.2 {
288e506deb2Sdan  execsql { INSERT INTO artist VALUES(2, 'artist 1') }
289e506deb2Sdan  catchsql { INSERT INTO track VALUES(1, 'track 1', 1) }
290f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
2918e9f6aedSdando_test e_fkey-8.2 {
292e506deb2Sdan  execsql { INSERT INTO track VALUES(1, 'track 1', 2) }
293e506deb2Sdan} {}
294e506deb2Sdan
295e506deb2Sdan#-------------------------------------------------------------------------
296e506deb2Sdan# Attempting to delete a row from the 'artist' table while there are
297e506deb2Sdan# dependent rows in the track table also fails.
298e506deb2Sdan#
29927298ffdSdan# EVIDENCE-OF: R-24401-52400 as will attempting to delete a row from the
30027298ffdSdan# artist table when there exist dependent rows in the track table
30127298ffdSdan#
3028e9f6aedSdando_test e_fkey-9.1 {
303e506deb2Sdan  catchsql { DELETE FROM artist WHERE artistid = 2 }
304f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
3058e9f6aedSdando_test e_fkey-9.2 {
306e506deb2Sdan  execsql {
307e506deb2Sdan    DELETE FROM track WHERE trackartist = 2;
308e506deb2Sdan    DELETE FROM artist WHERE artistid = 2;
309e506deb2Sdan  }
310e506deb2Sdan} {}
311e506deb2Sdan
312e506deb2Sdan#-------------------------------------------------------------------------
313e506deb2Sdan# If the foreign key column (trackartist) in table 'track' is set to NULL,
314e506deb2Sdan# there is no requirement for a matching row in the 'artist' table.
315e506deb2Sdan#
31627298ffdSdan# EVIDENCE-OF: R-23980-48859 There is one exception: if the foreign key
31727298ffdSdan# column in the track table is NULL, then no corresponding entry in the
31827298ffdSdan# artist table is required.
31927298ffdSdan#
3208e9f6aedSdando_test e_fkey-10.1 {
321e506deb2Sdan  execsql {
322e506deb2Sdan    INSERT INTO track VALUES(1, 'track 1', NULL);
323e506deb2Sdan    INSERT INTO track VALUES(2, 'track 2', NULL);
324e506deb2Sdan  }
325e506deb2Sdan} {}
3268e9f6aedSdando_test e_fkey-10.2 {
327e506deb2Sdan  execsql { SELECT * FROM artist }
328e506deb2Sdan} {}
3298e9f6aedSdando_test e_fkey-10.3 {
330e506deb2Sdan  # Setting the trackid to a non-NULL value fails, of course.
331e506deb2Sdan  catchsql { UPDATE track SET trackartist = 5 WHERE trackid = 1 }
332f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
3338e9f6aedSdando_test e_fkey-10.4 {
334e506deb2Sdan  execsql {
335e506deb2Sdan    INSERT INTO artist VALUES(5, 'artist 5');
336e506deb2Sdan    UPDATE track SET trackartist = 5 WHERE trackid = 1;
337e506deb2Sdan  }
338e506deb2Sdan  catchsql { DELETE FROM artist WHERE artistid = 5}
339f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
3408e9f6aedSdando_test e_fkey-10.5 {
341e506deb2Sdan  execsql {
342e506deb2Sdan    UPDATE track SET trackartist = NULL WHERE trackid = 1;
343e506deb2Sdan    DELETE FROM artist WHERE artistid = 5;
344e506deb2Sdan  }
345e506deb2Sdan} {}
346e506deb2Sdan
347e506deb2Sdan#-------------------------------------------------------------------------
348e506deb2Sdan# Test that the following is true fo all rows in the track table:
349e506deb2Sdan#
350e506deb2Sdan#   trackartist IS NULL OR
351e506deb2Sdan#   EXISTS(SELECT 1 FROM artist WHERE artistid=trackartist)
352e506deb2Sdan#
35327298ffdSdan# EVIDENCE-OF: R-52486-21352 Expressed in SQL, this means that for every
35427298ffdSdan# row in the track table, the following expression evaluates to true:
35527298ffdSdan# trackartist IS NULL OR EXISTS(SELECT 1 FROM artist WHERE
35627298ffdSdan# artistid=trackartist)
357e506deb2Sdan
358e506deb2Sdan# This procedure executes a test case to check that statement
359e506deb2Sdan# R-52486-21352 is true after executing the SQL statement passed.
360e506deb2Sdan# as the second argument.
361e506deb2Sdanproc test_r52486_21352 {tn sql} {
362e506deb2Sdan  set res [catchsql $sql]
363e506deb2Sdan  set results {
364e506deb2Sdan    {0 {}}
365f9c8ce3cSdrh    {1 {UNIQUE constraint failed: artist.artistid}}
366f9c8ce3cSdrh    {1 {FOREIGN KEY constraint failed}}
367e506deb2Sdan  }
368e506deb2Sdan  if {[lsearch $results $res]<0} {
369e506deb2Sdan    error $res
370e506deb2Sdan  }
371e506deb2Sdan
3728e9f6aedSdan  do_test e_fkey-11.$tn {
373e506deb2Sdan    execsql {
374e506deb2Sdan      SELECT count(*) FROM track WHERE NOT (
375e506deb2Sdan        trackartist IS NULL OR
376e506deb2Sdan        EXISTS(SELECT 1 FROM artist WHERE artistid=trackartist)
377e506deb2Sdan      )
378e506deb2Sdan    }
379e506deb2Sdan  } {0}
380e506deb2Sdan}
381e506deb2Sdan
382e506deb2Sdan# Execute a series of random INSERT, UPDATE and DELETE operations
383e506deb2Sdan# (some of which may fail due to FK or PK constraint violations) on
384e506deb2Sdan# the two tables in the example schema. Test that R-52486-21352
385e506deb2Sdan# is true after executing each operation.
386e506deb2Sdan#
387e506deb2Sdanset Template {
388e506deb2Sdan  {INSERT INTO track VALUES($t, 'track $t', $a)}
389e506deb2Sdan  {DELETE FROM track WHERE trackid = $t}
390e506deb2Sdan  {UPDATE track SET trackartist = $a WHERE trackid = $t}
391e506deb2Sdan  {INSERT INTO artist VALUES($a, 'artist $a')}
392e506deb2Sdan  {DELETE FROM artist WHERE artistid = $a}
393e506deb2Sdan  {UPDATE artist SET artistid = $a2 WHERE artistid = $a}
394e506deb2Sdan}
395e506deb2Sdanfor {set i 0} {$i < 500} {incr i} {
396e506deb2Sdan  set a   [expr int(rand()*10)]
397e506deb2Sdan  set a2  [expr int(rand()*10)]
398e506deb2Sdan  set t   [expr int(rand()*50)]
399e506deb2Sdan  set sql [subst [lindex $Template [expr int(rand()*6)]]]
400e506deb2Sdan
401e506deb2Sdan  test_r52486_21352 $i $sql
402e506deb2Sdan}
403e506deb2Sdan
404e506deb2Sdan#-------------------------------------------------------------------------
405e506deb2Sdan# Check that a NOT NULL constraint can be added to the example schema
406e506deb2Sdan# to prohibit NULL child keys from being inserted.
407e506deb2Sdan#
40827298ffdSdan# EVIDENCE-OF: R-42412-59321 Tip: If the application requires a stricter
40927298ffdSdan# relationship between artist and track, where NULL values are not
41027298ffdSdan# permitted in the trackartist column, simply add the appropriate "NOT
41127298ffdSdan# NULL" constraint to the schema.
41227298ffdSdan#
413e506deb2Sdandrop_all_tables
4148e9f6aedSdando_test e_fkey-12.1 {
415e506deb2Sdan  execsql {
416e506deb2Sdan    CREATE TABLE artist(
417e506deb2Sdan      artistid    INTEGER PRIMARY KEY,
418e506deb2Sdan      artistname  TEXT
419e506deb2Sdan    );
420e506deb2Sdan    CREATE TABLE track(
421e506deb2Sdan      trackid     INTEGER,
422e506deb2Sdan      trackname   TEXT,
423e506deb2Sdan      trackartist INTEGER NOT NULL,
424e506deb2Sdan      FOREIGN KEY(trackartist) REFERENCES artist(artistid)
425e506deb2Sdan    );
426e506deb2Sdan  }
427e506deb2Sdan} {}
4288e9f6aedSdando_test e_fkey-12.2 {
429e506deb2Sdan  catchsql { INSERT INTO track VALUES(14, 'Mr. Bojangles', NULL) }
430f9c8ce3cSdrh} {1 {NOT NULL constraint failed: track.trackartist}}
431e506deb2Sdan
432e506deb2Sdan#-------------------------------------------------------------------------
4339ede952aSdrh# EVIDENCE-OF: R-16127-35442
434e506deb2Sdan#
435e506deb2Sdan# Test an example from foreignkeys.html.
436e506deb2Sdan#
437e506deb2Sdandrop_all_tables
4388e9f6aedSdando_test e_fkey-13.1 {
439e506deb2Sdan  execsql {
440e506deb2Sdan    CREATE TABLE artist(
441e506deb2Sdan      artistid    INTEGER PRIMARY KEY,
442e506deb2Sdan      artistname  TEXT
443e506deb2Sdan    );
444e506deb2Sdan    CREATE TABLE track(
445e506deb2Sdan      trackid     INTEGER,
446e506deb2Sdan      trackname   TEXT,
447e506deb2Sdan      trackartist INTEGER,
448e506deb2Sdan      FOREIGN KEY(trackartist) REFERENCES artist(artistid)
449e506deb2Sdan    );
450e506deb2Sdan    INSERT INTO artist VALUES(1, 'Dean Martin');
451e506deb2Sdan    INSERT INTO artist VALUES(2, 'Frank Sinatra');
452e506deb2Sdan    INSERT INTO track VALUES(11, 'That''s Amore', 1);
453e506deb2Sdan    INSERT INTO track VALUES(12, 'Christmas Blues', 1);
454e506deb2Sdan    INSERT INTO track VALUES(13, 'My Way', 2);
455e506deb2Sdan  }
456e506deb2Sdan} {}
4578e9f6aedSdando_test e_fkey-13.2 {
458e506deb2Sdan  catchsql { INSERT INTO track VALUES(14, 'Mr. Bojangles', 3) }
459f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
4608e9f6aedSdando_test e_fkey-13.3 {
461e506deb2Sdan  execsql { INSERT INTO track VALUES(14, 'Mr. Bojangles', NULL) }
462e506deb2Sdan} {}
4638e9f6aedSdando_test e_fkey-13.4 {
464e506deb2Sdan  catchsql {
465e506deb2Sdan    UPDATE track SET trackartist = 3 WHERE trackname = 'Mr. Bojangles';
466e506deb2Sdan  }
467f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
4688e9f6aedSdando_test e_fkey-13.5 {
469e506deb2Sdan  execsql {
470e506deb2Sdan    INSERT INTO artist VALUES(3, 'Sammy Davis Jr.');
471e506deb2Sdan    UPDATE track SET trackartist = 3 WHERE trackname = 'Mr. Bojangles';
472e506deb2Sdan    INSERT INTO track VALUES(15, 'Boogie Woogie', 3);
473e506deb2Sdan  }
474e506deb2Sdan} {}
475e506deb2Sdan
476e506deb2Sdan#-------------------------------------------------------------------------
4779ede952aSdrh# EVIDENCE-OF: R-15958-50233
478e506deb2Sdan#
479e506deb2Sdan# Test the second example from the first section of foreignkeys.html.
480e506deb2Sdan#
4818e9f6aedSdando_test e_fkey-14.1 {
482e506deb2Sdan  catchsql {
483e506deb2Sdan    DELETE FROM artist WHERE artistname = 'Frank Sinatra';
484e506deb2Sdan  }
485f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
4868e9f6aedSdando_test e_fkey-14.2 {
487e506deb2Sdan  execsql {
488e506deb2Sdan    DELETE FROM track WHERE trackname = 'My Way';
489e506deb2Sdan    DELETE FROM artist WHERE artistname = 'Frank Sinatra';
490e506deb2Sdan  }
491e506deb2Sdan} {}
4928e9f6aedSdando_test e_fkey-14.3 {
493e506deb2Sdan  catchsql {
494e506deb2Sdan    UPDATE artist SET artistid=4 WHERE artistname = 'Dean Martin';
495e506deb2Sdan  }
496f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
4978e9f6aedSdando_test e_fkey-14.4 {
498e506deb2Sdan  execsql {
499e506deb2Sdan    DELETE FROM track WHERE trackname IN('That''s Amore', 'Christmas Blues');
500e506deb2Sdan    UPDATE artist SET artistid=4 WHERE artistname = 'Dean Martin';
501e506deb2Sdan  }
502e506deb2Sdan} {}
503e506deb2Sdan
504e506deb2Sdan
505e506deb2Sdan#-------------------------------------------------------------------------
50627298ffdSdan# EVIDENCE-OF: R-56032-24923 The foreign key constraint is satisfied if
50727298ffdSdan# for each row in the child table either one or more of the child key
50827298ffdSdan# columns are NULL, or there exists a row in the parent table for which
50927298ffdSdan# each parent key column contains a value equal to the value in its
51027298ffdSdan# associated child key column.
511e506deb2Sdan#
51227298ffdSdan# Test also that the usual comparison rules are used when testing if there
513e506deb2Sdan# is a matching row in the parent table of a foreign key constraint.
514e506deb2Sdan#
51527298ffdSdan# EVIDENCE-OF: R-57765-12380 In the above paragraph, the term "equal"
51627298ffdSdan# means equal when values are compared using the rules specified here.
51727298ffdSdan#
518e506deb2Sdandrop_all_tables
5198e9f6aedSdando_test e_fkey-15.1 {
520e506deb2Sdan  execsql {
521e506deb2Sdan    CREATE TABLE par(p PRIMARY KEY);
522e506deb2Sdan    CREATE TABLE chi(c REFERENCES par);
523e506deb2Sdan
524e506deb2Sdan    INSERT INTO par VALUES(1);
525e506deb2Sdan    INSERT INTO par VALUES('1');
526e506deb2Sdan    INSERT INTO par VALUES(X'31');
527e506deb2Sdan    SELECT typeof(p) FROM par;
528e506deb2Sdan  }
529e506deb2Sdan} {integer text blob}
530e506deb2Sdan
531e506deb2Sdanproc test_efkey_45 {tn isError sql} {
5328e9f6aedSdan  do_test e_fkey-15.$tn.1 "
533e506deb2Sdan    catchsql {$sql}
534f9c8ce3cSdrh  " [lindex {{0 {}} {1 {FOREIGN KEY constraint failed}}} $isError]
535e506deb2Sdan
5368e9f6aedSdan  do_test e_fkey-15.$tn.2 {
537e506deb2Sdan    execsql {
538e506deb2Sdan      SELECT * FROM chi WHERE c IS NOT NULL AND c NOT IN (SELECT p FROM par)
539e506deb2Sdan    }
540e506deb2Sdan  } {}
541e506deb2Sdan}
542e506deb2Sdan
543e506deb2Sdantest_efkey_45 1 0 "INSERT INTO chi VALUES(1)"
544e506deb2Sdantest_efkey_45 2 1 "INSERT INTO chi VALUES('1.0')"
545e506deb2Sdantest_efkey_45 3 0 "INSERT INTO chi VALUES('1')"
546e506deb2Sdantest_efkey_45 4 1 "DELETE FROM par WHERE p = '1'"
547e506deb2Sdantest_efkey_45 5 0 "DELETE FROM chi WHERE c = '1'"
548e506deb2Sdantest_efkey_45 6 0 "DELETE FROM par WHERE p = '1'"
549e506deb2Sdantest_efkey_45 7 1 "INSERT INTO chi VALUES('1')"
550e506deb2Sdantest_efkey_45 8 0 "INSERT INTO chi VALUES(X'31')"
551e506deb2Sdantest_efkey_45 9 1 "INSERT INTO chi VALUES(X'32')"
552e506deb2Sdan
553e506deb2Sdan#-------------------------------------------------------------------------
554e506deb2Sdan# Specifically, test that when comparing child and parent key values the
555e506deb2Sdan# default collation sequence of the parent key column is used.
556e506deb2Sdan#
55727298ffdSdan# EVIDENCE-OF: R-15796-47513 When comparing text values, the collating
55827298ffdSdan# sequence associated with the parent key column is always used.
55927298ffdSdan#
560e506deb2Sdandrop_all_tables
5618e9f6aedSdando_test e_fkey-16.1 {
562e506deb2Sdan  execsql {
563e506deb2Sdan    CREATE TABLE t1(a COLLATE nocase PRIMARY KEY);
564e506deb2Sdan    CREATE TABLE t2(b REFERENCES t1);
565e506deb2Sdan  }
566e506deb2Sdan} {}
5678e9f6aedSdando_test e_fkey-16.2 {
568e506deb2Sdan  execsql {
569e506deb2Sdan    INSERT INTO t1 VALUES('oNe');
570e506deb2Sdan    INSERT INTO t2 VALUES('one');
571e506deb2Sdan    INSERT INTO t2 VALUES('ONE');
572e506deb2Sdan    UPDATE t2 SET b = 'OnE';
573e506deb2Sdan    UPDATE t1 SET a = 'ONE';
574e506deb2Sdan  }
575e506deb2Sdan} {}
5768e9f6aedSdando_test e_fkey-16.3 {
577e506deb2Sdan  catchsql { UPDATE t2 SET b = 'two' WHERE rowid = 1 }
578f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
5798e9f6aedSdando_test e_fkey-16.4 {
580e506deb2Sdan  catchsql { DELETE FROM t1 WHERE rowid = 1 }
581f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
582e506deb2Sdan
583e506deb2Sdan#-------------------------------------------------------------------------
584e506deb2Sdan# Specifically, test that when comparing child and parent key values the
585e506deb2Sdan# affinity of the parent key column is applied to the child key value
586e506deb2Sdan# before the comparison takes place.
587e506deb2Sdan#
58827298ffdSdan# EVIDENCE-OF: R-04240-13860 When comparing values, if the parent key
58927298ffdSdan# column has an affinity, then that affinity is applied to the child key
59027298ffdSdan# value before the comparison is performed.
59127298ffdSdan#
592e506deb2Sdandrop_all_tables
5938e9f6aedSdando_test e_fkey-17.1 {
594e506deb2Sdan  execsql {
595e506deb2Sdan    CREATE TABLE t1(a NUMERIC PRIMARY KEY);
596e506deb2Sdan    CREATE TABLE t2(b TEXT REFERENCES t1);
597e506deb2Sdan  }
598e506deb2Sdan} {}
5998e9f6aedSdando_test e_fkey-17.2 {
600e506deb2Sdan  execsql {
601e506deb2Sdan    INSERT INTO t1 VALUES(1);
602e506deb2Sdan    INSERT INTO t1 VALUES(2);
603e506deb2Sdan    INSERT INTO t1 VALUES('three');
604e506deb2Sdan    INSERT INTO t2 VALUES('2.0');
605e506deb2Sdan    SELECT b, typeof(b) FROM t2;
606e506deb2Sdan  }
607e506deb2Sdan} {2.0 text}
6088e9f6aedSdando_test e_fkey-17.3 {
609e506deb2Sdan  execsql { SELECT typeof(a) FROM t1 }
610e506deb2Sdan} {integer integer text}
6118e9f6aedSdando_test e_fkey-17.4 {
612e506deb2Sdan  catchsql { DELETE FROM t1 WHERE rowid = 2 }
613f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
614e506deb2Sdan
6152f01f465Sdan###########################################################################
6162f01f465Sdan### SECTION 3: Required and Suggested Database Indexes
6172f01f465Sdan###########################################################################
6182f01f465Sdan
61952a48419Sdan#-------------------------------------------------------------------------
62052a48419Sdan# A parent key must be either a PRIMARY KEY, subject to a UNIQUE
62152a48419Sdan# constraint, or have a UNIQUE index created on it.
62252a48419Sdan#
62327298ffdSdan# EVIDENCE-OF: R-13435-26311 Usually, the parent key of a foreign key
62427298ffdSdan# constraint is the primary key of the parent table. If they are not the
62527298ffdSdan# primary key, then the parent key columns must be collectively subject
62627298ffdSdan# to a UNIQUE constraint or have a UNIQUE index.
62752a48419Sdan#
62852a48419Sdan# Also test that if a parent key is not subject to a PRIMARY KEY or UNIQUE
62952a48419Sdan# constraint, but does have a UNIQUE index created on it, then the UNIQUE index
63052a48419Sdan# must use the default collation sequences associated with the parent key
63152a48419Sdan# columns.
63252a48419Sdan#
63327298ffdSdan# EVIDENCE-OF: R-00376-39212 If the parent key columns have a UNIQUE
63427298ffdSdan# index, then that index must use the collation sequences that are
63527298ffdSdan# specified in the CREATE TABLE statement for the parent table.
63627298ffdSdan#
63752a48419Sdandrop_all_tables
6388e9f6aedSdando_test e_fkey-18.1 {
63952a48419Sdan  execsql {
64052a48419Sdan    CREATE TABLE t2(a REFERENCES t1(x));
64152a48419Sdan  }
64252a48419Sdan} {}
64352a48419Sdanproc test_efkey_57 {tn isError sql} {
64452a48419Sdan  catchsql { DROP TABLE t1 }
64552a48419Sdan  execsql $sql
6468e9f6aedSdan  do_test e_fkey-18.$tn {
64752a48419Sdan    catchsql { INSERT INTO t2 VALUES(NULL) }
6489148defaSdrh  } [lindex {{0 {}} {/1 {foreign key mismatch - ".*" referencing ".*"}/}} \
6499148defaSdrh     $isError]
65052a48419Sdan}
65152a48419Sdantest_efkey_57 2 0 { CREATE TABLE t1(x PRIMARY KEY) }
65252a48419Sdantest_efkey_57 3 0 { CREATE TABLE t1(x UNIQUE) }
65352a48419Sdantest_efkey_57 4 0 { CREATE TABLE t1(x); CREATE UNIQUE INDEX t1i ON t1(x) }
65452a48419Sdantest_efkey_57 5 1 {
65552a48419Sdan  CREATE TABLE t1(x);
65652a48419Sdan  CREATE UNIQUE INDEX t1i ON t1(x COLLATE nocase);
65752a48419Sdan}
65852a48419Sdantest_efkey_57 6 1 { CREATE TABLE t1(x) }
65952a48419Sdantest_efkey_57 7 1 { CREATE TABLE t1(x, y, PRIMARY KEY(x, y)) }
66052a48419Sdantest_efkey_57 8 1 { CREATE TABLE t1(x, y, UNIQUE(x, y)) }
66152a48419Sdantest_efkey_57 9 1 {
66252a48419Sdan  CREATE TABLE t1(x, y);
66352a48419Sdan  CREATE UNIQUE INDEX t1i ON t1(x, y);
66452a48419Sdan}
66552a48419Sdan
66652a48419Sdan
66752a48419Sdan#-------------------------------------------------------------------------
66852a48419Sdan# This block tests an example in foreignkeys.html. Several testable
66952a48419Sdan# statements refer to this example, as follows
67052a48419Sdan#
67127298ffdSdan# EVIDENCE-OF: R-27484-01467
67252a48419Sdan#
67352a48419Sdan# FK Constraints on child1, child2 and child3 are Ok.
67452a48419Sdan#
67527298ffdSdan# Problem with FK on child4:
67652a48419Sdan#
67727298ffdSdan# EVIDENCE-OF: R-51039-44840 The foreign key declared as part of table
67827298ffdSdan# child4 is an error because even though the parent key column is
67927298ffdSdan# indexed, the index is not UNIQUE.
68052a48419Sdan#
68127298ffdSdan# Problem with FK on child5:
68252a48419Sdan#
68327298ffdSdan# EVIDENCE-OF: R-01060-48788 The foreign key for table child5 is an
68427298ffdSdan# error because even though the parent key column has a unique index,
68527298ffdSdan# the index uses a different collating sequence.
68652a48419Sdan#
68727298ffdSdan# Problem with FK on child6 and child7:
68852a48419Sdan#
68927298ffdSdan# EVIDENCE-OF: R-63088-37469 Tables child6 and child7 are incorrect
69027298ffdSdan# because while both have UNIQUE indices on their parent keys, the keys
69127298ffdSdan# are not an exact match to the columns of a single UNIQUE index.
69252a48419Sdan#
69352a48419Sdandrop_all_tables
6948e9f6aedSdando_test e_fkey-19.1 {
69552a48419Sdan  execsql {
69652a48419Sdan    CREATE TABLE parent(a PRIMARY KEY, b UNIQUE, c, d, e, f);
69752a48419Sdan    CREATE UNIQUE INDEX i1 ON parent(c, d);
69852a48419Sdan    CREATE INDEX i2 ON parent(e);
69952a48419Sdan    CREATE UNIQUE INDEX i3 ON parent(f COLLATE nocase);
70052a48419Sdan
70152a48419Sdan    CREATE TABLE child1(f, g REFERENCES parent(a));                       -- Ok
70252a48419Sdan    CREATE TABLE child2(h, i REFERENCES parent(b));                       -- Ok
70352a48419Sdan    CREATE TABLE child3(j, k, FOREIGN KEY(j, k) REFERENCES parent(c, d)); -- Ok
70452a48419Sdan    CREATE TABLE child4(l, m REFERENCES parent(e));                       -- Err
70552a48419Sdan    CREATE TABLE child5(n, o REFERENCES parent(f));                       -- Err
70652a48419Sdan    CREATE TABLE child6(p, q, FOREIGN KEY(p,q) REFERENCES parent(b, c));  -- Err
70752a48419Sdan    CREATE TABLE child7(r REFERENCES parent(c));                          -- Err
70852a48419Sdan  }
70952a48419Sdan} {}
7108e9f6aedSdando_test e_fkey-19.2 {
71152a48419Sdan  execsql {
71252a48419Sdan    INSERT INTO parent VALUES(1, 2, 3, 4, 5, 6);
71352a48419Sdan    INSERT INTO child1 VALUES('xxx', 1);
71452a48419Sdan    INSERT INTO child2 VALUES('xxx', 2);
71552a48419Sdan    INSERT INTO child3 VALUES(3, 4);
71652a48419Sdan  }
71752a48419Sdan} {}
7188e9f6aedSdando_test e_fkey-19.2 {
71952a48419Sdan  catchsql { INSERT INTO child4 VALUES('xxx', 5) }
7209148defaSdrh} {1 {foreign key mismatch - "child4" referencing "parent"}}
7218e9f6aedSdando_test e_fkey-19.3 {
72252a48419Sdan  catchsql { INSERT INTO child5 VALUES('xxx', 6) }
7239148defaSdrh} {1 {foreign key mismatch - "child5" referencing "parent"}}
7248e9f6aedSdando_test e_fkey-19.4 {
72552a48419Sdan  catchsql { INSERT INTO child6 VALUES(2, 3) }
7269148defaSdrh} {1 {foreign key mismatch - "child6" referencing "parent"}}
7278e9f6aedSdando_test e_fkey-19.5 {
72852a48419Sdan  catchsql { INSERT INTO child7 VALUES(3) }
7299148defaSdrh} {1 {foreign key mismatch - "child7" referencing "parent"}}
73052a48419Sdan
73152a48419Sdan#-------------------------------------------------------------------------
73252a48419Sdan# Test errors in the database schema that are detected while preparing
73352a48419Sdan# DML statements. The error text for these messages always matches
73452a48419Sdan# either "foreign key mismatch" or "no such table*" (using [string match]).
73552a48419Sdan#
73627298ffdSdan# EVIDENCE-OF: R-45488-08504 If the database schema contains foreign key
73727298ffdSdan# errors that require looking at more than one table definition to
73827298ffdSdan# identify, then those errors are not detected when the tables are
73927298ffdSdan# created.
74027298ffdSdan#
74127298ffdSdan# EVIDENCE-OF: R-48391-38472 Instead, such errors prevent the
74227298ffdSdan# application from preparing SQL statements that modify the content of
74327298ffdSdan# the child or parent tables in ways that use the foreign keys.
74427298ffdSdan#
74527298ffdSdan# EVIDENCE-OF: R-03108-63659 The English language error message for
74627298ffdSdan# foreign key DML errors is usually "foreign key mismatch" but can also
74727298ffdSdan# be "no such table" if the parent table does not exist.
74827298ffdSdan#
749923260c8Sdrh# EVIDENCE-OF: R-35763-48267 Foreign key DML errors are reported if: The
750923260c8Sdrh# parent table does not exist, or The parent key columns named in the
751923260c8Sdrh# foreign key constraint do not exist, or The parent key columns named
752923260c8Sdrh# in the foreign key constraint are not the primary key of the parent
753923260c8Sdrh# table and are not subject to a unique constraint using collating
754923260c8Sdrh# sequence specified in the CREATE TABLE, or The child table references
755923260c8Sdrh# the primary key of the parent without specifying the primary key
756923260c8Sdrh# columns and the number of primary key columns in the parent do not
757923260c8Sdrh# match the number of child key columns.
75827298ffdSdan#
7598e9f6aedSdando_test e_fkey-20.1 {
76052a48419Sdan  execsql {
76152a48419Sdan    CREATE TABLE c1(c REFERENCES nosuchtable, d);
76252a48419Sdan
76352a48419Sdan    CREATE TABLE p2(a, b, UNIQUE(a, b));
76452a48419Sdan    CREATE TABLE c2(c, d, FOREIGN KEY(c, d) REFERENCES p2(a, x));
76552a48419Sdan
76652a48419Sdan    CREATE TABLE p3(a PRIMARY KEY, b);
76752a48419Sdan    CREATE TABLE c3(c REFERENCES p3(b), d);
76852a48419Sdan
76952a48419Sdan    CREATE TABLE p4(a PRIMARY KEY, b);
77052a48419Sdan    CREATE UNIQUE INDEX p4i ON p4(b COLLATE nocase);
77152a48419Sdan    CREATE TABLE c4(c REFERENCES p4(b), d);
77252a48419Sdan
77352a48419Sdan    CREATE TABLE p5(a PRIMARY KEY, b COLLATE nocase);
77452a48419Sdan    CREATE UNIQUE INDEX p5i ON p5(b COLLATE binary);
775166d9c8aSdan    CREATE TABLE c5(c REFERENCES p5(b), d);
77652a48419Sdan
77752a48419Sdan    CREATE TABLE p6(a PRIMARY KEY, b);
77852a48419Sdan    CREATE TABLE c6(c, d, FOREIGN KEY(c, d) REFERENCES p6);
77952a48419Sdan
78052a48419Sdan    CREATE TABLE p7(a, b, PRIMARY KEY(a, b));
78152a48419Sdan    CREATE TABLE c7(c, d REFERENCES p7);
78252a48419Sdan  }
78352a48419Sdan} {}
78452a48419Sdan
785166d9c8aSdanforeach {tn tbl ptbl err} {
786166d9c8aSdan  2 c1 {} "no such table: main.nosuchtable"
7879148defaSdrh  3 c2 p2 "foreign key mismatch - \"c2\" referencing \"p2\""
7889148defaSdrh  4 c3 p3 "foreign key mismatch - \"c3\" referencing \"p3\""
7899148defaSdrh  5 c4 p4 "foreign key mismatch - \"c4\" referencing \"p4\""
7909148defaSdrh  6 c5 p5 "foreign key mismatch - \"c5\" referencing \"p5\""
7919148defaSdrh  7 c6 p6 "foreign key mismatch - \"c6\" referencing \"p6\""
7929148defaSdrh  8 c7 p7 "foreign key mismatch - \"c7\" referencing \"p7\""
79352a48419Sdan} {
7948e9f6aedSdan  do_test e_fkey-20.$tn.1 {
79552a48419Sdan    catchsql "INSERT INTO $tbl VALUES('a', 'b')"
79652a48419Sdan  } [list 1 $err]
7978e9f6aedSdan  do_test e_fkey-20.$tn.2 {
798166d9c8aSdan    catchsql "UPDATE $tbl SET c = ?, d = ?"
799166d9c8aSdan  } [list 1 $err]
8008e9f6aedSdan  do_test e_fkey-20.$tn.3 {
801166d9c8aSdan    catchsql "INSERT INTO $tbl SELECT ?, ?"
802166d9c8aSdan  } [list 1 $err]
803166d9c8aSdan
804166d9c8aSdan  if {$ptbl ne ""} {
8058e9f6aedSdan    do_test e_fkey-20.$tn.4 {
806166d9c8aSdan      catchsql "DELETE FROM $ptbl"
807166d9c8aSdan    } [list 1 $err]
8088e9f6aedSdan    do_test e_fkey-20.$tn.5 {
809166d9c8aSdan      catchsql "UPDATE $ptbl SET a = ?, b = ?"
810166d9c8aSdan    } [list 1 $err]
8118e9f6aedSdan    do_test e_fkey-20.$tn.6 {
812166d9c8aSdan      catchsql "INSERT INTO $ptbl SELECT ?, ?"
813166d9c8aSdan    } [list 1 $err]
814166d9c8aSdan  }
81552a48419Sdan}
81652a48419Sdan
81752a48419Sdan#-------------------------------------------------------------------------
81827298ffdSdan# EVIDENCE-OF: R-19353-43643
81952a48419Sdan#
82052a48419Sdan# Test the example of foreign key mismatch errors caused by implicitly
82152a48419Sdan# mapping a child key to the primary key of the parent table when the
82252a48419Sdan# child key consists of a different number of columns to that primary key.
82352a48419Sdan#
82452a48419Sdandrop_all_tables
8258e9f6aedSdando_test e_fkey-21.1 {
82652a48419Sdan  execsql {
82752a48419Sdan    CREATE TABLE parent2(a, b, PRIMARY KEY(a,b));
82852a48419Sdan
82952a48419Sdan    CREATE TABLE child8(x, y, FOREIGN KEY(x,y) REFERENCES parent2);     -- Ok
83052a48419Sdan    CREATE TABLE child9(x REFERENCES parent2);                          -- Err
83152a48419Sdan    CREATE TABLE child10(x,y,z, FOREIGN KEY(x,y,z) REFERENCES parent2); -- Err
83252a48419Sdan  }
83352a48419Sdan} {}
8348e9f6aedSdando_test e_fkey-21.2 {
83552a48419Sdan  execsql {
83652a48419Sdan    INSERT INTO parent2 VALUES('I', 'II');
83752a48419Sdan    INSERT INTO child8 VALUES('I', 'II');
83852a48419Sdan  }
83952a48419Sdan} {}
8408e9f6aedSdando_test e_fkey-21.3 {
84152a48419Sdan  catchsql { INSERT INTO child9 VALUES('I') }
8429148defaSdrh} {1 {foreign key mismatch - "child9" referencing "parent2"}}
8438e9f6aedSdando_test e_fkey-21.4 {
84452a48419Sdan  catchsql { INSERT INTO child9 VALUES('II') }
8459148defaSdrh} {1 {foreign key mismatch - "child9" referencing "parent2"}}
8468e9f6aedSdando_test e_fkey-21.5 {
84752a48419Sdan  catchsql { INSERT INTO child9 VALUES(NULL) }
8489148defaSdrh} {1 {foreign key mismatch - "child9" referencing "parent2"}}
8498e9f6aedSdando_test e_fkey-21.6 {
85052a48419Sdan  catchsql { INSERT INTO child10 VALUES('I', 'II', 'III') }
8519148defaSdrh} {1 {foreign key mismatch - "child10" referencing "parent2"}}
8528e9f6aedSdando_test e_fkey-21.7 {
85352a48419Sdan  catchsql { INSERT INTO child10 VALUES(1, 2, 3) }
8549148defaSdrh} {1 {foreign key mismatch - "child10" referencing "parent2"}}
8558e9f6aedSdando_test e_fkey-21.8 {
85652a48419Sdan  catchsql { INSERT INTO child10 VALUES(NULL, NULL, NULL) }
8579148defaSdrh} {1 {foreign key mismatch - "child10" referencing "parent2"}}
85852a48419Sdan
85952a48419Sdan#-------------------------------------------------------------------------
86052a48419Sdan# Test errors that are reported when creating the child table.
86152a48419Sdan# Specifically:
86252a48419Sdan#
86352a48419Sdan#   * different number of child and parent key columns, and
86452a48419Sdan#   * child columns that do not exist.
86552a48419Sdan#
86627298ffdSdan# EVIDENCE-OF: R-23682-59820 By contrast, if foreign key errors can be
86727298ffdSdan# recognized simply by looking at the definition of the child table and
86827298ffdSdan# without having to consult the parent table definition, then the CREATE
86927298ffdSdan# TABLE statement for the child table fails.
87052a48419Sdan#
87152a48419Sdan# These errors are reported whether or not FK support is enabled.
87252a48419Sdan#
87327298ffdSdan# EVIDENCE-OF: R-33883-28833 Foreign key DDL errors are reported
87427298ffdSdan# regardless of whether or not foreign key constraints are enabled when
87527298ffdSdan# the table is created.
87627298ffdSdan#
87752a48419Sdandrop_all_tables
87852a48419Sdanforeach fk [list OFF ON] {
87952a48419Sdan  execsql "PRAGMA foreign_keys = $fk"
88052a48419Sdan  set i 0
88152a48419Sdan  foreach {sql error} {
88252a48419Sdan    "CREATE TABLE child1(a, b, FOREIGN KEY(a, b) REFERENCES p(c))"
88352a48419Sdan      {number of columns in foreign key does not match the number of columns in the referenced table}
88452a48419Sdan    "CREATE TABLE child2(a, b, FOREIGN KEY(a, b) REFERENCES p(c, d, e))"
88552a48419Sdan      {number of columns in foreign key does not match the number of columns in the referenced table}
88652a48419Sdan    "CREATE TABLE child2(a, b, FOREIGN KEY(a, c) REFERENCES p(c, d))"
88752a48419Sdan      {unknown column "c" in foreign key definition}
88852a48419Sdan    "CREATE TABLE child2(a, b, FOREIGN KEY(c, b) REFERENCES p(c, d))"
88952a48419Sdan      {unknown column "c" in foreign key definition}
89052a48419Sdan  } {
8918e9f6aedSdan    do_test e_fkey-22.$fk.[incr i] {
89252a48419Sdan      catchsql $sql
89352a48419Sdan    } [list 1 $error]
89452a48419Sdan  }
89552a48419Sdan}
89652a48419Sdan
89752a48419Sdan#-------------------------------------------------------------------------
89852a48419Sdan# Test that a REFERENCING clause that does not specify parent key columns
89952a48419Sdan# implicitly maps to the primary key of the parent table.
90052a48419Sdan#
9019ede952aSdrh# EVIDENCE-OF: R-43879-08025 Attaching a "REFERENCES <parent-table>"
9029ede952aSdrh# clause to a column definition creates a foreign
903bf3e3a06Sdan# key constraint that maps the column to the primary key of
9049ede952aSdrh# <parent-table>.
905bf3e3a06Sdan#
9068e9f6aedSdando_test e_fkey-23.1 {
90752a48419Sdan  execsql {
90852a48419Sdan    CREATE TABLE p1(a, b, PRIMARY KEY(a, b));
90952a48419Sdan    CREATE TABLE p2(a, b PRIMARY KEY);
91052a48419Sdan    CREATE TABLE c1(c, d, FOREIGN KEY(c, d) REFERENCES p1);
91152a48419Sdan    CREATE TABLE c2(a, b REFERENCES p2);
91252a48419Sdan  }
91352a48419Sdan} {}
91452a48419Sdanproc test_efkey_60 {tn isError sql} {
9158e9f6aedSdan  do_test e_fkey-23.$tn "
91652a48419Sdan    catchsql {$sql}
917f9c8ce3cSdrh  " [lindex {{0 {}} {1 {FOREIGN KEY constraint failed}}} $isError]
91852a48419Sdan}
91952a48419Sdan
92052a48419Sdantest_efkey_60 2 1 "INSERT INTO c1 VALUES(239, 231)"
92152a48419Sdantest_efkey_60 3 0 "INSERT INTO p1 VALUES(239, 231)"
92252a48419Sdantest_efkey_60 4 0 "INSERT INTO c1 VALUES(239, 231)"
92352a48419Sdantest_efkey_60 5 1 "INSERT INTO c2 VALUES(239, 231)"
92452a48419Sdantest_efkey_60 6 0 "INSERT INTO p2 VALUES(239, 231)"
92552a48419Sdantest_efkey_60 7 0 "INSERT INTO c2 VALUES(239, 231)"
92652a48419Sdan
927166d9c8aSdan#-------------------------------------------------------------------------
928166d9c8aSdan# Test that an index on on the child key columns of an FK constraint
929166d9c8aSdan# is optional.
930166d9c8aSdan#
93127298ffdSdan# EVIDENCE-OF: R-15417-28014 Indices are not required for child key
93227298ffdSdan# columns
93327298ffdSdan#
934166d9c8aSdan# Also test that if an index is created on the child key columns, it does
935166d9c8aSdan# not make a difference whether or not it is a UNIQUE index.
936166d9c8aSdan#
937bf3e3a06Sdan# EVIDENCE-OF: R-15741-50893 The child key index does not have to be
938bf3e3a06Sdan# (and usually will not be) a UNIQUE index.
939bf3e3a06Sdan#
940166d9c8aSdandrop_all_tables
9418e9f6aedSdando_test e_fkey-24.1 {
942166d9c8aSdan  execsql {
943166d9c8aSdan    CREATE TABLE parent(x, y, UNIQUE(y, x));
944166d9c8aSdan    CREATE TABLE c1(a, b, FOREIGN KEY(a, b) REFERENCES parent(x, y));
945166d9c8aSdan    CREATE TABLE c2(a, b, FOREIGN KEY(a, b) REFERENCES parent(x, y));
946166d9c8aSdan    CREATE TABLE c3(a, b, FOREIGN KEY(a, b) REFERENCES parent(x, y));
947166d9c8aSdan    CREATE INDEX c2i ON c2(a, b);
948166d9c8aSdan    CREATE UNIQUE INDEX c3i ON c2(b, a);
949166d9c8aSdan  }
950166d9c8aSdan} {}
951166d9c8aSdanproc test_efkey_61 {tn isError sql} {
9528e9f6aedSdan  do_test e_fkey-24.$tn "
953166d9c8aSdan    catchsql {$sql}
954f9c8ce3cSdrh  " [lindex {{0 {}} {1 {FOREIGN KEY constraint failed}}} $isError]
955166d9c8aSdan}
956166d9c8aSdanforeach {tn c} [list 2 c1 3 c2 4 c3] {
957166d9c8aSdan  test_efkey_61 $tn.1 1 "INSERT INTO $c VALUES(1, 2)"
958166d9c8aSdan  test_efkey_61 $tn.2 0 "INSERT INTO parent VALUES(1, 2)"
959166d9c8aSdan  test_efkey_61 $tn.3 0 "INSERT INTO $c VALUES(1, 2)"
960166d9c8aSdan
961166d9c8aSdan  execsql "DELETE FROM $c ; DELETE FROM parent"
962166d9c8aSdan}
963166d9c8aSdan
964166d9c8aSdan#-------------------------------------------------------------------------
96527298ffdSdan# EVIDENCE-OF: R-00279-52283
966166d9c8aSdan#
967166d9c8aSdan# Test an example showing that when a row is deleted from the parent
968166d9c8aSdan# table, the child table is queried for orphaned rows as follows:
969166d9c8aSdan#
970166d9c8aSdan#   SELECT rowid FROM track WHERE trackartist = ?
971166d9c8aSdan#
97227298ffdSdan# EVIDENCE-OF: R-23302-30956 If this SELECT returns any rows at all,
97327298ffdSdan# then SQLite concludes that deleting the row from the parent table
97427298ffdSdan# would violate the foreign key constraint and returns an error.
975166d9c8aSdan#
9768e9f6aedSdando_test e_fkey-25.1 {
977166d9c8aSdan  execsql {
978166d9c8aSdan    CREATE TABLE artist(
979166d9c8aSdan      artistid    INTEGER PRIMARY KEY,
980166d9c8aSdan      artistname  TEXT
981166d9c8aSdan    );
982166d9c8aSdan    CREATE TABLE track(
983166d9c8aSdan      trackid     INTEGER,
984166d9c8aSdan      trackname   TEXT,
985166d9c8aSdan      trackartist INTEGER,
986166d9c8aSdan      FOREIGN KEY(trackartist) REFERENCES artist(artistid)
987166d9c8aSdan    );
988166d9c8aSdan  }
989166d9c8aSdan} {}
990d3e17ffbSdando_detail_test e_fkey-25.2 {
991166d9c8aSdan  PRAGMA foreign_keys = OFF;
992166d9c8aSdan  EXPLAIN QUERY PLAN DELETE FROM artist WHERE 1;
993166d9c8aSdan  EXPLAIN QUERY PLAN SELECT rowid FROM track WHERE trackartist = ?;
99447eb16d4Sdan} {
9958210233cSdrh  {SCAN artist}
9968210233cSdrh  {SCAN track}
997166d9c8aSdan}
998d3e17ffbSdando_detail_test e_fkey-25.3 {
999166d9c8aSdan  PRAGMA foreign_keys = ON;
1000166d9c8aSdan  EXPLAIN QUERY PLAN DELETE FROM artist WHERE 1;
100147eb16d4Sdan} {
10028210233cSdrh  {SCAN artist}
10038210233cSdrh  {SCAN track}
1004166d9c8aSdan}
10058e9f6aedSdando_test e_fkey-25.4 {
1006166d9c8aSdan  execsql {
1007166d9c8aSdan    INSERT INTO artist VALUES(5, 'artist 5');
1008166d9c8aSdan    INSERT INTO artist VALUES(6, 'artist 6');
1009166d9c8aSdan    INSERT INTO artist VALUES(7, 'artist 7');
1010166d9c8aSdan    INSERT INTO track VALUES(1, 'track 1', 5);
1011166d9c8aSdan    INSERT INTO track VALUES(2, 'track 2', 6);
1012166d9c8aSdan  }
1013166d9c8aSdan} {}
1014166d9c8aSdan
10158e9f6aedSdando_test e_fkey-25.5 {
1016166d9c8aSdan  concat \
1017166d9c8aSdan    [execsql { SELECT rowid FROM track WHERE trackartist = 5 }]   \
1018166d9c8aSdan    [catchsql { DELETE FROM artist WHERE artistid = 5 }]
1019f9c8ce3cSdrh} {1 1 {FOREIGN KEY constraint failed}}
1020166d9c8aSdan
10218e9f6aedSdando_test e_fkey-25.6 {
1022166d9c8aSdan  concat \
1023166d9c8aSdan    [execsql { SELECT rowid FROM track WHERE trackartist = 7 }]   \
1024166d9c8aSdan    [catchsql { DELETE FROM artist WHERE artistid = 7 }]
1025166d9c8aSdan} {0 {}}
1026166d9c8aSdan
10278e9f6aedSdando_test e_fkey-25.7 {
1028166d9c8aSdan  concat \
1029166d9c8aSdan    [execsql { SELECT rowid FROM track WHERE trackartist = 6 }]   \
1030166d9c8aSdan    [catchsql { DELETE FROM artist WHERE artistid = 6 }]
1031f9c8ce3cSdrh} {2 1 {FOREIGN KEY constraint failed}}
1032166d9c8aSdan
1033166d9c8aSdan#-------------------------------------------------------------------------
10349ede952aSdrh# EVIDENCE-OF: R-47936-10044 Or, more generally:
10359ede952aSdrh# SELECT rowid FROM <child-table> WHERE <child-key> = :parent_key_value
1036166d9c8aSdan#
1037166d9c8aSdan# Test that when a row is deleted from the parent table of an FK
1038166d9c8aSdan# constraint, the child table is queried for orphaned rows. The
1039166d9c8aSdan# query is equivalent to:
1040166d9c8aSdan#
1041166d9c8aSdan#   SELECT rowid FROM <child-table> WHERE <child-key> = :parent_key_value
1042166d9c8aSdan#
1043166d9c8aSdan# Also test that when a row is inserted into the parent table, or when the
1044166d9c8aSdan# parent key values of an existing row are modified, a query equivalent
1045166d9c8aSdan# to the following is planned. In some cases it is not executed, but it
1046166d9c8aSdan# is always planned.
1047166d9c8aSdan#
1048166d9c8aSdan#   SELECT rowid FROM <child-table> WHERE <child-key> = :parent_key_value
1049166d9c8aSdan#
105027298ffdSdan# EVIDENCE-OF: R-61616-46700 Similar queries may be run if the content
105127298ffdSdan# of the parent key is modified or a new row is inserted into the parent
105227298ffdSdan# table.
105327298ffdSdan#
1054166d9c8aSdan#
1055166d9c8aSdandrop_all_tables
10568e9f6aedSdando_test e_fkey-26.1 {
1057166d9c8aSdan  execsql { CREATE TABLE parent(x, y, UNIQUE(y, x)) }
1058166d9c8aSdan} {}
1059166d9c8aSdanforeach {tn sql} {
1060166d9c8aSdan  2 {
1061166d9c8aSdan    CREATE TABLE child(a, b, FOREIGN KEY(a, b) REFERENCES parent(x, y))
1062166d9c8aSdan  }
1063166d9c8aSdan  3 {
1064166d9c8aSdan    CREATE TABLE child(a, b, FOREIGN KEY(a, b) REFERENCES parent(x, y));
1065166d9c8aSdan    CREATE INDEX childi ON child(a, b);
1066166d9c8aSdan  }
1067166d9c8aSdan  4 {
1068166d9c8aSdan    CREATE TABLE child(a, b, FOREIGN KEY(a, b) REFERENCES parent(x, y));
1069166d9c8aSdan    CREATE UNIQUE INDEX childi ON child(b, a);
1070166d9c8aSdan  }
1071166d9c8aSdan} {
1072166d9c8aSdan  execsql $sql
1073166d9c8aSdan
1074166d9c8aSdan  execsql {PRAGMA foreign_keys = OFF}
1075166d9c8aSdan  set delete [concat \
1076166d9c8aSdan      [eqp "DELETE FROM parent WHERE 1"] \
1077166d9c8aSdan      [eqp "SELECT rowid FROM child WHERE a = ? AND b = ?"]
1078166d9c8aSdan  ]
1079166d9c8aSdan  set update [concat \
1080166d9c8aSdan      [eqp "UPDATE parent SET x=?, y=?"] \
1081166d9c8aSdan      [eqp "SELECT rowid FROM child WHERE a = ? AND b = ?"] \
1082166d9c8aSdan      [eqp "SELECT rowid FROM child WHERE a = ? AND b = ?"]
1083166d9c8aSdan  ]
1084166d9c8aSdan  execsql {PRAGMA foreign_keys = ON}
1085166d9c8aSdan
10868e9f6aedSdan  do_test e_fkey-26.$tn.1 { eqp "DELETE FROM parent WHERE 1" } $delete
10878e9f6aedSdan  do_test e_fkey-26.$tn.2 { eqp "UPDATE parent set x=?, y=?" } $update
1088166d9c8aSdan
1089166d9c8aSdan  execsql {DROP TABLE child}
1090166d9c8aSdan}
1091166d9c8aSdan
1092166d9c8aSdan#-------------------------------------------------------------------------
1093bf3e3a06Sdan# EVIDENCE-OF: R-14553-34013
1094166d9c8aSdan#
1095166d9c8aSdan# Test the example schema at the end of section 3. Also test that is
1096166d9c8aSdan# is "efficient". In this case "efficient" means that foreign key
1097166d9c8aSdan# related operations on the parent table do not provoke linear scans.
1098166d9c8aSdan#
1099166d9c8aSdandrop_all_tables
11008e9f6aedSdando_test e_fkey-27.1 {
1101166d9c8aSdan  execsql {
1102166d9c8aSdan    CREATE TABLE artist(
1103166d9c8aSdan      artistid    INTEGER PRIMARY KEY,
1104166d9c8aSdan      artistname  TEXT
1105166d9c8aSdan    );
1106166d9c8aSdan    CREATE TABLE track(
1107166d9c8aSdan      trackid     INTEGER,
1108166d9c8aSdan      trackname   TEXT,
1109166d9c8aSdan      trackartist INTEGER REFERENCES artist
1110166d9c8aSdan    );
1111166d9c8aSdan    CREATE INDEX trackindex ON track(trackartist);
1112166d9c8aSdan  }
1113166d9c8aSdan} {}
11148e9f6aedSdando_test e_fkey-27.2 {
1115166d9c8aSdan  eqp { INSERT INTO artist VALUES(?, ?) }
1116166d9c8aSdan} {}
1117d3e17ffbSdando_detail_test e_fkey-27.3 {
111847eb16d4Sdan  EXPLAIN QUERY PLAN UPDATE artist SET artistid = ?, artistname = ?
111947eb16d4Sdan} {
11208210233cSdrh  {SCAN artist}
11218210233cSdrh  {SEARCH track USING COVERING INDEX trackindex (trackartist=?)}
11228210233cSdrh  {SEARCH track USING COVERING INDEX trackindex (trackartist=?)}
112347eb16d4Sdan}
1124d3e17ffbSdando_detail_test e_fkey-27.4 {
112547eb16d4Sdan  EXPLAIN QUERY PLAN DELETE FROM artist
112647eb16d4Sdan} {
11278210233cSdrh  {SCAN artist}
11288210233cSdrh  {SEARCH track USING COVERING INDEX trackindex (trackartist=?)}
112947eb16d4Sdan}
1130166d9c8aSdan
11312f01f465Sdan###########################################################################
11322f01f465Sdan### SECTION 4.1: Composite Foreign Key Constraints
11332f01f465Sdan###########################################################################
11342f01f465Sdan
1135e506deb2Sdan#-------------------------------------------------------------------------
1136166d9c8aSdan# Check that parent and child keys must have the same number of columns.
1137166d9c8aSdan#
1138bf3e3a06Sdan# EVIDENCE-OF: R-41062-34431 Parent and child keys must have the same
1139bf3e3a06Sdan# cardinality.
1140bf3e3a06Sdan#
1141166d9c8aSdanforeach {tn sql err} {
1142166d9c8aSdan  1 "CREATE TABLE c(jj REFERENCES p(x, y))"
1143166d9c8aSdan    {foreign key on jj should reference only one column of table p}
1144166d9c8aSdan
1145166d9c8aSdan  2 "CREATE TABLE c(jj REFERENCES p())" {near ")": syntax error}
1146166d9c8aSdan
1147166d9c8aSdan  3 "CREATE TABLE c(jj, FOREIGN KEY(jj) REFERENCES p(x, y))"
1148166d9c8aSdan    {number of columns in foreign key does not match the number of columns in the referenced table}
1149166d9c8aSdan
1150166d9c8aSdan  4 "CREATE TABLE c(jj, FOREIGN KEY(jj) REFERENCES p())"
1151166d9c8aSdan    {near ")": syntax error}
1152166d9c8aSdan
1153166d9c8aSdan  5 "CREATE TABLE c(ii, jj, FOREIGN KEY(jj, ii) REFERENCES p())"
1154166d9c8aSdan    {near ")": syntax error}
1155166d9c8aSdan
1156166d9c8aSdan  6 "CREATE TABLE c(ii, jj, FOREIGN KEY(jj, ii) REFERENCES p(x))"
1157166d9c8aSdan    {number of columns in foreign key does not match the number of columns in the referenced table}
1158166d9c8aSdan
1159166d9c8aSdan  7 "CREATE TABLE c(ii, jj, FOREIGN KEY(jj, ii) REFERENCES p(x,y,z))"
1160166d9c8aSdan    {number of columns in foreign key does not match the number of columns in the referenced table}
1161166d9c8aSdan} {
1162166d9c8aSdan  drop_all_tables
11638e9f6aedSdan  do_test e_fkey-28.$tn [list catchsql $sql] [list 1 $err]
1164166d9c8aSdan}
11658e9f6aedSdando_test e_fkey-28.8 {
1166166d9c8aSdan  drop_all_tables
1167166d9c8aSdan  execsql {
1168166d9c8aSdan    CREATE TABLE p(x PRIMARY KEY);
1169166d9c8aSdan    CREATE TABLE c(a, b, FOREIGN KEY(a,b) REFERENCES p);
1170166d9c8aSdan  }
1171166d9c8aSdan  catchsql {DELETE FROM p}
11729148defaSdrh} {1 {foreign key mismatch - "c" referencing "p"}}
11738e9f6aedSdando_test e_fkey-28.9 {
1174166d9c8aSdan  drop_all_tables
1175166d9c8aSdan  execsql {
1176166d9c8aSdan    CREATE TABLE p(x, y, PRIMARY KEY(x,y));
1177166d9c8aSdan    CREATE TABLE c(a REFERENCES p);
1178166d9c8aSdan  }
1179166d9c8aSdan  catchsql {DELETE FROM p}
11809148defaSdrh} {1 {foreign key mismatch - "c" referencing "p"}}
1181166d9c8aSdan
1182166d9c8aSdan
1183166d9c8aSdan#-------------------------------------------------------------------------
1184bf3e3a06Sdan# EVIDENCE-OF: R-24676-09859
1185e506deb2Sdan#
1186e506deb2Sdan# Test the example schema in the "Composite Foreign Key Constraints"
1187e506deb2Sdan# section.
1188e506deb2Sdan#
11898e9f6aedSdando_test e_fkey-29.1 {
1190e506deb2Sdan  execsql {
1191e506deb2Sdan    CREATE TABLE album(
1192e506deb2Sdan      albumartist TEXT,
1193e506deb2Sdan      albumname TEXT,
1194e506deb2Sdan      albumcover BINARY,
1195e506deb2Sdan      PRIMARY KEY(albumartist, albumname)
1196e506deb2Sdan    );
1197e506deb2Sdan    CREATE TABLE song(
1198e506deb2Sdan      songid INTEGER,
1199e506deb2Sdan      songartist TEXT,
1200e506deb2Sdan      songalbum TEXT,
1201e506deb2Sdan      songname TEXT,
1202e506deb2Sdan      FOREIGN KEY(songartist, songalbum) REFERENCES album(albumartist,albumname)
1203e506deb2Sdan    );
1204e506deb2Sdan  }
1205e506deb2Sdan} {}
1206e506deb2Sdan
12078e9f6aedSdando_test e_fkey-29.2 {
1208e506deb2Sdan  execsql {
1209e506deb2Sdan    INSERT INTO album VALUES('Elvis Presley', 'Elvis'' Christmas Album', NULL);
1210e506deb2Sdan    INSERT INTO song VALUES(
1211e506deb2Sdan      1, 'Elvis Presley', 'Elvis'' Christmas Album', 'Here Comes Santa Clause'
1212e506deb2Sdan    );
1213e506deb2Sdan  }
1214e506deb2Sdan} {}
12158e9f6aedSdando_test e_fkey-29.3 {
1216e506deb2Sdan  catchsql {
1217e506deb2Sdan    INSERT INTO song VALUES(2, 'Elvis Presley', 'Elvis Is Back!', 'Fever');
1218e506deb2Sdan  }
1219f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
1220e506deb2Sdan
1221166d9c8aSdan
1222e506deb2Sdan#-------------------------------------------------------------------------
1223bf3e3a06Sdan# EVIDENCE-OF: R-33626-48418 In SQLite, if any of the child key columns
1224bf3e3a06Sdan# (in this case songartist and songalbum) are NULL, then there is no
1225bf3e3a06Sdan# requirement for a corresponding row in the parent table.
1226e506deb2Sdan#
12278e9f6aedSdando_test e_fkey-30.1 {
1228e506deb2Sdan  execsql {
1229e506deb2Sdan    INSERT INTO song VALUES(2, 'Elvis Presley', NULL, 'Fever');
1230e506deb2Sdan    INSERT INTO song VALUES(3, NULL, 'Elvis Is Back', 'Soldier Boy');
1231e506deb2Sdan  }
1232e506deb2Sdan} {}
1233e506deb2Sdan
12342f01f465Sdan###########################################################################
12352f01f465Sdan### SECTION 4.2: Deferred Foreign Key Constraints
12362f01f465Sdan###########################################################################
12372f01f465Sdan
12382f01f465Sdan#-------------------------------------------------------------------------
12392f01f465Sdan# Test that if a statement violates an immediate FK constraint, and the
12402f01f465Sdan# database does not satisfy the FK constraint once all effects of the
12412f01f465Sdan# statement have been applied, an error is reported and the effects of
12422f01f465Sdan# the statement rolled back.
12432f01f465Sdan#
1244bf3e3a06Sdan# EVIDENCE-OF: R-09323-30470 If a statement modifies the contents of the
1245bf3e3a06Sdan# database so that an immediate foreign key constraint is in violation
1246bf3e3a06Sdan# at the conclusion the statement, an exception is thrown and the
1247bf3e3a06Sdan# effects of the statement are reverted.
1248bf3e3a06Sdan#
12492f01f465Sdandrop_all_tables
12508e9f6aedSdando_test e_fkey-31.1 {
12512f01f465Sdan  execsql {
12522f01f465Sdan    CREATE TABLE king(a, b, PRIMARY KEY(a));
12532f01f465Sdan    CREATE TABLE prince(c REFERENCES king, d);
12542f01f465Sdan  }
12552f01f465Sdan} {}
12562f01f465Sdan
12578e9f6aedSdando_test e_fkey-31.2 {
12582f01f465Sdan  # Execute a statement that violates the immediate FK constraint.
12592f01f465Sdan  catchsql { INSERT INTO prince VALUES(1, 2) }
1260f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
12612f01f465Sdan
12628e9f6aedSdando_test e_fkey-31.3 {
12632f01f465Sdan  # This time, use a trigger to fix the constraint violation before the
12642f01f465Sdan  # statement has finished executing. Then execute the same statement as
12652f01f465Sdan  # in the previous test case. This time, no error.
12662f01f465Sdan  execsql {
12672f01f465Sdan    CREATE TRIGGER kt AFTER INSERT ON prince WHEN
12682f01f465Sdan      NOT EXISTS (SELECT a FROM king WHERE a = new.c)
12692f01f465Sdan    BEGIN
12702f01f465Sdan      INSERT INTO king VALUES(new.c, NULL);
12712f01f465Sdan    END
12722f01f465Sdan  }
12732f01f465Sdan  execsql { INSERT INTO prince VALUES(1, 2) }
12742f01f465Sdan} {}
12752f01f465Sdan
12762f01f465Sdan# Test that operating inside a transaction makes no difference to
12772f01f465Sdan# immediate constraint violation handling.
12788e9f6aedSdando_test e_fkey-31.4 {
12792f01f465Sdan  execsql {
12802f01f465Sdan    BEGIN;
12812f01f465Sdan    INSERT INTO prince VALUES(2, 3);
12822f01f465Sdan    DROP TRIGGER kt;
12832f01f465Sdan  }
12842f01f465Sdan  catchsql { INSERT INTO prince VALUES(3, 4) }
1285f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
12868e9f6aedSdando_test e_fkey-31.5 {
12872f01f465Sdan  execsql {
12882f01f465Sdan    COMMIT;
12892f01f465Sdan    SELECT * FROM king;
12902f01f465Sdan  }
12912f01f465Sdan} {1 {} 2 {}}
12922f01f465Sdan
12932f01f465Sdan#-------------------------------------------------------------------------
12942f01f465Sdan# Test that if a deferred constraint is violated within a transaction,
12952f01f465Sdan# nothing happens immediately and the database is allowed to persist
12962f01f465Sdan# in a state that does not satisfy the FK constraint. However attempts
12972f01f465Sdan# to COMMIT the transaction fail until the FK constraint is satisfied.
12982f01f465Sdan#
1299bf3e3a06Sdan# EVIDENCE-OF: R-49178-21358 By contrast, if a statement modifies the
1300bf3e3a06Sdan# contents of the database such that a deferred foreign key constraint
1301bf3e3a06Sdan# is violated, the violation is not reported immediately.
1302bf3e3a06Sdan#
1303bf3e3a06Sdan# EVIDENCE-OF: R-39692-12488 Deferred foreign key constraints are not
1304bf3e3a06Sdan# checked until the transaction tries to COMMIT.
1305bf3e3a06Sdan#
1306bf3e3a06Sdan# EVIDENCE-OF: R-55147-47664 For as long as the user has an open
1307bf3e3a06Sdan# transaction, the database is allowed to exist in a state that violates
1308bf3e3a06Sdan# any number of deferred foreign key constraints.
1309bf3e3a06Sdan#
1310bf3e3a06Sdan# EVIDENCE-OF: R-29604-30395 However, COMMIT will fail as long as
1311bf3e3a06Sdan# foreign key constraints remain in violation.
1312bf3e3a06Sdan#
13132f01f465Sdanproc test_efkey_34 {tn isError sql} {
13148e9f6aedSdan  do_test e_fkey-32.$tn "
13152f01f465Sdan    catchsql {$sql}
1316f9c8ce3cSdrh  " [lindex {{0 {}} {1 {FOREIGN KEY constraint failed}}} $isError]
13172f01f465Sdan}
13182f01f465Sdandrop_all_tables
13192f01f465Sdan
13202f01f465Sdantest_efkey_34  1 0 {
13212f01f465Sdan  CREATE TABLE ll(k PRIMARY KEY);
13222f01f465Sdan  CREATE TABLE kk(c REFERENCES ll DEFERRABLE INITIALLY DEFERRED);
13232f01f465Sdan}
13242f01f465Sdantest_efkey_34  2 0 "BEGIN"
13252f01f465Sdantest_efkey_34  3 0   "INSERT INTO kk VALUES(5)"
13262f01f465Sdantest_efkey_34  4 0   "INSERT INTO kk VALUES(10)"
13272f01f465Sdantest_efkey_34  5 1 "COMMIT"
13282f01f465Sdantest_efkey_34  6 0   "INSERT INTO ll VALUES(10)"
13292f01f465Sdantest_efkey_34  7 1 "COMMIT"
13302f01f465Sdantest_efkey_34  8 0   "INSERT INTO ll VALUES(5)"
13312f01f465Sdantest_efkey_34  9 0 "COMMIT"
13322f01f465Sdan
13332f01f465Sdan#-------------------------------------------------------------------------
13342f01f465Sdan# When not running inside a transaction, a deferred constraint is similar
13352f01f465Sdan# to an immediate constraint (violations are reported immediately).
13362f01f465Sdan#
1337bf3e3a06Sdan# EVIDENCE-OF: R-56844-61705 If the current statement is not inside an
1338bf3e3a06Sdan# explicit transaction (a BEGIN/COMMIT/ROLLBACK block), then an implicit
1339bf3e3a06Sdan# transaction is committed as soon as the statement has finished
1340bf3e3a06Sdan# executing. In this case deferred constraints behave the same as
1341bf3e3a06Sdan# immediate constraints.
1342bf3e3a06Sdan#
13432f01f465Sdandrop_all_tables
13442f01f465Sdanproc test_efkey_35 {tn isError sql} {
13458e9f6aedSdan  do_test e_fkey-33.$tn "
13462f01f465Sdan    catchsql {$sql}
1347f9c8ce3cSdrh  " [lindex {{0 {}} {1 {FOREIGN KEY constraint failed}}} $isError]
13482f01f465Sdan}
13498e9f6aedSdando_test e_fkey-33.1 {
13502f01f465Sdan  execsql {
13512f01f465Sdan    CREATE TABLE parent(x, y);
13522f01f465Sdan    CREATE UNIQUE INDEX pi ON parent(x, y);
13532f01f465Sdan    CREATE TABLE child(a, b,
13542f01f465Sdan      FOREIGN KEY(a, b) REFERENCES parent(x, y) DEFERRABLE INITIALLY DEFERRED
13552f01f465Sdan    );
13562f01f465Sdan  }
13572f01f465Sdan} {}
13582f01f465Sdantest_efkey_35 2 1 "INSERT INTO child  VALUES('x', 'y')"
13592f01f465Sdantest_efkey_35 3 0 "INSERT INTO parent VALUES('x', 'y')"
13602f01f465Sdantest_efkey_35 4 0 "INSERT INTO child  VALUES('x', 'y')"
13612f01f465Sdan
13622f01f465Sdan
13632f01f465Sdan#-------------------------------------------------------------------------
1364bf3e3a06Sdan# EVIDENCE-OF: R-12782-61841
13652f01f465Sdan#
13662f01f465Sdan# Test that an FK constraint is made deferred by adding the following
13672f01f465Sdan# to the definition:
13682f01f465Sdan#
13692f01f465Sdan#   DEFERRABLE INITIALLY DEFERRED
13702f01f465Sdan#
1371bf3e3a06Sdan# EVIDENCE-OF: R-09005-28791
13722f01f465Sdan#
13732f01f465Sdan# Also test that adding any of the following to a foreign key definition
13742f01f465Sdan# makes the constraint IMMEDIATE:
13752f01f465Sdan#
13762f01f465Sdan#   NOT DEFERRABLE INITIALLY DEFERRED
13771760024bSdan#   NOT DEFERRABLE INITIALLY IMMEDIATE
13781760024bSdan#   NOT DEFERRABLE
13792f01f465Sdan#   DEFERRABLE INITIALLY IMMEDIATE
13802f01f465Sdan#   DEFERRABLE
13812f01f465Sdan#
13822f01f465Sdan# Foreign keys are IMMEDIATE by default (if there is no DEFERRABLE or NOT
13832f01f465Sdan# DEFERRABLE clause).
13842f01f465Sdan#
1385bf3e3a06Sdan# EVIDENCE-OF: R-35290-16460 Foreign key constraints are immediate by
1386bf3e3a06Sdan# default.
1387bf3e3a06Sdan#
1388bf3e3a06Sdan# EVIDENCE-OF: R-30323-21917 Each foreign key constraint in SQLite is
1389bf3e3a06Sdan# classified as either immediate or deferred.
1390e6ab0692Sdrh#
13912f01f465Sdandrop_all_tables
13928e9f6aedSdando_test e_fkey-34.1 {
13932f01f465Sdan  execsql {
13942f01f465Sdan    CREATE TABLE parent(x, y, z, PRIMARY KEY(x,y,z));
13952f01f465Sdan    CREATE TABLE c1(a, b, c,
13962f01f465Sdan      FOREIGN KEY(a, b, c) REFERENCES parent NOT DEFERRABLE INITIALLY DEFERRED
13972f01f465Sdan    );
13982f01f465Sdan    CREATE TABLE c2(a, b, c,
13991760024bSdan      FOREIGN KEY(a, b, c) REFERENCES parent NOT DEFERRABLE INITIALLY IMMEDIATE
14002f01f465Sdan    );
14012f01f465Sdan    CREATE TABLE c3(a, b, c,
14021760024bSdan      FOREIGN KEY(a, b, c) REFERENCES parent NOT DEFERRABLE
14031760024bSdan    );
14041760024bSdan    CREATE TABLE c4(a, b, c,
14051760024bSdan      FOREIGN KEY(a, b, c) REFERENCES parent DEFERRABLE INITIALLY IMMEDIATE
14061760024bSdan    );
14071760024bSdan    CREATE TABLE c5(a, b, c,
14082f01f465Sdan      FOREIGN KEY(a, b, c) REFERENCES parent DEFERRABLE
14092f01f465Sdan    );
14101760024bSdan    CREATE TABLE c6(a, b, c, FOREIGN KEY(a, b, c) REFERENCES parent);
14112f01f465Sdan
14122f01f465Sdan    -- This FK constraint is the only deferrable one.
14131760024bSdan    CREATE TABLE c7(a, b, c,
14142f01f465Sdan      FOREIGN KEY(a, b, c) REFERENCES parent DEFERRABLE INITIALLY DEFERRED
14152f01f465Sdan    );
14162f01f465Sdan
14172f01f465Sdan    INSERT INTO parent VALUES('a', 'b', 'c');
14182f01f465Sdan    INSERT INTO parent VALUES('d', 'e', 'f');
14192f01f465Sdan    INSERT INTO parent VALUES('g', 'h', 'i');
14202f01f465Sdan    INSERT INTO parent VALUES('j', 'k', 'l');
14212f01f465Sdan    INSERT INTO parent VALUES('m', 'n', 'o');
14221760024bSdan    INSERT INTO parent VALUES('p', 'q', 'r');
14231760024bSdan    INSERT INTO parent VALUES('s', 't', 'u');
14242f01f465Sdan
14252f01f465Sdan    INSERT INTO c1 VALUES('a', 'b', 'c');
14262f01f465Sdan    INSERT INTO c2 VALUES('d', 'e', 'f');
14272f01f465Sdan    INSERT INTO c3 VALUES('g', 'h', 'i');
14282f01f465Sdan    INSERT INTO c4 VALUES('j', 'k', 'l');
14292f01f465Sdan    INSERT INTO c5 VALUES('m', 'n', 'o');
14301760024bSdan    INSERT INTO c6 VALUES('p', 'q', 'r');
14311760024bSdan    INSERT INTO c7 VALUES('s', 't', 'u');
14322f01f465Sdan  }
14332f01f465Sdan} {}
14342f01f465Sdan
14352f01f465Sdanproc test_efkey_29 {tn sql isError} {
14368e9f6aedSdan  do_test e_fkey-34.$tn "catchsql {$sql}" [
1437f9c8ce3cSdrh    lindex {{0 {}} {1 {FOREIGN KEY constraint failed}}} $isError
14382f01f465Sdan  ]
14392f01f465Sdan}
14402f01f465Sdantest_efkey_29  2 "BEGIN"                                   0
14412f01f465Sdantest_efkey_29  3 "DELETE FROM parent WHERE x = 'a'"        1
14422f01f465Sdantest_efkey_29  4 "DELETE FROM parent WHERE x = 'd'"        1
14432f01f465Sdantest_efkey_29  5 "DELETE FROM parent WHERE x = 'g'"        1
14442f01f465Sdantest_efkey_29  6 "DELETE FROM parent WHERE x = 'j'"        1
14451760024bSdantest_efkey_29  7 "DELETE FROM parent WHERE x = 'm'"        1
14461760024bSdantest_efkey_29  8 "DELETE FROM parent WHERE x = 'p'"        1
14471760024bSdantest_efkey_29  9 "DELETE FROM parent WHERE x = 's'"        0
14481760024bSdantest_efkey_29 10 "COMMIT"                                  1
14491760024bSdantest_efkey_29 11 "ROLLBACK"                                0
14502f01f465Sdan
14512f01f465Sdantest_efkey_29  9 "BEGIN"                                   0
14522f01f465Sdantest_efkey_29 10 "UPDATE parent SET z = 'z' WHERE z = 'c'" 1
14532f01f465Sdantest_efkey_29 11 "UPDATE parent SET z = 'z' WHERE z = 'f'" 1
14542f01f465Sdantest_efkey_29 12 "UPDATE parent SET z = 'z' WHERE z = 'i'" 1
14552f01f465Sdantest_efkey_29 13 "UPDATE parent SET z = 'z' WHERE z = 'l'" 1
14561760024bSdantest_efkey_29 14 "UPDATE parent SET z = 'z' WHERE z = 'o'" 1
14571760024bSdantest_efkey_29 15 "UPDATE parent SET z = 'z' WHERE z = 'r'" 1
14581760024bSdantest_efkey_29 16 "UPDATE parent SET z = 'z' WHERE z = 'u'" 0
14591760024bSdantest_efkey_29 17 "COMMIT"                                  1
14601760024bSdantest_efkey_29 18 "ROLLBACK"                                0
14612f01f465Sdan
14622f01f465Sdantest_efkey_29 17 "BEGIN"                                   0
14632f01f465Sdantest_efkey_29 18 "INSERT INTO c1 VALUES(1, 2, 3)"          1
14642f01f465Sdantest_efkey_29 19 "INSERT INTO c2 VALUES(1, 2, 3)"          1
14652f01f465Sdantest_efkey_29 20 "INSERT INTO c3 VALUES(1, 2, 3)"          1
14662f01f465Sdantest_efkey_29 21 "INSERT INTO c4 VALUES(1, 2, 3)"          1
14671760024bSdantest_efkey_29 22 "INSERT INTO c5 VALUES(1, 2, 3)"          1
14681760024bSdantest_efkey_29 22 "INSERT INTO c6 VALUES(1, 2, 3)"          1
14691760024bSdantest_efkey_29 22 "INSERT INTO c7 VALUES(1, 2, 3)"          0
14702f01f465Sdantest_efkey_29 23 "COMMIT"                                  1
14712f01f465Sdantest_efkey_29 24 "INSERT INTO parent VALUES(1, 2, 3)"      0
14722f01f465Sdantest_efkey_29 25 "COMMIT"                                  0
14732f01f465Sdan
14742f01f465Sdantest_efkey_29 26 "BEGIN"                                   0
14752f01f465Sdantest_efkey_29 27 "UPDATE c1 SET a = 10"                    1
14762f01f465Sdantest_efkey_29 28 "UPDATE c2 SET a = 10"                    1
14772f01f465Sdantest_efkey_29 29 "UPDATE c3 SET a = 10"                    1
14782f01f465Sdantest_efkey_29 30 "UPDATE c4 SET a = 10"                    1
14791760024bSdantest_efkey_29 31 "UPDATE c5 SET a = 10"                    1
14801760024bSdantest_efkey_29 31 "UPDATE c6 SET a = 10"                    1
14811760024bSdantest_efkey_29 31 "UPDATE c7 SET a = 10"                    0
14822f01f465Sdantest_efkey_29 32 "COMMIT"                                  1
14832f01f465Sdantest_efkey_29 33 "ROLLBACK"                                0
14842f01f465Sdan
14852f01f465Sdan#-------------------------------------------------------------------------
14869ede952aSdrh# EVIDENCE-OF: R-24499-57071
14872f01f465Sdan#
14882f01f465Sdan# Test an example from foreignkeys.html dealing with a deferred foreign
14892f01f465Sdan# key constraint.
14902f01f465Sdan#
14918e9f6aedSdando_test e_fkey-35.1 {
14922f01f465Sdan  drop_all_tables
14932f01f465Sdan  execsql {
14942f01f465Sdan    CREATE TABLE artist(
14952f01f465Sdan      artistid    INTEGER PRIMARY KEY,
14962f01f465Sdan      artistname  TEXT
14972f01f465Sdan    );
14982f01f465Sdan    CREATE TABLE track(
14992f01f465Sdan      trackid     INTEGER,
15002f01f465Sdan      trackname   TEXT,
15012f01f465Sdan      trackartist INTEGER REFERENCES artist(artistid) DEFERRABLE INITIALLY DEFERRED
15022f01f465Sdan    );
15032f01f465Sdan  }
15042f01f465Sdan} {}
15058e9f6aedSdando_test e_fkey-35.2 {
15062f01f465Sdan  execsql {
15072f01f465Sdan    BEGIN;
15082f01f465Sdan      INSERT INTO track VALUES(1, 'White Christmas', 5);
15092f01f465Sdan  }
15102f01f465Sdan  catchsql COMMIT
1511f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
15128e9f6aedSdando_test e_fkey-35.3 {
15132f01f465Sdan  execsql {
15142f01f465Sdan    INSERT INTO artist VALUES(5, 'Bing Crosby');
15152f01f465Sdan    COMMIT;
15162f01f465Sdan  }
15172f01f465Sdan} {}
15182f01f465Sdan
15192f01f465Sdan#-------------------------------------------------------------------------
15202f01f465Sdan# Verify that a nested savepoint may be released without satisfying
15212f01f465Sdan# deferred foreign key constraints.
15222f01f465Sdan#
1523bf3e3a06Sdan# EVIDENCE-OF: R-07223-48323 A nested savepoint transaction may be
1524bf3e3a06Sdan# RELEASEd while the database is in a state that does not satisfy a
1525bf3e3a06Sdan# deferred foreign key constraint.
1526bf3e3a06Sdan#
15272f01f465Sdandrop_all_tables
15288e9f6aedSdando_test e_fkey-36.1 {
15292f01f465Sdan  execsql {
15302f01f465Sdan    CREATE TABLE t1(a PRIMARY KEY,
15312f01f465Sdan      b REFERENCES t1 DEFERRABLE INITIALLY DEFERRED
15322f01f465Sdan    );
15332f01f465Sdan    INSERT INTO t1 VALUES(1, 1);
15342f01f465Sdan    INSERT INTO t1 VALUES(2, 2);
15352f01f465Sdan    INSERT INTO t1 VALUES(3, 3);
15362f01f465Sdan  }
15372f01f465Sdan} {}
15388e9f6aedSdando_test e_fkey-36.2 {
15392f01f465Sdan  execsql {
15402f01f465Sdan    BEGIN;
15412f01f465Sdan      SAVEPOINT one;
15422f01f465Sdan        INSERT INTO t1 VALUES(4, 5);
15432f01f465Sdan      RELEASE one;
15442f01f465Sdan  }
15452f01f465Sdan} {}
15468e9f6aedSdando_test e_fkey-36.3 {
15472f01f465Sdan  catchsql COMMIT
1548f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
15498e9f6aedSdando_test e_fkey-36.4 {
15502f01f465Sdan  execsql {
15512f01f465Sdan    UPDATE t1 SET a = 5 WHERE a = 4;
15522f01f465Sdan    COMMIT;
15532f01f465Sdan  }
15542f01f465Sdan} {}
15552f01f465Sdan
15562f01f465Sdan
15572f01f465Sdan#-------------------------------------------------------------------------
15582f01f465Sdan# Check that a transaction savepoint (an outermost savepoint opened when
15592f01f465Sdan# the database was in auto-commit mode) cannot be released without
15602f01f465Sdan# satisfying deferred foreign key constraints. It may be rolled back.
15612f01f465Sdan#
1562bf3e3a06Sdan# EVIDENCE-OF: R-44295-13823 A transaction savepoint (a non-nested
1563bf3e3a06Sdan# savepoint that was opened while there was not currently an open
1564bf3e3a06Sdan# transaction), on the other hand, is subject to the same restrictions
1565bf3e3a06Sdan# as a COMMIT - attempting to RELEASE it while the database is in such a
1566bf3e3a06Sdan# state will fail.
1567bf3e3a06Sdan#
15688e9f6aedSdando_test e_fkey-37.1 {
15692f01f465Sdan  execsql {
15702f01f465Sdan    SAVEPOINT one;
15712f01f465Sdan      SAVEPOINT two;
15722f01f465Sdan        INSERT INTO t1 VALUES(6, 7);
15732f01f465Sdan      RELEASE two;
15742f01f465Sdan  }
15752f01f465Sdan} {}
15768e9f6aedSdando_test e_fkey-37.2 {
15772f01f465Sdan  catchsql {RELEASE one}
1578f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
15798e9f6aedSdando_test e_fkey-37.3 {
15802f01f465Sdan  execsql {
15812f01f465Sdan      UPDATE t1 SET a = 7 WHERE a = 6;
15822f01f465Sdan    RELEASE one;
15832f01f465Sdan  }
15842f01f465Sdan} {}
15858e9f6aedSdando_test e_fkey-37.4 {
15862f01f465Sdan  execsql {
15872f01f465Sdan    SAVEPOINT one;
15882f01f465Sdan      SAVEPOINT two;
15892f01f465Sdan        INSERT INTO t1 VALUES(9, 10);
15902f01f465Sdan      RELEASE two;
15912f01f465Sdan  }
15922f01f465Sdan} {}
15938e9f6aedSdando_test e_fkey-37.5 {
15942f01f465Sdan  catchsql {RELEASE one}
1595f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
15968e9f6aedSdando_test e_fkey-37.6 {
15972f01f465Sdan  execsql {ROLLBACK TO one ; RELEASE one}
15982f01f465Sdan} {}
15992f01f465Sdan
16002f01f465Sdan#-------------------------------------------------------------------------
16012f01f465Sdan# Test that if a COMMIT operation fails due to deferred foreign key
16022f01f465Sdan# constraints, any nested savepoints remain open.
16032f01f465Sdan#
1604bf3e3a06Sdan# EVIDENCE-OF: R-37736-42616 If a COMMIT statement (or the RELEASE of a
1605bf3e3a06Sdan# transaction SAVEPOINT) fails because the database is currently in a
1606bf3e3a06Sdan# state that violates a deferred foreign key constraint and there are
1607bf3e3a06Sdan# currently nested savepoints, the nested savepoints remain open.
1608bf3e3a06Sdan#
16098e9f6aedSdando_test e_fkey-38.1 {
16102f01f465Sdan  execsql {
16112f01f465Sdan    DELETE FROM t1 WHERE a>3;
16122f01f465Sdan    SELECT * FROM t1;
16132f01f465Sdan  }
16142f01f465Sdan} {1 1 2 2 3 3}
16158e9f6aedSdando_test e_fkey-38.2 {
16162f01f465Sdan  execsql {
16172f01f465Sdan    BEGIN;
16182f01f465Sdan      INSERT INTO t1 VALUES(4, 4);
16192f01f465Sdan      SAVEPOINT one;
16202f01f465Sdan        INSERT INTO t1 VALUES(5, 6);
16212f01f465Sdan        SELECT * FROM t1;
16222f01f465Sdan  }
16232f01f465Sdan} {1 1 2 2 3 3 4 4 5 6}
16248e9f6aedSdando_test e_fkey-38.3 {
16252f01f465Sdan  catchsql COMMIT
1626f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
16278e9f6aedSdando_test e_fkey-38.4 {
16282f01f465Sdan  execsql {
16292f01f465Sdan    ROLLBACK TO one;
16302f01f465Sdan    COMMIT;
16312f01f465Sdan    SELECT * FROM t1;
16322f01f465Sdan  }
16332f01f465Sdan} {1 1 2 2 3 3 4 4}
16342f01f465Sdan
16358e9f6aedSdando_test e_fkey-38.5 {
16362f01f465Sdan  execsql {
16372f01f465Sdan    SAVEPOINT a;
16382f01f465Sdan      INSERT INTO t1 VALUES(5, 5);
16392f01f465Sdan      SAVEPOINT b;
16402f01f465Sdan        INSERT INTO t1 VALUES(6, 7);
16412f01f465Sdan        SAVEPOINT c;
16422f01f465Sdan          INSERT INTO t1 VALUES(7, 8);
16432f01f465Sdan  }
16442f01f465Sdan} {}
16458e9f6aedSdando_test e_fkey-38.6 {
16462f01f465Sdan  catchsql {RELEASE a}
1647f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
16488e9f6aedSdando_test e_fkey-38.7 {
16492f01f465Sdan  execsql  {ROLLBACK TO c}
16502f01f465Sdan  catchsql {RELEASE a}
1651f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
16528e9f6aedSdando_test e_fkey-38.8 {
16532f01f465Sdan  execsql  {
16542f01f465Sdan    ROLLBACK TO b;
16552f01f465Sdan    RELEASE a;
16562f01f465Sdan    SELECT * FROM t1;
16572f01f465Sdan  }
16582f01f465Sdan} {1 1 2 2 3 3 4 4 5 5}
16592f01f465Sdan
16602f01f465Sdan###########################################################################
16612140429cSdan### SECTION 4.3: ON DELETE and ON UPDATE Actions
16622140429cSdan###########################################################################
16632140429cSdan
1664f589450dSdan#-------------------------------------------------------------------------
16652140429cSdan# Test that configured ON DELETE and ON UPDATE actions take place when
16662140429cSdan# deleting or modifying rows of the parent table, respectively.
16672140429cSdan#
1668bf3e3a06Sdan# EVIDENCE-OF: R-48270-44282 Foreign key ON DELETE and ON UPDATE clauses
1669bf3e3a06Sdan# are used to configure actions that take place when deleting rows from
1670bf3e3a06Sdan# the parent table (ON DELETE), or modifying the parent key values of
1671bf3e3a06Sdan# existing rows (ON UPDATE).
16722140429cSdan#
16732140429cSdan# Test that a single FK constraint may have different actions configured
16742140429cSdan# for ON DELETE and ON UPDATE.
16752140429cSdan#
1676bf3e3a06Sdan# EVIDENCE-OF: R-48124-63225 A single foreign key constraint may have
1677bf3e3a06Sdan# different actions configured for ON DELETE and ON UPDATE.
1678bf3e3a06Sdan#
16798e9f6aedSdando_test e_fkey-39.1 {
16802140429cSdan  execsql {
16812140429cSdan    CREATE TABLE p(a, b PRIMARY KEY, c);
16822140429cSdan    CREATE TABLE c1(d, e, f DEFAULT 'k0' REFERENCES p
16832140429cSdan      ON UPDATE SET DEFAULT
16842140429cSdan      ON DELETE SET NULL
16852140429cSdan    );
16862140429cSdan
16872140429cSdan    INSERT INTO p VALUES(0, 'k0', '');
16882140429cSdan    INSERT INTO p VALUES(1, 'k1', 'I');
16892140429cSdan    INSERT INTO p VALUES(2, 'k2', 'II');
16902140429cSdan    INSERT INTO p VALUES(3, 'k3', 'III');
16912140429cSdan
16922140429cSdan    INSERT INTO c1 VALUES(1, 'xx', 'k1');
16932140429cSdan    INSERT INTO c1 VALUES(2, 'xx', 'k2');
16942140429cSdan    INSERT INTO c1 VALUES(3, 'xx', 'k3');
16952140429cSdan  }
16962140429cSdan} {}
16978e9f6aedSdando_test e_fkey-39.2 {
16982140429cSdan  execsql {
16992140429cSdan    UPDATE p SET b = 'k4' WHERE a = 1;
17002140429cSdan    SELECT * FROM c1;
17012140429cSdan  }
17022140429cSdan} {1 xx k0 2 xx k2 3 xx k3}
17038e9f6aedSdando_test e_fkey-39.3 {
17042140429cSdan  execsql {
17052140429cSdan    DELETE FROM p WHERE a = 2;
17062140429cSdan    SELECT * FROM c1;
17072140429cSdan  }
17082140429cSdan} {1 xx k0 2 xx {} 3 xx k3}
17098e9f6aedSdando_test e_fkey-39.4 {
17102140429cSdan  execsql {
17112140429cSdan    CREATE UNIQUE INDEX pi ON p(c);
17122140429cSdan    REPLACE INTO p VALUES(5, 'k5', 'III');
17132140429cSdan    SELECT * FROM c1;
17142140429cSdan  }
17152140429cSdan} {1 xx k0 2 xx {} 3 xx {}}
17162140429cSdan
17172140429cSdan#-------------------------------------------------------------------------
17182140429cSdan# Each foreign key in the system has an ON UPDATE and ON DELETE action,
17192140429cSdan# either "NO ACTION", "RESTRICT", "SET NULL", "SET DEFAULT" or "CASCADE".
17202140429cSdan#
1721bf3e3a06Sdan# EVIDENCE-OF: R-33326-45252 The ON DELETE and ON UPDATE action
1722bf3e3a06Sdan# associated with each foreign key in an SQLite database is one of "NO
1723bf3e3a06Sdan# ACTION", "RESTRICT", "SET NULL", "SET DEFAULT" or "CASCADE".
17242140429cSdan#
17252140429cSdan# If none is specified explicitly, "NO ACTION" is the default.
17264e7deacfSdan#
1727bf3e3a06Sdan# EVIDENCE-OF: R-19803-45884 If an action is not explicitly specified,
1728bf3e3a06Sdan# it defaults to "NO ACTION".
1729bf3e3a06Sdan#
17304e7deacfSdandrop_all_tables
17318e9f6aedSdando_test e_fkey-40.1 {
17322140429cSdan  execsql {
17332140429cSdan    CREATE TABLE parent(x PRIMARY KEY, y);
17342140429cSdan    CREATE TABLE child1(a,
17352140429cSdan      b REFERENCES parent ON UPDATE NO ACTION ON DELETE RESTRICT
17362140429cSdan    );
17372140429cSdan    CREATE TABLE child2(a,
17382140429cSdan      b REFERENCES parent ON UPDATE RESTRICT ON DELETE SET NULL
17392140429cSdan    );
17402140429cSdan    CREATE TABLE child3(a,
17412140429cSdan      b REFERENCES parent ON UPDATE SET NULL ON DELETE SET DEFAULT
17422140429cSdan    );
17432140429cSdan    CREATE TABLE child4(a,
17442140429cSdan      b REFERENCES parent ON UPDATE SET DEFAULT ON DELETE CASCADE
17452140429cSdan    );
17462140429cSdan
17472140429cSdan    -- Create some foreign keys that use the default action - "NO ACTION"
17482140429cSdan    CREATE TABLE child5(a, b REFERENCES parent ON UPDATE CASCADE);
17492140429cSdan    CREATE TABLE child6(a, b REFERENCES parent ON DELETE RESTRICT);
17502140429cSdan    CREATE TABLE child7(a, b REFERENCES parent ON DELETE NO ACTION);
17512140429cSdan    CREATE TABLE child8(a, b REFERENCES parent ON UPDATE NO ACTION);
17522140429cSdan  }
17532140429cSdan} {}
17542140429cSdan
17552140429cSdanforeach {tn zTab lRes} {
17562140429cSdan  2 child1 {0 0 parent b {} {NO ACTION} RESTRICT NONE}
17572140429cSdan  3 child2 {0 0 parent b {} RESTRICT {SET NULL} NONE}
17582140429cSdan  4 child3 {0 0 parent b {} {SET NULL} {SET DEFAULT} NONE}
17592140429cSdan  5 child4 {0 0 parent b {} {SET DEFAULT} CASCADE NONE}
17602140429cSdan  6 child5 {0 0 parent b {} CASCADE {NO ACTION} NONE}
17612140429cSdan  7 child6 {0 0 parent b {} {NO ACTION} RESTRICT NONE}
17622140429cSdan  8 child7 {0 0 parent b {} {NO ACTION} {NO ACTION} NONE}
17632140429cSdan  9 child8 {0 0 parent b {} {NO ACTION} {NO ACTION} NONE}
17642140429cSdan} {
17658e9f6aedSdan  do_test e_fkey-40.$tn { execsql "PRAGMA foreign_key_list($zTab)" } $lRes
17662140429cSdan}
17672140429cSdan
17682140429cSdan#-------------------------------------------------------------------------
17692140429cSdan# Test that "NO ACTION" means that nothing happens to a child row when
17702140429cSdan# it's parent row is updated or deleted.
17712140429cSdan#
1772bf3e3a06Sdan# EVIDENCE-OF: R-19971-54976 Configuring "NO ACTION" means just that:
1773bf3e3a06Sdan# when a parent key is modified or deleted from the database, no special
1774bf3e3a06Sdan# action is taken.
1775bf3e3a06Sdan#
17762140429cSdandrop_all_tables
17778e9f6aedSdando_test e_fkey-41.1 {
17782140429cSdan  execsql {
17792140429cSdan    CREATE TABLE parent(p1, p2, PRIMARY KEY(p1, p2));
17802140429cSdan    CREATE TABLE child(c1, c2,
17812140429cSdan      FOREIGN KEY(c1, c2) REFERENCES parent
17822140429cSdan      ON UPDATE NO ACTION
17832140429cSdan      ON DELETE NO ACTION
17842140429cSdan      DEFERRABLE INITIALLY DEFERRED
17852140429cSdan    );
17862140429cSdan    INSERT INTO parent VALUES('j', 'k');
17872140429cSdan    INSERT INTO parent VALUES('l', 'm');
17882140429cSdan    INSERT INTO child VALUES('j', 'k');
17892140429cSdan    INSERT INTO child VALUES('l', 'm');
17902140429cSdan  }
17912140429cSdan} {}
17928e9f6aedSdando_test e_fkey-41.2 {
17932140429cSdan  execsql {
17942140429cSdan    BEGIN;
17952140429cSdan      UPDATE parent SET p1='k' WHERE p1='j';
17962140429cSdan      DELETE FROM parent WHERE p1='l';
17972140429cSdan      SELECT * FROM child;
17982140429cSdan  }
17992140429cSdan} {j k l m}
18008e9f6aedSdando_test e_fkey-41.3 {
18012140429cSdan  catchsql COMMIT
1802f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
18038e9f6aedSdando_test e_fkey-41.4 {
18042140429cSdan  execsql ROLLBACK
18052140429cSdan} {}
18062140429cSdan
18072140429cSdan#-------------------------------------------------------------------------
18082140429cSdan# Test that "RESTRICT" means the application is prohibited from deleting
18092140429cSdan# or updating a parent table row when there exists one or more child keys
18102140429cSdan# mapped to it.
18112140429cSdan#
1812bf3e3a06Sdan# EVIDENCE-OF: R-04272-38653 The "RESTRICT" action means that the
1813bf3e3a06Sdan# application is prohibited from deleting (for ON DELETE RESTRICT) or
1814bf3e3a06Sdan# modifying (for ON UPDATE RESTRICT) a parent key when there exists one
1815bf3e3a06Sdan# or more child keys mapped to it.
1816bf3e3a06Sdan#
18172140429cSdandrop_all_tables
18188e9f6aedSdando_test e_fkey-41.1 {
18192140429cSdan  execsql {
18202140429cSdan    CREATE TABLE parent(p1, p2);
18212140429cSdan    CREATE UNIQUE INDEX parent_i ON parent(p1, p2);
18222140429cSdan    CREATE TABLE child1(c1, c2,
18232140429cSdan      FOREIGN KEY(c2, c1) REFERENCES parent(p1, p2) ON DELETE RESTRICT
18242140429cSdan    );
18252140429cSdan    CREATE TABLE child2(c1, c2,
18262140429cSdan      FOREIGN KEY(c2, c1) REFERENCES parent(p1, p2) ON UPDATE RESTRICT
18272140429cSdan    );
18282140429cSdan  }
18292140429cSdan} {}
18308e9f6aedSdando_test e_fkey-41.2 {
18312140429cSdan  execsql {
18322140429cSdan    INSERT INTO parent VALUES('a', 'b');
18332140429cSdan    INSERT INTO parent VALUES('c', 'd');
18342140429cSdan    INSERT INTO child1 VALUES('b', 'a');
18352140429cSdan    INSERT INTO child2 VALUES('d', 'c');
18362140429cSdan  }
18372140429cSdan} {}
18388e9f6aedSdando_test e_fkey-41.3 {
18392140429cSdan  catchsql { DELETE FROM parent WHERE p1 = 'a' }
1840f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
18418e9f6aedSdando_test e_fkey-41.4 {
18422140429cSdan  catchsql { UPDATE parent SET p2 = 'e' WHERE p1 = 'c' }
1843f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
18442140429cSdan
18452140429cSdan#-------------------------------------------------------------------------
18462140429cSdan# Test that RESTRICT is slightly different from NO ACTION for IMMEDIATE
18472140429cSdan# constraints, in that it is enforced immediately, not at the end of the
18482140429cSdan# statement.
18492140429cSdan#
1850bf3e3a06Sdan# EVIDENCE-OF: R-37997-42187 The difference between the effect of a
1851bf3e3a06Sdan# RESTRICT action and normal foreign key constraint enforcement is that
1852bf3e3a06Sdan# the RESTRICT action processing happens as soon as the field is updated
1853bf3e3a06Sdan# - not at the end of the current statement as it would with an
1854bf3e3a06Sdan# immediate constraint, or at the end of the current transaction as it
1855bf3e3a06Sdan# would with a deferred constraint.
1856bf3e3a06Sdan#
18572140429cSdandrop_all_tables
18588e9f6aedSdando_test e_fkey-42.1 {
18594e7deacfSdan  execsql {
18604e7deacfSdan    CREATE TABLE parent(x PRIMARY KEY);
18612140429cSdan    CREATE TABLE child1(c REFERENCES parent ON UPDATE RESTRICT);
18622140429cSdan    CREATE TABLE child2(c REFERENCES parent ON UPDATE NO ACTION);
18632140429cSdan
18642140429cSdan    INSERT INTO parent VALUES('key1');
18652140429cSdan    INSERT INTO parent VALUES('key2');
18662140429cSdan    INSERT INTO child1 VALUES('key1');
18672140429cSdan    INSERT INTO child2 VALUES('key2');
18682140429cSdan
18692140429cSdan    CREATE TRIGGER parent_t AFTER UPDATE ON parent BEGIN
18702140429cSdan      UPDATE child1 set c = new.x WHERE c = old.x;
18712140429cSdan      UPDATE child2 set c = new.x WHERE c = old.x;
18722140429cSdan    END;
18734e7deacfSdan  }
18744e7deacfSdan} {}
18758e9f6aedSdando_test e_fkey-42.2 {
18762140429cSdan  catchsql { UPDATE parent SET x = 'key one' WHERE x = 'key1' }
1877f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
18788e9f6aedSdando_test e_fkey-42.3 {
18794e7deacfSdan  execsql {
18802140429cSdan    UPDATE parent SET x = 'key two' WHERE x = 'key2';
18812140429cSdan    SELECT * FROM child2;
18824e7deacfSdan  }
18832140429cSdan} {{key two}}
18842140429cSdan
18852140429cSdandrop_all_tables
18868e9f6aedSdando_test e_fkey-42.4 {
18874e7deacfSdan  execsql {
18882140429cSdan    CREATE TABLE parent(x PRIMARY KEY);
18892140429cSdan    CREATE TABLE child1(c REFERENCES parent ON DELETE RESTRICT);
18902140429cSdan    CREATE TABLE child2(c REFERENCES parent ON DELETE NO ACTION);
18912140429cSdan
18922140429cSdan    INSERT INTO parent VALUES('key1');
18932140429cSdan    INSERT INTO parent VALUES('key2');
18942140429cSdan    INSERT INTO child1 VALUES('key1');
18952140429cSdan    INSERT INTO child2 VALUES('key2');
18962140429cSdan
18972140429cSdan    CREATE TRIGGER parent_t AFTER DELETE ON parent BEGIN
18982140429cSdan      UPDATE child1 SET c = NULL WHERE c = old.x;
18992140429cSdan      UPDATE child2 SET c = NULL WHERE c = old.x;
19002140429cSdan    END;
19014e7deacfSdan  }
19022140429cSdan} {}
19038e9f6aedSdando_test e_fkey-42.5 {
19042140429cSdan  catchsql { DELETE FROM parent WHERE x = 'key1' }
1905f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
19068e9f6aedSdando_test e_fkey-42.6 {
19072140429cSdan  execsql {
19082140429cSdan    DELETE FROM parent WHERE x = 'key2';
19092140429cSdan    SELECT * FROM child2;
19102140429cSdan  }
19112140429cSdan} {{}}
19122140429cSdan
19132140429cSdandrop_all_tables
19148e9f6aedSdando_test e_fkey-42.7 {
19152140429cSdan  execsql {
19162140429cSdan    CREATE TABLE parent(x PRIMARY KEY);
19172140429cSdan    CREATE TABLE child1(c REFERENCES parent ON DELETE RESTRICT);
19182140429cSdan    CREATE TABLE child2(c REFERENCES parent ON DELETE NO ACTION);
19192140429cSdan
19202140429cSdan    INSERT INTO parent VALUES('key1');
19212140429cSdan    INSERT INTO parent VALUES('key2');
19222140429cSdan    INSERT INTO child1 VALUES('key1');
19232140429cSdan    INSERT INTO child2 VALUES('key2');
19242140429cSdan  }
19252140429cSdan} {}
19268e9f6aedSdando_test e_fkey-42.8 {
19272140429cSdan  catchsql { REPLACE INTO parent VALUES('key1') }
1928f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
19298e9f6aedSdando_test e_fkey-42.9 {
19302140429cSdan  execsql {
19312140429cSdan    REPLACE INTO parent VALUES('key2');
19322140429cSdan    SELECT * FROM child2;
19332140429cSdan  }
19342140429cSdan} {key2}
19354e7deacfSdan
19364e7deacfSdan#-------------------------------------------------------------------------
19372140429cSdan# Test that RESTRICT is enforced immediately, even for a DEFERRED constraint.
19384e7deacfSdan#
1939bf3e3a06Sdan# EVIDENCE-OF: R-24179-60523 Even if the foreign key constraint it is
1940bf3e3a06Sdan# attached to is deferred, configuring a RESTRICT action causes SQLite
1941bf3e3a06Sdan# to return an error immediately if a parent key with dependent child
1942bf3e3a06Sdan# keys is deleted or modified.
1943bf3e3a06Sdan#
19444e7deacfSdandrop_all_tables
19458e9f6aedSdando_test e_fkey-43.1 {
19464e7deacfSdan  execsql {
19472140429cSdan    CREATE TABLE parent(x PRIMARY KEY);
19482140429cSdan    CREATE TABLE child1(c REFERENCES parent ON UPDATE RESTRICT
19492140429cSdan      DEFERRABLE INITIALLY DEFERRED
19504e7deacfSdan    );
19512140429cSdan    CREATE TABLE child2(c REFERENCES parent ON UPDATE NO ACTION
19522140429cSdan      DEFERRABLE INITIALLY DEFERRED
19534e7deacfSdan    );
19542140429cSdan
19552140429cSdan    INSERT INTO parent VALUES('key1');
19562140429cSdan    INSERT INTO parent VALUES('key2');
19572140429cSdan    INSERT INTO child1 VALUES('key1');
19582140429cSdan    INSERT INTO child2 VALUES('key2');
19592140429cSdan    BEGIN;
19604e7deacfSdan  }
19614e7deacfSdan} {}
19628e9f6aedSdando_test e_fkey-43.2 {
19632140429cSdan  catchsql { UPDATE parent SET x = 'key one' WHERE x = 'key1' }
1964f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
19658e9f6aedSdando_test e_fkey-43.3 {
19662140429cSdan  execsql { UPDATE parent SET x = 'key two' WHERE x = 'key2' }
19672140429cSdan} {}
19688e9f6aedSdando_test e_fkey-43.4 {
19692140429cSdan  catchsql COMMIT
1970f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
19718e9f6aedSdando_test e_fkey-43.5 {
19724e7deacfSdan  execsql {
19732140429cSdan    UPDATE child2 SET c = 'key two';
19742140429cSdan    COMMIT;
19754e7deacfSdan  }
19764e7deacfSdan} {}
19772140429cSdan
19782140429cSdandrop_all_tables
19798e9f6aedSdando_test e_fkey-43.6 {
19802140429cSdan  execsql {
19812140429cSdan    CREATE TABLE parent(x PRIMARY KEY);
19822140429cSdan    CREATE TABLE child1(c REFERENCES parent ON DELETE RESTRICT
19832140429cSdan      DEFERRABLE INITIALLY DEFERRED
19842140429cSdan    );
19852140429cSdan    CREATE TABLE child2(c REFERENCES parent ON DELETE NO ACTION
19862140429cSdan      DEFERRABLE INITIALLY DEFERRED
19872140429cSdan    );
19882140429cSdan
19892140429cSdan    INSERT INTO parent VALUES('key1');
19902140429cSdan    INSERT INTO parent VALUES('key2');
19912140429cSdan    INSERT INTO child1 VALUES('key1');
19922140429cSdan    INSERT INTO child2 VALUES('key2');
19932140429cSdan    BEGIN;
19942140429cSdan  }
19952140429cSdan} {}
19968e9f6aedSdando_test e_fkey-43.7 {
19972140429cSdan  catchsql { DELETE FROM parent WHERE x = 'key1' }
1998f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
19998e9f6aedSdando_test e_fkey-43.8 {
20002140429cSdan  execsql { DELETE FROM parent WHERE x = 'key2' }
20012140429cSdan} {}
20028e9f6aedSdando_test e_fkey-43.9 {
20032140429cSdan  catchsql COMMIT
2004f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
20058e9f6aedSdando_test e_fkey-43.10 {
20062140429cSdan  execsql {
20072140429cSdan    UPDATE child2 SET c = NULL;
20082140429cSdan    COMMIT;
20092140429cSdan  }
20102140429cSdan} {}
20114e7deacfSdan
20124e7deacfSdan#-------------------------------------------------------------------------
20132140429cSdan# Test SET NULL actions.
20142140429cSdan#
2015bf3e3a06Sdan# EVIDENCE-OF: R-03353-05327 If the configured action is "SET NULL",
2016bf3e3a06Sdan# then when a parent key is deleted (for ON DELETE SET NULL) or modified
2017bf3e3a06Sdan# (for ON UPDATE SET NULL), the child key columns of all rows in the
2018bf3e3a06Sdan# child table that mapped to the parent key are set to contain SQL NULL
2019bf3e3a06Sdan# values.
2020bf3e3a06Sdan#
20212140429cSdandrop_all_tables
20228e9f6aedSdando_test e_fkey-44.1 {
20232140429cSdan  execsql {
20242140429cSdan    CREATE TABLE pA(x PRIMARY KEY);
20252140429cSdan    CREATE TABLE cA(c REFERENCES pA ON DELETE SET NULL);
20262140429cSdan    CREATE TABLE cB(c REFERENCES pA ON UPDATE SET NULL);
20272140429cSdan
20282140429cSdan    INSERT INTO pA VALUES(X'ABCD');
20292140429cSdan    INSERT INTO pA VALUES(X'1234');
20302140429cSdan    INSERT INTO cA VALUES(X'ABCD');
20312140429cSdan    INSERT INTO cB VALUES(X'1234');
20322140429cSdan  }
20332140429cSdan} {}
20348e9f6aedSdando_test e_fkey-44.2 {
20352140429cSdan  execsql {
20362140429cSdan    DELETE FROM pA WHERE rowid = 1;
20372140429cSdan    SELECT quote(x) FROM pA;
20382140429cSdan  }
20392140429cSdan} {X'1234'}
20408e9f6aedSdando_test e_fkey-44.3 {
20412140429cSdan  execsql {
20422140429cSdan    SELECT quote(c) FROM cA;
20432140429cSdan  }
20442140429cSdan} {NULL}
20458e9f6aedSdando_test e_fkey-44.4 {
20462140429cSdan  execsql {
20472140429cSdan    UPDATE pA SET x = X'8765' WHERE rowid = 2;
20482140429cSdan    SELECT quote(x) FROM pA;
20492140429cSdan  }
20502140429cSdan} {X'8765'}
20518e9f6aedSdando_test e_fkey-44.5 {
20522140429cSdan  execsql { SELECT quote(c) FROM cB }
20532140429cSdan} {NULL}
20542140429cSdan
20552140429cSdan#-------------------------------------------------------------------------
20562140429cSdan# Test SET DEFAULT actions.
20572140429cSdan#
20580ca23aa4Sdrh# EVIDENCE-OF: R-55814-22637 The "SET DEFAULT" actions are similar to
2059bf3e3a06Sdan# "SET NULL", except that each of the child key columns is set to
20600ca23aa4Sdrh# contain the column's default value instead of NULL.
2061bf3e3a06Sdan#
20622140429cSdandrop_all_tables
20638e9f6aedSdando_test e_fkey-45.1 {
20642140429cSdan  execsql {
20652140429cSdan    CREATE TABLE pA(x PRIMARY KEY);
20662140429cSdan    CREATE TABLE cA(c DEFAULT X'0000' REFERENCES pA ON DELETE SET DEFAULT);
20672140429cSdan    CREATE TABLE cB(c DEFAULT X'9999' REFERENCES pA ON UPDATE SET DEFAULT);
20682140429cSdan
20692140429cSdan    INSERT INTO pA(rowid, x) VALUES(1, X'0000');
20702140429cSdan    INSERT INTO pA(rowid, x) VALUES(2, X'9999');
20712140429cSdan    INSERT INTO pA(rowid, x) VALUES(3, X'ABCD');
20722140429cSdan    INSERT INTO pA(rowid, x) VALUES(4, X'1234');
20732140429cSdan
20742140429cSdan    INSERT INTO cA VALUES(X'ABCD');
20752140429cSdan    INSERT INTO cB VALUES(X'1234');
20762140429cSdan  }
20772140429cSdan} {}
20788e9f6aedSdando_test e_fkey-45.2 {
20792140429cSdan  execsql {
20802140429cSdan    DELETE FROM pA WHERE rowid = 3;
20813f4d1d1bSdrh    SELECT quote(x) FROM pA ORDER BY rowid;
20822140429cSdan  }
20832140429cSdan} {X'0000' X'9999' X'1234'}
20848e9f6aedSdando_test e_fkey-45.3 {
20852140429cSdan  execsql { SELECT quote(c) FROM cA }
20862140429cSdan} {X'0000'}
20878e9f6aedSdando_test e_fkey-45.4 {
20882140429cSdan  execsql {
20892140429cSdan    UPDATE pA SET x = X'8765' WHERE rowid = 4;
20903f4d1d1bSdrh    SELECT quote(x) FROM pA ORDER BY rowid;
20912140429cSdan  }
20922140429cSdan} {X'0000' X'9999' X'8765'}
20938e9f6aedSdando_test e_fkey-45.5 {
20942140429cSdan  execsql { SELECT quote(c) FROM cB }
20952140429cSdan} {X'9999'}
20962140429cSdan
20972140429cSdan#-------------------------------------------------------------------------
20982140429cSdan# Test ON DELETE CASCADE actions.
20992140429cSdan#
2100bf3e3a06Sdan# EVIDENCE-OF: R-61376-57267 A "CASCADE" action propagates the delete or
2101bf3e3a06Sdan# update operation on the parent key to each dependent child key.
2102bf3e3a06Sdan#
2103bf3e3a06Sdan# EVIDENCE-OF: R-61809-62207 For an "ON DELETE CASCADE" action, this
2104bf3e3a06Sdan# means that each row in the child table that was associated with the
2105bf3e3a06Sdan# deleted parent row is also deleted.
2106bf3e3a06Sdan#
21072140429cSdandrop_all_tables
21088e9f6aedSdando_test e_fkey-46.1 {
21092140429cSdan  execsql {
21102140429cSdan    CREATE TABLE p1(a, b UNIQUE);
21112140429cSdan    CREATE TABLE c1(c REFERENCES p1(b) ON DELETE CASCADE, d);
21122140429cSdan    INSERT INTO p1 VALUES(NULL, NULL);
21132140429cSdan    INSERT INTO p1 VALUES(4, 4);
21142140429cSdan    INSERT INTO p1 VALUES(5, 5);
21152140429cSdan    INSERT INTO c1 VALUES(NULL, NULL);
21162140429cSdan    INSERT INTO c1 VALUES(4, 4);
21172140429cSdan    INSERT INTO c1 VALUES(5, 5);
21182140429cSdan    SELECT count(*) FROM c1;
21192140429cSdan  }
21202140429cSdan} {3}
21218e9f6aedSdando_test e_fkey-46.2 {
21222140429cSdan  execsql {
21232140429cSdan    DELETE FROM p1 WHERE a = 4;
21242140429cSdan    SELECT d, c FROM c1;
21252140429cSdan  }
21262140429cSdan} {{} {} 5 5}
21278e9f6aedSdando_test e_fkey-46.3 {
21282140429cSdan  execsql {
21292140429cSdan    DELETE FROM p1;
21302140429cSdan    SELECT d, c FROM c1;
21312140429cSdan  }
21322140429cSdan} {{} {}}
21338e9f6aedSdando_test e_fkey-46.4 {
21342140429cSdan  execsql { SELECT * FROM p1 }
21352140429cSdan} {}
21362140429cSdan
21372140429cSdan
21382140429cSdan#-------------------------------------------------------------------------
21392140429cSdan# Test ON UPDATE CASCADE actions.
21402140429cSdan#
2141bf3e3a06Sdan# EVIDENCE-OF: R-13877-64542 For an "ON UPDATE CASCADE" action, it means
2142bf3e3a06Sdan# that the values stored in each dependent child key are modified to
2143bf3e3a06Sdan# match the new parent key values.
2144bf3e3a06Sdan#
2145bf3e3a06Sdan# EVIDENCE-OF: R-61376-57267 A "CASCADE" action propagates the delete or
2146bf3e3a06Sdan# update operation on the parent key to each dependent child key.
2147bf3e3a06Sdan#
21482140429cSdandrop_all_tables
21498e9f6aedSdando_test e_fkey-47.1 {
21502140429cSdan  execsql {
21512140429cSdan    CREATE TABLE p1(a, b UNIQUE);
21522140429cSdan    CREATE TABLE c1(c REFERENCES p1(b) ON UPDATE CASCADE, d);
21532140429cSdan    INSERT INTO p1 VALUES(NULL, NULL);
21542140429cSdan    INSERT INTO p1 VALUES(4, 4);
21552140429cSdan    INSERT INTO p1 VALUES(5, 5);
21562140429cSdan    INSERT INTO c1 VALUES(NULL, NULL);
21572140429cSdan    INSERT INTO c1 VALUES(4, 4);
21582140429cSdan    INSERT INTO c1 VALUES(5, 5);
21592140429cSdan    SELECT count(*) FROM c1;
21602140429cSdan  }
21612140429cSdan} {3}
21628e9f6aedSdando_test e_fkey-47.2 {
21632140429cSdan  execsql {
21642140429cSdan    UPDATE p1 SET b = 10 WHERE b = 5;
21652140429cSdan    SELECT d, c FROM c1;
21662140429cSdan  }
21672140429cSdan} {{} {} 4 4 5 10}
21688e9f6aedSdando_test e_fkey-47.3 {
21692140429cSdan  execsql {
21702140429cSdan    UPDATE p1 SET b = 11 WHERE b = 4;
21712140429cSdan    SELECT d, c FROM c1;
21722140429cSdan  }
21732140429cSdan} {{} {} 4 11 5 10}
21748e9f6aedSdando_test e_fkey-47.4 {
21752140429cSdan  execsql {
21762140429cSdan    UPDATE p1 SET b = 6 WHERE b IS NULL;
21772140429cSdan    SELECT d, c FROM c1;
21782140429cSdan  }
21792140429cSdan} {{} {} 4 11 5 10}
21808e9f6aedSdando_test e_fkey-46.5 {
21812140429cSdan  execsql { SELECT * FROM p1 }
21822140429cSdan} {{} 6 4 11 5 10}
21832140429cSdan
21842140429cSdan#-------------------------------------------------------------------------
21859ede952aSdrh# EVIDENCE-OF: R-65058-57158
21864e7deacfSdan#
21874e7deacfSdan# Test an example from the "ON DELETE and ON UPDATE Actions" section
21884e7deacfSdan# of foreignkeys.html.
21894e7deacfSdan#
21904e7deacfSdandrop_all_tables
21918e9f6aedSdando_test e_fkey-48.1 {
21924e7deacfSdan  execsql {
21934e7deacfSdan    CREATE TABLE artist(
21944e7deacfSdan      artistid    INTEGER PRIMARY KEY,
21954e7deacfSdan      artistname  TEXT
21964e7deacfSdan    );
21974e7deacfSdan    CREATE TABLE track(
21984e7deacfSdan      trackid     INTEGER,
21994e7deacfSdan      trackname   TEXT,
22004e7deacfSdan      trackartist INTEGER REFERENCES artist(artistid) ON UPDATE CASCADE
22014e7deacfSdan    );
22024e7deacfSdan
22034e7deacfSdan    INSERT INTO artist VALUES(1, 'Dean Martin');
22044e7deacfSdan    INSERT INTO artist VALUES(2, 'Frank Sinatra');
22054e7deacfSdan    INSERT INTO track VALUES(11, 'That''s Amore', 1);
22064e7deacfSdan    INSERT INTO track VALUES(12, 'Christmas Blues', 1);
22074e7deacfSdan    INSERT INTO track VALUES(13, 'My Way', 2);
22084e7deacfSdan  }
22094e7deacfSdan} {}
22108e9f6aedSdando_test e_fkey-48.2 {
22114e7deacfSdan  execsql {
22124e7deacfSdan    UPDATE artist SET artistid = 100 WHERE artistname = 'Dean Martin';
22134e7deacfSdan  }
22144e7deacfSdan} {}
22158e9f6aedSdando_test e_fkey-48.3 {
22164e7deacfSdan  execsql { SELECT * FROM artist }
22174e7deacfSdan} {2 {Frank Sinatra} 100 {Dean Martin}}
22188e9f6aedSdando_test e_fkey-48.4 {
22194e7deacfSdan  execsql { SELECT * FROM track }
22204e7deacfSdan} {11 {That's Amore} 100 12 {Christmas Blues} 100 13 {My Way} 2}
22214e7deacfSdan
22222140429cSdan
22232140429cSdan#-------------------------------------------------------------------------
22242140429cSdan# Verify that adding an FK action does not absolve the user of the
22252140429cSdan# requirement not to violate the foreign key constraint.
22262140429cSdan#
2227bf3e3a06Sdan# EVIDENCE-OF: R-53968-51642 Configuring an ON UPDATE or ON DELETE
2228bf3e3a06Sdan# action does not mean that the foreign key constraint does not need to
2229bf3e3a06Sdan# be satisfied.
2230bf3e3a06Sdan#
22312140429cSdandrop_all_tables
22328e9f6aedSdando_test e_fkey-49.1 {
22332140429cSdan  execsql {
22342140429cSdan    CREATE TABLE parent(a COLLATE nocase, b, c, PRIMARY KEY(c, a));
22352140429cSdan    CREATE TABLE child(d DEFAULT 'a', e, f DEFAULT 'c',
22362140429cSdan      FOREIGN KEY(f, d) REFERENCES parent ON UPDATE SET DEFAULT
22372140429cSdan    );
22382140429cSdan
22392140429cSdan    INSERT INTO parent VALUES('A', 'b', 'c');
22402140429cSdan    INSERT INTO parent VALUES('ONE', 'two', 'three');
22412140429cSdan    INSERT INTO child VALUES('one', 'two', 'three');
22422140429cSdan  }
22432140429cSdan} {}
22448e9f6aedSdando_test e_fkey-49.2 {
22452140429cSdan  execsql {
22462140429cSdan    BEGIN;
22472140429cSdan      UPDATE parent SET a = '' WHERE a = 'oNe';
22482140429cSdan      SELECT * FROM child;
22492140429cSdan  }
22502140429cSdan} {a two c}
22518e9f6aedSdando_test e_fkey-49.3 {
22522140429cSdan  execsql {
22532140429cSdan    ROLLBACK;
22542140429cSdan    DELETE FROM parent WHERE a = 'A';
22552140429cSdan    SELECT * FROM parent;
22562140429cSdan  }
22572140429cSdan} {ONE two three}
22588e9f6aedSdando_test e_fkey-49.4 {
22592140429cSdan  catchsql { UPDATE parent SET a = '' WHERE a = 'oNe' }
2260f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
22612140429cSdan
22622140429cSdan
22632140429cSdan#-------------------------------------------------------------------------
22649ede952aSdrh# EVIDENCE-OF: R-11856-19836
22652140429cSdan#
22662140429cSdan# Test an example from the "ON DELETE and ON UPDATE Actions" section
22672140429cSdan# of foreignkeys.html. This example shows that adding an "ON DELETE DEFAULT"
22682140429cSdan# clause does not abrogate the need to satisfy the foreign key constraint
22692140429cSdan# (R-28220-46694).
22702140429cSdan#
2271bf3e3a06Sdan# EVIDENCE-OF: R-28220-46694 For example, if an "ON DELETE SET DEFAULT"
2272bf3e3a06Sdan# action is configured, but there is no row in the parent table that
2273bf3e3a06Sdan# corresponds to the default values of the child key columns, deleting a
2274bf3e3a06Sdan# parent key while dependent child keys exist still causes a foreign key
2275bf3e3a06Sdan# violation.
2276bf3e3a06Sdan#
22772140429cSdandrop_all_tables
22788e9f6aedSdando_test e_fkey-50.1 {
22792140429cSdan  execsql {
22802140429cSdan    CREATE TABLE artist(
22812140429cSdan      artistid    INTEGER PRIMARY KEY,
22822140429cSdan      artistname  TEXT
22832140429cSdan    );
22842140429cSdan    CREATE TABLE track(
22852140429cSdan      trackid     INTEGER,
22862140429cSdan      trackname   TEXT,
22872140429cSdan      trackartist INTEGER DEFAULT 0 REFERENCES artist(artistid) ON DELETE SET DEFAULT
22882140429cSdan    );
22892140429cSdan    INSERT INTO artist VALUES(3, 'Sammy Davis Jr.');
22902140429cSdan    INSERT INTO track VALUES(14, 'Mr. Bojangles', 3);
22912140429cSdan  }
22922140429cSdan} {}
22938e9f6aedSdando_test e_fkey-50.2 {
22942140429cSdan  catchsql { DELETE FROM artist WHERE artistname = 'Sammy Davis Jr.' }
2295f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
22968e9f6aedSdando_test e_fkey-50.3 {
22972140429cSdan  execsql {
22982140429cSdan    INSERT INTO artist VALUES(0, 'Unknown Artist');
22992140429cSdan    DELETE FROM artist WHERE artistname = 'Sammy Davis Jr.';
23002140429cSdan  }
23012140429cSdan} {}
23028e9f6aedSdando_test e_fkey-50.4 {
23032140429cSdan  execsql { SELECT * FROM artist }
23042140429cSdan} {0 {Unknown Artist}}
23058e9f6aedSdando_test e_fkey-50.5 {
23062140429cSdan  execsql { SELECT * FROM track }
23072140429cSdan} {14 {Mr. Bojangles} 0}
23082140429cSdan
23092140429cSdan#-------------------------------------------------------------------------
2310bf3e3a06Sdan# EVIDENCE-OF: R-09564-22170
23112140429cSdan#
23122140429cSdan# Check that the order of steps in an UPDATE or DELETE on a parent
23132140429cSdan# table is as follows:
23142140429cSdan#
23152140429cSdan#   1. Execute applicable BEFORE trigger programs,
23162140429cSdan#   2. Check local (non foreign key) constraints,
23172140429cSdan#   3. Update or delete the row in the parent table,
23182140429cSdan#   4. Perform any required foreign key actions,
23192140429cSdan#   5. Execute applicable AFTER trigger programs.
23202140429cSdan#
23212140429cSdandrop_all_tables
23228e9f6aedSdando_test e_fkey-51.1 {
23232140429cSdan  proc maxparent {args} { db one {SELECT max(x) FROM parent} }
23242140429cSdan  db func maxparent maxparent
23252140429cSdan
23262140429cSdan  execsql {
23272140429cSdan    CREATE TABLE parent(x PRIMARY KEY);
23282140429cSdan
23292140429cSdan    CREATE TRIGGER bu BEFORE UPDATE ON parent BEGIN
23302140429cSdan      INSERT INTO parent VALUES(new.x-old.x);
23312140429cSdan    END;
23322140429cSdan    CREATE TABLE child(
23332140429cSdan      a DEFAULT (maxparent()) REFERENCES parent ON UPDATE SET DEFAULT
23342140429cSdan    );
23352140429cSdan    CREATE TRIGGER au AFTER UPDATE ON parent BEGIN
23362140429cSdan      INSERT INTO parent VALUES(new.x+old.x);
23372140429cSdan    END;
23382140429cSdan
23392140429cSdan    INSERT INTO parent VALUES(1);
23402140429cSdan    INSERT INTO child VALUES(1);
23412140429cSdan  }
23422140429cSdan} {}
23438e9f6aedSdando_test e_fkey-51.2 {
23442140429cSdan  execsql {
23452140429cSdan    UPDATE parent SET x = 22;
23463f4d1d1bSdrh    SELECT * FROM parent ORDER BY rowid; SELECT 'xxx' ; SELECT a FROM child;
23472140429cSdan  }
23482140429cSdan} {22 21 23 xxx 22}
23498e9f6aedSdando_test e_fkey-51.3 {
23502140429cSdan  execsql {
23512140429cSdan    DELETE FROM child;
23522140429cSdan    DELETE FROM parent;
23532140429cSdan    INSERT INTO parent VALUES(-1);
23542140429cSdan    INSERT INTO child VALUES(-1);
23552140429cSdan    UPDATE parent SET x = 22;
23563f4d1d1bSdrh    SELECT * FROM parent ORDER BY rowid; SELECT 'xxx' ; SELECT a FROM child;
23572140429cSdan  }
23582140429cSdan} {22 23 21 xxx 23}
23592140429cSdan
23602140429cSdan
23612140429cSdan#-------------------------------------------------------------------------
23622140429cSdan# Verify that ON UPDATE actions only actually take place if the parent key
23632140429cSdan# is set to a new value that is distinct from the old value. The default
23642140429cSdan# collation sequence and affinity are used to determine if the new value
23652140429cSdan# is 'distinct' from the old or not.
23662140429cSdan#
2367bf3e3a06Sdan# EVIDENCE-OF: R-27383-10246 An ON UPDATE action is only taken if the
2368bf3e3a06Sdan# values of the parent key are modified so that the new parent key
2369bf3e3a06Sdan# values are not equal to the old.
2370bf3e3a06Sdan#
23712140429cSdandrop_all_tables
23728e9f6aedSdando_test e_fkey-52.1 {
23732140429cSdan  execsql {
23742140429cSdan    CREATE TABLE zeus(a INTEGER COLLATE NOCASE, b, PRIMARY KEY(a, b));
23752140429cSdan    CREATE TABLE apollo(c, d,
23762140429cSdan      FOREIGN KEY(c, d) REFERENCES zeus ON UPDATE CASCADE
23772140429cSdan    );
23782140429cSdan    INSERT INTO zeus VALUES('abc', 'xyz');
23792140429cSdan    INSERT INTO apollo VALUES('ABC', 'xyz');
23802140429cSdan  }
23812140429cSdan  execsql {
23822140429cSdan    UPDATE zeus SET a = 'aBc';
23832140429cSdan    SELECT * FROM apollo;
23842140429cSdan  }
23852140429cSdan} {ABC xyz}
23868e9f6aedSdando_test e_fkey-52.2 {
23872140429cSdan  execsql {
23882140429cSdan    UPDATE zeus SET a = 1, b = 1;
23892140429cSdan    SELECT * FROM apollo;
23902140429cSdan  }
23912140429cSdan} {1 1}
23928e9f6aedSdando_test e_fkey-52.3 {
23932140429cSdan  execsql {
23942140429cSdan    UPDATE zeus SET a = 1, b = 1;
23952140429cSdan    SELECT typeof(c), c, typeof(d), d FROM apollo;
23962140429cSdan  }
23972140429cSdan} {integer 1 integer 1}
23988e9f6aedSdando_test e_fkey-52.4 {
23992140429cSdan  execsql {
24002140429cSdan    UPDATE zeus SET a = '1';
24012140429cSdan    SELECT typeof(c), c, typeof(d), d FROM apollo;
24022140429cSdan  }
24032140429cSdan} {integer 1 integer 1}
24048e9f6aedSdando_test e_fkey-52.5 {
24052140429cSdan  execsql {
24062140429cSdan    UPDATE zeus SET b = '1';
24072140429cSdan    SELECT typeof(c), c, typeof(d), d FROM apollo;
24082140429cSdan  }
24092140429cSdan} {integer 1 text 1}
24108e9f6aedSdando_test e_fkey-52.6 {
24112140429cSdan  execsql {
24122140429cSdan    UPDATE zeus SET b = NULL;
24132140429cSdan    SELECT typeof(c), c, typeof(d), d FROM apollo;
24142140429cSdan  }
24152140429cSdan} {integer 1 null {}}
24162140429cSdan
24172140429cSdan#-------------------------------------------------------------------------
24189ede952aSdrh# EVIDENCE-OF: R-35129-58141
24192140429cSdan#
24202140429cSdan# Test an example from the "ON DELETE and ON UPDATE Actions" section
24212140429cSdan# of foreignkeys.html. This example demonstrates that ON UPDATE actions
24222140429cSdan# only take place if at least one parent key column is set to a value
24232140429cSdan# that is distinct from its previous value.
24242140429cSdan#
24252140429cSdandrop_all_tables
24268e9f6aedSdando_test e_fkey-53.1 {
24272140429cSdan  execsql {
24282140429cSdan    CREATE TABLE parent(x PRIMARY KEY);
24292140429cSdan    CREATE TABLE child(y REFERENCES parent ON UPDATE SET NULL);
24302140429cSdan    INSERT INTO parent VALUES('key');
24312140429cSdan    INSERT INTO child VALUES('key');
24322140429cSdan  }
24332140429cSdan} {}
24348e9f6aedSdando_test e_fkey-53.2 {
24352140429cSdan  execsql {
24362140429cSdan    UPDATE parent SET x = 'key';
24372140429cSdan    SELECT IFNULL(y, 'null') FROM child;
24382140429cSdan  }
24392140429cSdan} {key}
24408e9f6aedSdando_test e_fkey-53.3 {
24412140429cSdan  execsql {
24422140429cSdan    UPDATE parent SET x = 'key2';
24432140429cSdan    SELECT IFNULL(y, 'null') FROM child;
24442140429cSdan  }
24452140429cSdan} {null}
24462140429cSdan
24472140429cSdan###########################################################################
24482140429cSdan### SECTION 5: CREATE, ALTER and DROP TABLE commands
24492140429cSdan###########################################################################
24502140429cSdan
24514e7deacfSdan#-------------------------------------------------------------------------
2452ce374532Sdan# Test that parent keys are not checked when tables are created.
2453ce374532Sdan#
2454bf3e3a06Sdan# EVIDENCE-OF: R-36018-21755 The parent key definitions of foreign key
2455bf3e3a06Sdan# constraints are not checked when a table is created.
2456bf3e3a06Sdan#
2457bf3e3a06Sdan# EVIDENCE-OF: R-25384-39337 There is nothing stopping the user from
2458bf3e3a06Sdan# creating a foreign key definition that refers to a parent table that
2459bf3e3a06Sdan# does not exist, or to parent key columns that do not exist or are not
2460bf3e3a06Sdan# collectively bound by a PRIMARY KEY or UNIQUE constraint.
2461bf3e3a06Sdan#
2462ce374532Sdan# Child keys are checked to ensure all component columns exist. If parent
2463ce374532Sdan# key columns are explicitly specified, SQLite checks to make sure there
2464ce374532Sdan# are the same number of columns in the child and parent keys. (TODO: This
2465ce374532Sdan# is tested but does not correspond to any testable statement.)
2466ce374532Sdan#
2467ce374532Sdan# Also test that the above statements are true regardless of whether or not
24682f01f465Sdan# foreign keys are enabled:  "A CREATE TABLE command operates the same whether
24692f01f465Sdan# or not foreign key constraints are enabled."
2470ce374532Sdan#
2471bf3e3a06Sdan# EVIDENCE-OF: R-08908-23439 A CREATE TABLE command operates the same
2472bf3e3a06Sdan# whether or not foreign key constraints are enabled.
2473bf3e3a06Sdan#
2474ce374532Sdanforeach {tn zCreateTbl lRes} {
2475ce374532Sdan  1 "CREATE TABLE t1(a, b REFERENCES t1)"                            {0 {}}
2476ce374532Sdan  2 "CREATE TABLE t1(a, b REFERENCES t2)"                            {0 {}}
2477ce374532Sdan  3 "CREATE TABLE t1(a, b, FOREIGN KEY(a,b) REFERENCES t1)"          {0 {}}
2478ce374532Sdan  4 "CREATE TABLE t1(a, b, FOREIGN KEY(a,b) REFERENCES t2)"          {0 {}}
2479ce374532Sdan  5 "CREATE TABLE t1(a, b, FOREIGN KEY(a,b) REFERENCES t2)"          {0 {}}
2480ce374532Sdan  6 "CREATE TABLE t1(a, b, FOREIGN KEY(a,b) REFERENCES t2(n,d))"     {0 {}}
2481ce374532Sdan  7 "CREATE TABLE t1(a, b, FOREIGN KEY(a,b) REFERENCES t1(a,b))"     {0 {}}
2482ce374532Sdan
2483ce374532Sdan  A "CREATE TABLE t1(a, b, FOREIGN KEY(c,b) REFERENCES t2)"
2484ce374532Sdan     {1 {unknown column "c" in foreign key definition}}
2485ce374532Sdan  B "CREATE TABLE t1(a, b, FOREIGN KEY(c,b) REFERENCES t2(d))"
2486ce374532Sdan     {1 {number of columns in foreign key does not match the number of columns in the referenced table}}
2487ce374532Sdan} {
24888e9f6aedSdan  do_test e_fkey-54.$tn.off {
2489ce374532Sdan    drop_all_tables
2490ce374532Sdan    execsql {PRAGMA foreign_keys = OFF}
2491ce374532Sdan    catchsql $zCreateTbl
2492ce374532Sdan  } $lRes
24938e9f6aedSdan  do_test e_fkey-54.$tn.on {
2494ce374532Sdan    drop_all_tables
2495ce374532Sdan    execsql {PRAGMA foreign_keys = ON}
2496ce374532Sdan    catchsql $zCreateTbl
2497ce374532Sdan  } $lRes
2498ce374532Sdan}
2499ce374532Sdan
2500ce374532Sdan#-------------------------------------------------------------------------
2501bf3e3a06Sdan# EVIDENCE-OF: R-47952-62498 It is not possible to use the "ALTER TABLE
2502bf3e3a06Sdan# ... ADD COLUMN" syntax to add a column that includes a REFERENCES
2503bf3e3a06Sdan# clause, unless the default value of the new column is NULL. Attempting
2504bf3e3a06Sdan# to do so returns an error.
2505ce374532Sdan#
2506ce374532Sdanproc test_efkey_6 {tn zAlter isError} {
2507ce374532Sdan  drop_all_tables
2508ce374532Sdan
25098e9f6aedSdan  do_test e_fkey-56.$tn.1 "
25102629adc7Sdan    execsql { CREATE TABLE tbl(a, b); INSERT INTO tbl VALUES(1, 2); }
2511ce374532Sdan    [list catchsql $zAlter]
2512ce374532Sdan  " [lindex {{0 {}} {1 {Cannot add a REFERENCES column with non-NULL default value}}} $isError]
2513ce374532Sdan
2514ce374532Sdan}
2515ce374532Sdan
25162841abedSdanifcapable altertable {
2517ce374532Sdan  test_efkey_6 1 "ALTER TABLE tbl ADD COLUMN c REFERENCES xx" 0
2518ce374532Sdan  test_efkey_6 2 "ALTER TABLE tbl ADD COLUMN c DEFAULT NULL REFERENCES xx" 0
2519ce374532Sdan  test_efkey_6 3 "ALTER TABLE tbl ADD COLUMN c DEFAULT 0 REFERENCES xx" 1
25202841abedSdan}
2521ce374532Sdan
2522ce374532Sdan#-------------------------------------------------------------------------
2523ce374532Sdan# Test that ALTER TABLE adjusts REFERENCES clauses when the parent table
2524ce374532Sdan# is RENAMED.
2525ce374532Sdan#
2526bf3e3a06Sdan# EVIDENCE-OF: R-47080-02069 If an "ALTER TABLE ... RENAME TO" command
2527bf3e3a06Sdan# is used to rename a table that is the parent table of one or more
2528bf3e3a06Sdan# foreign key constraints, the definitions of the foreign key
2529bf3e3a06Sdan# constraints are modified to refer to the parent table by its new name
2530ce374532Sdan#
2531ce374532Sdan# Test that these adjustments are visible in the sqlite_master table.
2532ce374532Sdan#
2533d43c0cbeSdrh# EVIDENCE-OF: R-43040-62530 The text of the child CREATE TABLE
2534d43c0cbeSdrh# statement or statements stored in the sqlite_schema table are modified
2535bf3e3a06Sdan# to reflect the new parent table name.
2536bf3e3a06Sdan#
25372841abedSdanifcapable altertable {
25388e9f6aedSdando_test e_fkey-56.1 {
2539ce374532Sdan  drop_all_tables
2540ce374532Sdan  execsql {
2541ce374532Sdan    CREATE TABLE 'p 1 "parent one"'(a REFERENCES 'p 1 "parent one"', b, PRIMARY KEY(b));
2542ce374532Sdan
2543ce374532Sdan    CREATE TABLE c1(c, d REFERENCES 'p 1 "parent one"' ON UPDATE CASCADE);
2544ce374532Sdan    CREATE TABLE c2(e, f, FOREIGN KEY(f) REFERENCES 'p 1 "parent one"' ON UPDATE CASCADE);
2545ce374532Sdan    CREATE TABLE c3(e, 'f col 2', FOREIGN KEY('f col 2') REFERENCES 'p 1 "parent one"' ON UPDATE CASCADE);
2546ce374532Sdan
2547ce374532Sdan    INSERT INTO 'p 1 "parent one"' VALUES(1, 1);
2548ce374532Sdan    INSERT INTO c1 VALUES(1, 1);
2549ce374532Sdan    INSERT INTO c2 VALUES(1, 1);
2550ce374532Sdan    INSERT INTO c3 VALUES(1, 1);
2551ce374532Sdan
2552ce374532Sdan    -- CREATE TABLE q(a, b, PRIMARY KEY(b));
2553ce374532Sdan  }
2554ce374532Sdan} {}
25558e9f6aedSdando_test e_fkey-56.2 {
2556ce374532Sdan  execsql { ALTER TABLE 'p 1 "parent one"' RENAME TO p }
2557ce374532Sdan} {}
25588e9f6aedSdando_test e_fkey-56.3 {
2559ce374532Sdan  execsql {
2560ce374532Sdan    UPDATE p SET a = 'xxx', b = 'xxx';
2561ce374532Sdan    SELECT * FROM p;
2562ce374532Sdan    SELECT * FROM c1;
2563ce374532Sdan    SELECT * FROM c2;
2564ce374532Sdan    SELECT * FROM c3;
2565ce374532Sdan  }
2566ce374532Sdan} {xxx xxx 1 xxx 1 xxx 1 xxx}
25678e9f6aedSdando_test e_fkey-56.4 {
2568ce374532Sdan  execsql { SELECT sql FROM sqlite_master WHERE type = 'table'}
2569ce374532Sdan} [list                                                                     \
2570ce374532Sdan  {CREATE TABLE "p"(a REFERENCES "p", b, PRIMARY KEY(b))}                   \
2571ce374532Sdan  {CREATE TABLE c1(c, d REFERENCES "p" ON UPDATE CASCADE)}                  \
2572ce374532Sdan  {CREATE TABLE c2(e, f, FOREIGN KEY(f) REFERENCES "p" ON UPDATE CASCADE)}  \
2573ce374532Sdan  {CREATE TABLE c3(e, 'f col 2', FOREIGN KEY('f col 2') REFERENCES "p" ON UPDATE CASCADE)} \
2574ce374532Sdan]
25752841abedSdan}
2576ce374532Sdan
2577598d2028Sdan#-------------------------------------------------------------------------
2578598d2028Sdan# Check that a DROP TABLE does an implicit DELETE FROM. Which does not
2579598d2028Sdan# cause any triggers to fire, but does fire foreign key actions.
2580598d2028Sdan#
2581bf3e3a06Sdan# EVIDENCE-OF: R-14208-23986 If foreign key constraints are enabled when
2582bf3e3a06Sdan# it is prepared, the DROP TABLE command performs an implicit DELETE to
2583bf3e3a06Sdan# remove all rows from the table before dropping it.
2584bf3e3a06Sdan#
2585bf3e3a06Sdan# EVIDENCE-OF: R-11078-03945 The implicit DELETE does not cause any SQL
2586bf3e3a06Sdan# triggers to fire, but may invoke foreign key actions or constraint
2587bf3e3a06Sdan# violations.
2588bf3e3a06Sdan#
25898e9f6aedSdando_test e_fkey-57.1 {
2590598d2028Sdan  drop_all_tables
2591598d2028Sdan  execsql {
2592598d2028Sdan    CREATE TABLE p(a, b, PRIMARY KEY(a, b));
2593598d2028Sdan
2594598d2028Sdan    CREATE TABLE c1(c, d, FOREIGN KEY(c, d) REFERENCES p ON DELETE SET NULL);
2595598d2028Sdan    CREATE TABLE c2(c, d, FOREIGN KEY(c, d) REFERENCES p ON DELETE SET DEFAULT);
2596598d2028Sdan    CREATE TABLE c3(c, d, FOREIGN KEY(c, d) REFERENCES p ON DELETE CASCADE);
2597598d2028Sdan    CREATE TABLE c4(c, d, FOREIGN KEY(c, d) REFERENCES p ON DELETE RESTRICT);
2598598d2028Sdan    CREATE TABLE c5(c, d, FOREIGN KEY(c, d) REFERENCES p ON DELETE NO ACTION);
2599598d2028Sdan
2600598d2028Sdan    CREATE TABLE c6(c, d,
2601598d2028Sdan      FOREIGN KEY(c, d) REFERENCES p ON DELETE RESTRICT
2602598d2028Sdan      DEFERRABLE INITIALLY DEFERRED
2603598d2028Sdan    );
2604598d2028Sdan    CREATE TABLE c7(c, d,
2605598d2028Sdan      FOREIGN KEY(c, d) REFERENCES p ON DELETE NO ACTION
2606598d2028Sdan      DEFERRABLE INITIALLY DEFERRED
2607598d2028Sdan    );
2608598d2028Sdan
2609598d2028Sdan    CREATE TABLE log(msg);
2610598d2028Sdan    CREATE TRIGGER tt AFTER DELETE ON p BEGIN
2611598d2028Sdan      INSERT INTO log VALUES('delete ' || old.rowid);
2612598d2028Sdan    END;
2613598d2028Sdan  }
2614598d2028Sdan} {}
2615598d2028Sdan
26168e9f6aedSdando_test e_fkey-57.2 {
2617598d2028Sdan  execsql {
2618598d2028Sdan    INSERT INTO p VALUES('a', 'b');
2619598d2028Sdan    INSERT INTO c1 VALUES('a', 'b');
2620598d2028Sdan    INSERT INTO c2 VALUES('a', 'b');
2621598d2028Sdan    INSERT INTO c3 VALUES('a', 'b');
2622598d2028Sdan    BEGIN;
2623598d2028Sdan      DROP TABLE p;
2624598d2028Sdan      SELECT * FROM c1;
2625598d2028Sdan  }
2626598d2028Sdan} {{} {}}
26278e9f6aedSdando_test e_fkey-57.3 {
2628598d2028Sdan  execsql { SELECT * FROM c2 }
2629598d2028Sdan} {{} {}}
26308e9f6aedSdando_test e_fkey-57.4 {
2631598d2028Sdan  execsql { SELECT * FROM c3 }
2632598d2028Sdan} {}
26338e9f6aedSdando_test e_fkey-57.5 {
2634598d2028Sdan  execsql { SELECT * FROM log }
2635598d2028Sdan} {}
26368e9f6aedSdando_test e_fkey-57.6 {
2637598d2028Sdan  execsql ROLLBACK
2638598d2028Sdan} {}
26398e9f6aedSdando_test e_fkey-57.7 {
2640598d2028Sdan  execsql {
2641598d2028Sdan    BEGIN;
2642598d2028Sdan      DELETE FROM p;
2643598d2028Sdan      SELECT * FROM log;
2644598d2028Sdan    ROLLBACK;
2645598d2028Sdan  }
2646598d2028Sdan} {{delete 1}}
2647598d2028Sdan
2648598d2028Sdan#-------------------------------------------------------------------------
2649598d2028Sdan# If an IMMEDIATE foreign key fails as a result of a DROP TABLE, the
2650598d2028Sdan# DROP TABLE command fails.
2651598d2028Sdan#
2652bf3e3a06Sdan# EVIDENCE-OF: R-32768-47925 If an immediate foreign key constraint is
2653bf3e3a06Sdan# violated, the DROP TABLE statement fails and the table is not dropped.
2654bf3e3a06Sdan#
26558e9f6aedSdando_test e_fkey-58.1 {
2656598d2028Sdan  execsql {
2657598d2028Sdan    DELETE FROM c1;
2658598d2028Sdan    DELETE FROM c2;
2659598d2028Sdan    DELETE FROM c3;
2660598d2028Sdan  }
2661598d2028Sdan  execsql { INSERT INTO c5 VALUES('a', 'b') }
2662598d2028Sdan  catchsql { DROP TABLE p }
2663f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
26648e9f6aedSdando_test e_fkey-58.2 {
2665598d2028Sdan  execsql { SELECT * FROM p }
2666598d2028Sdan} {a b}
26678e9f6aedSdando_test e_fkey-58.3 {
2668598d2028Sdan  catchsql {
2669598d2028Sdan    BEGIN;
2670598d2028Sdan      DROP TABLE p;
2671598d2028Sdan  }
2672f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
26738e9f6aedSdando_test e_fkey-58.4 {
2674598d2028Sdan  execsql {
2675598d2028Sdan    SELECT * FROM p;
2676598d2028Sdan    SELECT * FROM c5;
2677598d2028Sdan    ROLLBACK;
2678598d2028Sdan  }
2679598d2028Sdan} {a b a b}
2680598d2028Sdan
2681598d2028Sdan#-------------------------------------------------------------------------
2682598d2028Sdan# If a DEFERRED foreign key fails as a result of a DROP TABLE, attempting
2683598d2028Sdan# to commit the transaction fails unless the violation is fixed.
2684598d2028Sdan#
2685bf3e3a06Sdan# EVIDENCE-OF: R-05903-08460 If a deferred foreign key constraint is
2686bf3e3a06Sdan# violated, then an error is reported when the user attempts to commit
2687bf3e3a06Sdan# the transaction if the foreign key constraint violations still exist
2688bf3e3a06Sdan# at that point.
2689bf3e3a06Sdan#
26908e9f6aedSdando_test e_fkey-59.1 {
2691598d2028Sdan  execsql {
2692598d2028Sdan    DELETE FROM c1 ; DELETE FROM c2 ; DELETE FROM c3 ;
2693598d2028Sdan    DELETE FROM c4 ; DELETE FROM c5 ; DELETE FROM c6 ;
2694598d2028Sdan    DELETE FROM c7
2695598d2028Sdan  }
2696598d2028Sdan} {}
26978e9f6aedSdando_test e_fkey-59.2 {
2698598d2028Sdan  execsql { INSERT INTO c7 VALUES('a', 'b') }
2699598d2028Sdan  execsql {
2700598d2028Sdan    BEGIN;
2701598d2028Sdan      DROP TABLE p;
2702598d2028Sdan  }
2703598d2028Sdan} {}
27048e9f6aedSdando_test e_fkey-59.3 {
2705598d2028Sdan  catchsql COMMIT
2706f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
27078e9f6aedSdando_test e_fkey-59.4 {
2708598d2028Sdan  execsql { CREATE TABLE p(a, b, PRIMARY KEY(a, b)) }
2709598d2028Sdan  catchsql COMMIT
2710f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
27118e9f6aedSdando_test e_fkey-59.5 {
2712598d2028Sdan  execsql { INSERT INTO p VALUES('a', 'b') }
2713598d2028Sdan  execsql COMMIT
2714598d2028Sdan} {}
2715598d2028Sdan
2716598d2028Sdan#-------------------------------------------------------------------------
2717598d2028Sdan# Any "foreign key mismatch" errors encountered while running an implicit
2718598d2028Sdan# "DELETE FROM tbl" are ignored.
2719598d2028Sdan#
2720bf3e3a06Sdan# EVIDENCE-OF: R-57242-37005 Any "foreign key mismatch" errors
2721bf3e3a06Sdan# encountered as part of an implicit DELETE are ignored.
2722bf3e3a06Sdan#
2723598d2028Sdandrop_all_tables
27248e9f6aedSdando_test e_fkey-60.1 {
2725598d2028Sdan  execsql {
2726598d2028Sdan    PRAGMA foreign_keys = OFF;
2727598d2028Sdan
2728598d2028Sdan    CREATE TABLE p(a PRIMARY KEY, b REFERENCES nosuchtable);
2729598d2028Sdan    CREATE TABLE c1(c, d, FOREIGN KEY(c, d) REFERENCES a);
2730598d2028Sdan    CREATE TABLE c2(c REFERENCES p(b), d);
2731598d2028Sdan    CREATE TABLE c3(c REFERENCES p ON DELETE SET NULL, d);
2732598d2028Sdan
2733598d2028Sdan    INSERT INTO p VALUES(1, 2);
2734598d2028Sdan    INSERT INTO c1 VALUES(1, 2);
2735598d2028Sdan    INSERT INTO c2 VALUES(1, 2);
2736598d2028Sdan    INSERT INTO c3 VALUES(1, 2);
2737598d2028Sdan  }
2738598d2028Sdan} {}
27398e9f6aedSdando_test e_fkey-60.2 {
2740598d2028Sdan  execsql { PRAGMA foreign_keys = ON }
2741598d2028Sdan  catchsql { DELETE FROM p }
2742598d2028Sdan} {1 {no such table: main.nosuchtable}}
27438e9f6aedSdando_test e_fkey-60.3 {
2744598d2028Sdan  execsql {
2745598d2028Sdan    BEGIN;
2746598d2028Sdan      DROP TABLE p;
2747598d2028Sdan      SELECT * FROM c3;
2748598d2028Sdan    ROLLBACK;
2749598d2028Sdan  }
2750598d2028Sdan} {{} 2}
27518e9f6aedSdando_test e_fkey-60.4 {
2752598d2028Sdan  execsql { CREATE TABLE nosuchtable(x PRIMARY KEY) }
2753598d2028Sdan  catchsql { DELETE FROM p }
27549148defaSdrh} {1 {foreign key mismatch - "c2" referencing "p"}}
27558e9f6aedSdando_test e_fkey-60.5 {
2756598d2028Sdan  execsql { DROP TABLE c1 }
2757598d2028Sdan  catchsql { DELETE FROM p }
27589148defaSdrh} {1 {foreign key mismatch - "c2" referencing "p"}}
27598e9f6aedSdando_test e_fkey-60.6 {
2760598d2028Sdan  execsql { DROP TABLE c2 }
2761598d2028Sdan  execsql { DELETE FROM p }
2762598d2028Sdan} {}
2763598d2028Sdan
2764598d2028Sdan#-------------------------------------------------------------------------
276548864df9Smistachkin# Test that the special behaviors of ALTER and DROP TABLE are only
276648864df9Smistachkin# activated when foreign keys are enabled. Special behaviors are:
2767598d2028Sdan#
2768598d2028Sdan#   1. ADD COLUMN not allowing a REFERENCES clause with a non-NULL
2769598d2028Sdan#      default value.
2770598d2028Sdan#   2. Modifying foreign key definitions when a parent table is RENAMEd.
2771598d2028Sdan#   3. Running an implicit DELETE FROM command as part of DROP TABLE.
2772598d2028Sdan#
2773bf3e3a06Sdan# EVIDENCE-OF: R-54142-41346 The properties of the DROP TABLE and ALTER
2774bf3e3a06Sdan# TABLE commands described above only apply if foreign keys are enabled.
2775bf3e3a06Sdan#
27762841abedSdanifcapable altertable {
27778e9f6aedSdando_test e_fkey-61.1.1 {
2778598d2028Sdan  drop_all_tables
27792629adc7Sdan  execsql { CREATE TABLE t1(a, b) ; INSERT INTO t1 VALUES(1, 2) }
2780598d2028Sdan  catchsql { ALTER TABLE t1 ADD COLUMN c DEFAULT 'xxx' REFERENCES t2 }
2781598d2028Sdan} {1 {Cannot add a REFERENCES column with non-NULL default value}}
27828e9f6aedSdando_test e_fkey-61.1.2 {
2783598d2028Sdan  execsql { PRAGMA foreign_keys = OFF }
2784598d2028Sdan  execsql { ALTER TABLE t1 ADD COLUMN c DEFAULT 'xxx' REFERENCES t2 }
2785598d2028Sdan  execsql { SELECT sql FROM sqlite_master WHERE name = 't1' }
2786598d2028Sdan} {{CREATE TABLE t1(a, b, c DEFAULT 'xxx' REFERENCES t2)}}
27878e9f6aedSdando_test e_fkey-61.1.3 {
2788598d2028Sdan  execsql { PRAGMA foreign_keys = ON }
2789598d2028Sdan} {}
2790598d2028Sdan
27918e9f6aedSdando_test e_fkey-61.2.1 {
2792598d2028Sdan  drop_all_tables
2793598d2028Sdan  execsql {
2794598d2028Sdan    CREATE TABLE p(a UNIQUE);
2795598d2028Sdan    CREATE TABLE c(b REFERENCES p(a));
2796598d2028Sdan    BEGIN;
2797598d2028Sdan      ALTER TABLE p RENAME TO parent;
2798598d2028Sdan      SELECT sql FROM sqlite_master WHERE name = 'c';
2799598d2028Sdan    ROLLBACK;
2800598d2028Sdan  }
2801598d2028Sdan} {{CREATE TABLE c(b REFERENCES "parent"(a))}}
28028e9f6aedSdando_test e_fkey-61.2.2 {
2803598d2028Sdan  execsql {
2804598d2028Sdan    PRAGMA foreign_keys = OFF;
28058e2d4ad3Sdan    PRAGMA legacy_alter_table = ON;
2806598d2028Sdan    ALTER TABLE p RENAME TO parent;
2807598d2028Sdan    SELECT sql FROM sqlite_master WHERE name = 'c';
2808598d2028Sdan  }
2809598d2028Sdan} {{CREATE TABLE c(b REFERENCES p(a))}}
28108e9f6aedSdando_test e_fkey-61.2.3 {
2811598d2028Sdan  execsql { PRAGMA foreign_keys = ON }
28128e2d4ad3Sdan  execsql { PRAGMA legacy_alter_table = OFF }
2813598d2028Sdan} {}
2814598d2028Sdan
28158e9f6aedSdando_test e_fkey-61.3.1 {
2816598d2028Sdan  drop_all_tables
2817598d2028Sdan  execsql {
2818598d2028Sdan    CREATE TABLE p(a UNIQUE);
2819598d2028Sdan    CREATE TABLE c(b REFERENCES p(a) ON DELETE SET NULL);
2820598d2028Sdan    INSERT INTO p VALUES('x');
2821598d2028Sdan    INSERT INTO c VALUES('x');
2822598d2028Sdan    BEGIN;
2823598d2028Sdan      DROP TABLE p;
2824598d2028Sdan      SELECT * FROM c;
2825598d2028Sdan    ROLLBACK;
2826598d2028Sdan  }
2827598d2028Sdan} {{}}
28288e9f6aedSdando_test e_fkey-61.3.2 {
2829598d2028Sdan  execsql {
2830598d2028Sdan    PRAGMA foreign_keys = OFF;
2831598d2028Sdan    DROP TABLE p;
2832598d2028Sdan    SELECT * FROM c;
2833598d2028Sdan  }
2834598d2028Sdan} {x}
28358e9f6aedSdando_test e_fkey-61.3.3 {
2836598d2028Sdan  execsql { PRAGMA foreign_keys = ON }
2837598d2028Sdan} {}
28382841abedSdan}
2839ce374532Sdan
28402140429cSdan###########################################################################
28412140429cSdan### SECTION 6: Limits and Unsupported Features
28422140429cSdan###########################################################################
2843ce374532Sdan
2844ce374532Sdan#-------------------------------------------------------------------------
2845f589450dSdan# Test that MATCH clauses are parsed, but SQLite treats every foreign key
2846f589450dSdan# constraint as if it were "MATCH SIMPLE".
2847f589450dSdan#
2848bf3e3a06Sdan# EVIDENCE-OF: R-24728-13230 SQLite parses MATCH clauses (i.e. does not
2849bf3e3a06Sdan# report a syntax error if you specify one), but does not enforce them.
2850bf3e3a06Sdan#
2851bf3e3a06Sdan# EVIDENCE-OF: R-24450-46174 All foreign key constraints in SQLite are
2852bf3e3a06Sdan# handled as if MATCH SIMPLE were specified.
2853bf3e3a06Sdan#
2854f589450dSdanforeach zMatch [list SIMPLE PARTIAL FULL Simple parTIAL FuLL ] {
2855f589450dSdan  drop_all_tables
28568e9f6aedSdan  do_test e_fkey-62.$zMatch.1 {
2857f589450dSdan    execsql "
2858f589450dSdan      CREATE TABLE p(a, b, c, PRIMARY KEY(b, c));
2859f589450dSdan      CREATE TABLE c(d, e, f, FOREIGN KEY(e, f) REFERENCES p MATCH $zMatch);
2860f589450dSdan    "
2861f589450dSdan  } {}
28628e9f6aedSdan  do_test e_fkey-62.$zMatch.2 {
2863f589450dSdan    execsql { INSERT INTO p VALUES(1, 2, 3)         }
2864f589450dSdan
286548864df9Smistachkin    # MATCH SIMPLE behavior: Allow any child key that contains one or more
2866f589450dSdan    # NULL value to be inserted. Non-NULL values do not have to map to any
2867f589450dSdan    # parent key values, so long as at least one field of the child key is
2868f589450dSdan    # NULL.
2869f589450dSdan    execsql { INSERT INTO c VALUES('w', 2, 3)       }
2870f589450dSdan    execsql { INSERT INTO c VALUES('x', 'x', NULL)  }
2871f589450dSdan    execsql { INSERT INTO c VALUES('y', NULL, 'x')  }
2872f589450dSdan    execsql { INSERT INTO c VALUES('z', NULL, NULL) }
2873f589450dSdan
2874f589450dSdan    # Check that the FK is enforced properly if there are no NULL values
2875f589450dSdan    # in the child key columns.
2876f589450dSdan    catchsql { INSERT INTO c VALUES('a', 2, 4) }
2877f9c8ce3cSdrh  } {1 {FOREIGN KEY constraint failed}}
2878f589450dSdan}
2879f589450dSdan
2880f589450dSdan#-------------------------------------------------------------------------
2881f589450dSdan# Test that SQLite does not support the SET CONSTRAINT statement. And
2882f589450dSdan# that it is possible to create both immediate and deferred constraints.
2883f589450dSdan#
2884bf3e3a06Sdan# EVIDENCE-OF: R-21599-16038 In SQLite, a foreign key constraint is
2885bf3e3a06Sdan# permanently marked as deferred or immediate when it is created.
2886bf3e3a06Sdan#
2887f589450dSdandrop_all_tables
28888e9f6aedSdando_test e_fkey-62.1 {
2889f589450dSdan  catchsql { SET CONSTRAINTS ALL IMMEDIATE }
2890f589450dSdan} {1 {near "SET": syntax error}}
28918e9f6aedSdando_test e_fkey-62.2 {
2892f589450dSdan  catchsql { SET CONSTRAINTS ALL DEFERRED }
2893f589450dSdan} {1 {near "SET": syntax error}}
2894f589450dSdan
28958e9f6aedSdando_test e_fkey-62.3 {
2896f589450dSdan  execsql {
2897f589450dSdan    CREATE TABLE p(a, b, PRIMARY KEY(a, b));
2898f589450dSdan    CREATE TABLE cd(c, d,
2899f589450dSdan      FOREIGN KEY(c, d) REFERENCES p DEFERRABLE INITIALLY DEFERRED);
2900f589450dSdan    CREATE TABLE ci(c, d,
2901f589450dSdan      FOREIGN KEY(c, d) REFERENCES p DEFERRABLE INITIALLY IMMEDIATE);
2902f589450dSdan    BEGIN;
2903f589450dSdan  }
2904f589450dSdan} {}
29058e9f6aedSdando_test e_fkey-62.4 {
2906f589450dSdan  catchsql { INSERT INTO ci VALUES('x', 'y') }
2907f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
29088e9f6aedSdando_test e_fkey-62.5 {
2909f589450dSdan  catchsql { INSERT INTO cd VALUES('x', 'y') }
2910f589450dSdan} {0 {}}
29118e9f6aedSdando_test e_fkey-62.6 {
2912f589450dSdan  catchsql { COMMIT }
2913f9c8ce3cSdrh} {1 {FOREIGN KEY constraint failed}}
29148e9f6aedSdando_test e_fkey-62.7 {
2915f589450dSdan  execsql {
2916f589450dSdan    DELETE FROM cd;
2917f589450dSdan    COMMIT;
2918f589450dSdan  }
2919f589450dSdan} {}
2920f589450dSdan
2921f589450dSdan#-------------------------------------------------------------------------
2922f589450dSdan# Test that the maximum recursion depth of foreign key action programs is
2923f589450dSdan# governed by the SQLITE_MAX_TRIGGER_DEPTH and SQLITE_LIMIT_TRIGGER_DEPTH
2924f589450dSdan# settings.
2925f589450dSdan#
2926bf3e3a06Sdan# EVIDENCE-OF: R-42264-30503 The SQLITE_MAX_TRIGGER_DEPTH and
2927bf3e3a06Sdan# SQLITE_LIMIT_TRIGGER_DEPTH settings determine the maximum allowable
2928bf3e3a06Sdan# depth of trigger program recursion. For the purposes of these limits,
2929bf3e3a06Sdan# foreign key actions are considered trigger programs.
2930bf3e3a06Sdan#
2931f589450dSdanproc test_on_delete_recursion {limit} {
2932f589450dSdan  drop_all_tables
2933f589450dSdan  execsql {
2934f589450dSdan    BEGIN;
2935f589450dSdan    CREATE TABLE t0(a PRIMARY KEY, b);
2936f589450dSdan    INSERT INTO t0 VALUES('x0', NULL);
2937f589450dSdan  }
2938f589450dSdan  for {set i 1} {$i <= $limit} {incr i} {
2939f589450dSdan    execsql "
2940f589450dSdan      CREATE TABLE t$i (
2941f589450dSdan        a PRIMARY KEY, b REFERENCES t[expr $i-1] ON DELETE CASCADE
2942f589450dSdan      );
2943f589450dSdan      INSERT INTO t$i VALUES('x$i', 'x[expr $i-1]');
2944f589450dSdan    "
2945f589450dSdan  }
2946f589450dSdan  execsql COMMIT
2947f589450dSdan  catchsql "
2948f589450dSdan    DELETE FROM t0;
2949f589450dSdan    SELECT count(*) FROM t$limit;
2950f589450dSdan  "
2951f589450dSdan}
2952f589450dSdanproc test_on_update_recursion {limit} {
2953f589450dSdan  drop_all_tables
2954f589450dSdan  execsql {
2955f589450dSdan    BEGIN;
2956f589450dSdan    CREATE TABLE t0(a PRIMARY KEY);
2957f589450dSdan    INSERT INTO t0 VALUES('xxx');
2958f589450dSdan  }
2959f589450dSdan  for {set i 1} {$i <= $limit} {incr i} {
2960f589450dSdan    set j [expr $i-1]
2961f589450dSdan
2962f589450dSdan    execsql "
2963f589450dSdan      CREATE TABLE t$i (a PRIMARY KEY REFERENCES t$j ON UPDATE CASCADE);
2964f589450dSdan      INSERT INTO t$i VALUES('xxx');
2965f589450dSdan    "
2966f589450dSdan  }
2967f589450dSdan  execsql COMMIT
2968f589450dSdan  catchsql "
2969f589450dSdan    UPDATE t0 SET a = 'yyy';
2970f589450dSdan    SELECT NOT (a='yyy') FROM t$limit;
2971f589450dSdan  "
2972f589450dSdan}
2973f589450dSdan
2974afcf9bd8Sdan# If the current build was created using clang with the -fsanitize=address
2975afcf9bd8Sdan# switch, then the library uses considerably more stack space than usual.
2976afcf9bd8Sdan# So much more, that some of the following tests cause stack overflows
2977afcf9bd8Sdan# if they are run under this configuration.
2978afcf9bd8Sdan#
2979afcf9bd8Sdanif {[clang_sanitize_address]==0} {
29808e9f6aedSdan  do_test e_fkey-63.1.1 {
2981f589450dSdan    test_on_delete_recursion $SQLITE_MAX_TRIGGER_DEPTH
2982f589450dSdan  } {0 0}
29838e9f6aedSdan  do_test e_fkey-63.1.2 {
2984f589450dSdan    test_on_delete_recursion [expr $SQLITE_MAX_TRIGGER_DEPTH+1]
2985f589450dSdan  } {1 {too many levels of trigger recursion}}
29868e9f6aedSdan  do_test e_fkey-63.1.3 {
2987f589450dSdan    sqlite3_limit db SQLITE_LIMIT_TRIGGER_DEPTH 5
2988f589450dSdan      test_on_delete_recursion 5
2989f589450dSdan  } {0 0}
29908e9f6aedSdan  do_test e_fkey-63.1.4 {
2991f589450dSdan    test_on_delete_recursion 6
2992f589450dSdan  } {1 {too many levels of trigger recursion}}
29938e9f6aedSdan  do_test e_fkey-63.1.5 {
2994f589450dSdan    sqlite3_limit db SQLITE_LIMIT_TRIGGER_DEPTH 1000000
2995f589450dSdan  } {5}
29968e9f6aedSdan  do_test e_fkey-63.2.1 {
2997f589450dSdan    test_on_update_recursion $SQLITE_MAX_TRIGGER_DEPTH
2998f589450dSdan  } {0 0}
29998e9f6aedSdan  do_test e_fkey-63.2.2 {
3000f589450dSdan    test_on_update_recursion [expr $SQLITE_MAX_TRIGGER_DEPTH+1]
3001f589450dSdan  } {1 {too many levels of trigger recursion}}
30028e9f6aedSdan  do_test e_fkey-63.2.3 {
3003f589450dSdan    sqlite3_limit db SQLITE_LIMIT_TRIGGER_DEPTH 5
3004f589450dSdan      test_on_update_recursion 5
3005f589450dSdan  } {0 0}
30068e9f6aedSdan  do_test e_fkey-63.2.4 {
3007f589450dSdan    test_on_update_recursion 6
3008f589450dSdan  } {1 {too many levels of trigger recursion}}
30098e9f6aedSdan  do_test e_fkey-63.2.5 {
3010f589450dSdan    sqlite3_limit db SQLITE_LIMIT_TRIGGER_DEPTH 1000000
3011f589450dSdan  } {5}
3012afcf9bd8Sdan}
3013f589450dSdan
3014f589450dSdan#-------------------------------------------------------------------------
3015f589450dSdan# The setting of the recursive_triggers pragma does not affect foreign
3016f589450dSdan# key actions.
3017f589450dSdan#
30181f8bb4b0Sdrh# EVIDENCE-OF: R-44355-00270 The PRAGMA recursive_triggers setting does
30191f8bb4b0Sdrh# not affect the operation of foreign key actions.
3020bf3e3a06Sdan#
3021f589450dSdanforeach recursive_triggers_setting [list 0 1 ON OFF] {
3022f589450dSdan  drop_all_tables
3023f589450dSdan  execsql "PRAGMA recursive_triggers = $recursive_triggers_setting"
3024f589450dSdan
30258e9f6aedSdan  do_test e_fkey-64.$recursive_triggers_setting.1 {
3026f589450dSdan    execsql {
3027f589450dSdan      CREATE TABLE t1(a PRIMARY KEY, b REFERENCES t1 ON DELETE CASCADE);
3028f589450dSdan      INSERT INTO t1 VALUES(1, NULL);
3029f589450dSdan      INSERT INTO t1 VALUES(2, 1);
3030f589450dSdan      INSERT INTO t1 VALUES(3, 2);
3031f589450dSdan      INSERT INTO t1 VALUES(4, 3);
3032f589450dSdan      INSERT INTO t1 VALUES(5, 4);
3033f589450dSdan      SELECT count(*) FROM t1;
3034f589450dSdan    }
3035f589450dSdan  } {5}
30368e9f6aedSdan  do_test e_fkey-64.$recursive_triggers_setting.2 {
3037f589450dSdan    execsql { SELECT count(*) FROM t1 WHERE a = 1 }
3038f589450dSdan  } {1}
30398e9f6aedSdan  do_test e_fkey-64.$recursive_triggers_setting.3 {
3040f589450dSdan    execsql {
3041f589450dSdan      DELETE FROM t1 WHERE a = 1;
3042f589450dSdan      SELECT count(*) FROM t1;
3043f589450dSdan    }
3044f589450dSdan  } {0}
3045f589450dSdan}
3046f589450dSdan
3047f589450dSdanfinish_test
3048