genfkey.README 6.3 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138
  1. OVERVIEW
  2. The SQLite library is capable of parsing SQL foreign key constraints
  3. supplied as part of CREATE TABLE statements, but it does not actually
  4. implement them. However, most of the features of foreign keys may be
  5. implemented using SQL triggers, which SQLite does support. This text
  6. file describes a feature of the SQLite shell tool (sqlite3) that
  7. extracts foreign key definitions from an existing SQLite database and
  8. creates the set of CREATE TRIGGER statements required to implement
  9. the foreign key constraints.
  10. CAPABILITIES
  11. An SQL foreign key is a constraint that requires that each row in
  12. the "child" table corresponds to a row in the "parent" table. For
  13. example, the following schema:
  14. CREATE TABLE parent(a, b, c, PRIMARY KEY(a, b));
  15. CREATE TABLE child(d, e, f, FOREIGN KEY(d, e) REFERENCES parent(a, b));
  16. implies that for each row in table "child", there must be a row in
  17. "parent" for which the expression (child.d==parent.a AND child.e==parent.b)
  18. is true. The columns in the parent table are required to be either the
  19. primary key columns or subject to a UNIQUE constraint. There is no such
  20. requirement for the columns of the child table.
  21. At this time, all foreign keys are implemented as if they were
  22. "MATCH NONE", even if the declaration specified "MATCH PARTIAL" or
  23. "MATCH FULL". "MATCH NONE" means that if any of the key columns in
  24. the child table are NULL, then there is no requirement for a corresponding
  25. row in the parent table. So, taking this into account, the expression that
  26. must be true for every row of the child table in the above example is
  27. actually:
  28. (child.d IS NULL) OR
  29. (child.e IS NULL) OR
  30. (child.d==parent.a AND child.e==parent.b)
  31. Attempting to insert or update a row in the child table so that the
  32. affected row violates this constraint results in an exception being
  33. thrown.
  34. The effect of attempting to delete or update a row in the parent table
  35. so that the constraint becomes untrue for one or more rows in the child
  36. table depends on the "ON DELETE" or "ON UPDATE" actions specified as
  37. part of the foreign key definition, respectively. Three different actions
  38. are supported: "RESTRICT" (the default), "CASCADE" and "SET NULL". SQLite
  39. will also parse the "SET DEFAULT" action, but this is not implemented
  40. and "RESTRICT" is used instead.
  41. RESTRICT: Attempting to update or delete a row in the parent table so
  42. that the constraint becomes untrue for one or more rows in
  43. the child table is not allowed. An exception is thrown.
  44. CASCADE: Instead of throwing an exception, all corresponding child table
  45. rows are either deleted (if the parent row is being deleted)
  46. or updated to match the new parent key values (if the parent
  47. row is being updated).
  48. SET NULL: Instead of throwing an exception, the foreign key fields of
  49. all corresponding child table rows are set to NULL.
  50. LIMITATIONS
  51. Apart from those limitiations described above:
  52. * Implicit mapping to composite primary keys is not supported. If
  53. a parent table has a composite primary key, then any child table
  54. that refers to it must explicitly map each column. For example, given
  55. the following definition of table "parent":
  56. CREATE TABLE parent(a, b, c, PRIMARY KEY(a, b));
  57. only the first of the following two definitions of table "child"
  58. is supported:
  59. CREATE TABLE child(d, e, f, FOREIGN KEY(d, e) REFERENCES parent(a, b));
  60. CREATE TABLE child(d, e, f, FOREIGN KEY(d, e) REFERENCES parent);
  61. An implicit reference to a composite primary key is detected as an
  62. error when the program is run (see below).
  63. * SQLite does not support recursive triggers, and therefore this program
  64. does not support recursive CASCADE or SET NULL foreign key
  65. relationships. If the parent and the child tables of a CASCADE or
  66. SET NULL foreign key are the same table, the generated triggers will
  67. malfunction. This is also true if the recursive foreign key constraint
  68. is indirect (for example if table A references table B which references
  69. table A with a CASCADE or SET NULL foreign key constraint).
  70. Recursive CASCADE or SET NULL foreign key relationships are *not*
  71. detected as errors when the program is run. Buyer beware.
  72. USAGE
  73. The functionality is accessed through an sqlite3 shell tool "dot-command":
  74. .genfkey ?--no-drop? ?--ignore-errors? ?--exec?
  75. When this command is run, it first checks the schema of the open SQLite
  76. database for foreign key related errors or inconsistencies. For example,
  77. a foreign key that refers to a parent table that does not exist, or
  78. a foreign key that refers to columns in a parent table that are not
  79. guaranteed to be unique. If such errors are found and the --ignore-errors
  80. option was not present, a message for each one is printed to stderr and
  81. no further processing takes place.
  82. If errors are found and the --ignore-errors option is passed, then
  83. no error messages are printed. No "CREATE TRIGGER" statements are generated
  84. for foriegn-key definitions that contained errors, they are silently
  85. ignored by subsequent processing.
  86. All triggers generated by this command have names that match the pattern
  87. "genfkey*". Unless the --no-drop option is specified, then the program
  88. also generates a "DROP TRIGGER" statement for each trigger that exists
  89. in the database with a name that matches this pattern. This allows the
  90. program to be used to upgrade a database schema for which foreign key
  91. triggers have already been installed (i.e. after new tables are created
  92. or existing tables dropped).
  93. Finally, a series of SQL trigger definitions (CREATE TRIGGER statements)
  94. that implement the foreign key constraints found in the database schema are
  95. generated.
  96. If the --exec option was passed, then all generated SQL is immediately
  97. executed on the database. Otherwise, the generated SQL strings are output
  98. in the same way as the results of SELECT queries are. Normally, this means
  99. they will be printed to stdout, but this can be configured using other
  100. dot-commands (i.e. ".output").
  101. The simplest way to activate the foriegn key definitions in a database
  102. is simply to open it using the shell tool and enter the command
  103. ".genfkey --exec":
  104. sqlite> .genfkey --exec