-
Notifications
You must be signed in to change notification settings - Fork 43
Foreign keys constraints #3648
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
Foreign keys constraints #3648
Changes from all commits
File filter
Filter by extension
Conversations
Jump to
Diff view
Diff view
There are no files selected for viewing
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,82 @@ | ||
| local fio = require('fio') | ||
| local server = require('luatest.server') | ||
| local t = require('luatest') | ||
| local g = t.group() | ||
| g.before_each(function(cg) | ||
| cg.server = server:new { | ||
| box_cfg = {}, | ||
| workdir = fio.cwd() .. '/tmp' | ||
| } | ||
| cg.server:start() | ||
| end) | ||
|
|
||
| g.after_each(function(cg) | ||
| cg.server:stop() | ||
| cg.server:drop() | ||
| end) | ||
|
|
||
| g.test_space_is_updated = function(cg) | ||
| cg.server:exec(function() | ||
| box.execute([[SET SESSION "sql_seq_scan" = true;]]) | ||
| box.execute([[ | ||
| -- create_parent_start | ||
| CREATE TABLE author ( | ||
| id INTEGER PRIMARY KEY, | ||
| name STRING NOT NULL | ||
| ); | ||
| -- create_parent_end | ||
| ]]) | ||
| box.execute([[ | ||
| -- insert_parent_start | ||
| INSERT INTO author VALUES (1, 'Leo Tolstoy'), | ||
| (2, 'Fyodor Dostoevsky'); | ||
| -- insert_parent_end | ||
| ]]) | ||
| box.execute([[ | ||
| -- create_child_start | ||
| CREATE TABLE book ( | ||
| id INTEGER PRIMARY KEY, | ||
| title STRING NOT NULL, | ||
| author_id INTEGER NOT NULL UNIQUE, | ||
| FOREIGN KEY (author_id) | ||
| REFERENCES author (id) | ||
| ); | ||
| -- create_child_end | ||
| ]]) | ||
| box.execute([[ | ||
| -- insert_child_start | ||
| INSERT INTO book VALUES (1, 'War and Peace', 1), | ||
| (2, 'Crime and Punishment', 2); | ||
| -- insert_child_end | ||
| ]]) | ||
| local _, insert_err = box.execute([[ | ||
| -- insert_error_start | ||
| INSERT INTO book VALUES (3, 'Eugene Onegin', 3); | ||
| /* | ||
| - 'Foreign key constraint ''fk_unnamed_BOOK_1'' failed: foreign tuple was not found' | ||
| */ | ||
| -- insert_error_end | ||
| ]]) | ||
| local _, update_err = box.execute([[ | ||
| -- update_error_start | ||
| UPDATE book SET author_id = 10 WHERE id = 1; | ||
| /* | ||
| - 'Foreign key constraint ''fk_unnamed_BOOK_1'' failed: foreign tuple was not found' | ||
| */ | ||
| -- update_error_end | ||
| ]]) | ||
| local _, delete_err = box.execute([[ | ||
| -- delete_error_start | ||
| DELETE FROM author WHERE id = 2; | ||
| /* | ||
| - 'Foreign key ''fk_unnamed_BOOK_1'' integrity check failed: tuple is referenced' | ||
| */ | ||
| -- delete_error_end | ||
| ]]) | ||
|
|
||
| -- Tests | ||
| t.assert_equals(insert_err:unpack().message, "Foreign key constraint 'fk_unnamed_BOOK_1' failed: foreign tuple was not found") | ||
| t.assert_equals(update_err:unpack().message, "Foreign key constraint 'fk_unnamed_BOOK_1' failed: foreign tuple was not found") | ||
| t.assert_equals(delete_err:unpack().message, "Foreign key 'fk_unnamed_BOOK_1' integrity check failed: tuple is referenced") | ||
| end) | ||
| end |
| Original file line number | Diff line number | Diff line change |
|---|---|---|
|
|
@@ -404,18 +404,18 @@ The column-constraint or default clause may be as follows: | |
| * - NOT NULL | ||
| - means "it is illegal to assign a NULL to this column" | ||
| * - PRIMARY KEY | ||
| - explained in the later section | ||
| :ref:`"Table Constraint Definition" <sql_table_constraint_def>` | ||
| - explained in the | ||
| :ref:`Table constraint definition <sql_table_constraint_def>` section | ||
| * - UNIQUE | ||
| - explained in the later section | ||
| "Table Constraint Definition" | ||
| - explained in the | ||
| :ref:`Table constraint definition <sql_table_constraint_def>` section | ||
| * - CHECK (expression) | ||
| - explained in the later section | ||
| "Table Constraint Definition" | ||
| - explained in the | ||
| :ref:`Table constraint definition <sql_table_constraint_def>` section | ||
| * - foreign-key-clause | ||
| - explained in the later section | ||
| :ref:`"Table Constraint Definition for foreign keys" | ||
| <sql_foreign_key>` | ||
| - explained in the | ||
| :ref:`Table constraint definition for foreign keys | ||
| <sql_foreign_key>` section | ||
| * - DEFAULT expression | ||
| - means | ||
| "if INSERT does not assign to this column | ||
|
|
@@ -493,7 +493,7 @@ Data types may also appear in :ref:`CAST <sql_function_cast>` functions. | |
| .. _sql_table_constraint_def: | ||
|
|
||
| ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++ | ||
| Table Constraint Definition | ||
| Table constraint definition | ||
| ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++ | ||
|
|
||
| Syntax: | ||
|
|
@@ -617,143 +617,93 @@ causes no error message, although (s1, s1) is probably a user error. | |
| .. _sql_foreign_key: | ||
|
|
||
| ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++ | ||
| Table Constraint Definition for foreign keys | ||
| Table constraint definition for foreign keys | ||
| ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++ | ||
|
|
||
| FOREIGN KEY constraints look like this: |br| | ||
| :samp:`FOREIGN KEY ({referencing-column-name} [, {referencing-column-name}...]) REFERENCES {referenced-table-name} [({referenced-column-name} [, {referenced-column-name}...]]) [MATCH FULL] [update-or-delete-rules]` | ||
| A :ref:`foreign key <index-box_foreign_keys>` is a constraint that can be used to enforce data integrity across related tables. | ||
| A foreign key constraint is defined on the child table that references the parent table's column values. | ||
|
|
||
| There is a shorthand: specifying REFERENCES in a :ref:`column definition <sql_column_def_constraint>`. | ||
|
|
||
| The referencing column names must be defined in the table that is being created. | ||
| The referenced table name must refer to a table that already exists, | ||
| or to the table that is being created. | ||
| The referenced column names must be defined in the referenced table, | ||
| and have similar data types. | ||
| There must be a PRIMARY KEY or UNIQUE constraint or UNIQUE index on the referenced column names. | ||
|
|
||
| The words MATCH FULL are optional and have no effect. | ||
|
|
||
| If a foreign-key constraint exists, then the values in the referencing columns | ||
| must equal values in the referenced columns of the referenced table, | ||
| or at least one of the referencing columns must contain NULL. | ||
|
|
||
| Examples: | ||
| Foreign key constraints look like this: | ||
|
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. I see that the described FK constraint is known as the FK tuple constraint. What about the FK field constraint? I'm not sure if the FK description should be duplicated due to different types of constraints, but they have different error descriptions and are described differently in '_space', so at least add a quick overview of that and links to 'tuple constraint' and ' field constraint ' looks like a good idea.
Contributor
Author
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. Looks like this requires some investigation, created a separate ticket: #3703 |
||
|
|
||
| .. code-block:: sql | ||
|
|
||
| -- A foreign key referencing a primary key in the same table | ||
| CREATE TABLE t1 (s1 INTEGER PRIMARY KEY, s2 INTEGER, FOREIGN KEY (s2) REFERENCES t1 (s1)); | ||
| -- The same thing with column shorthand | ||
| CREATE TABLE t1 (s1 INTEGER PRIMARY KEY, s2 INTEGER REFERENCES t1(s1)); | ||
| -- An attempt to violate the constraint -- this will fail | ||
| INSERT INTO t1 VALUES (1, 2); | ||
| -- A NULL in the referencing column -- this will succeed | ||
| INSERT INTO t1 VALUES (1, NULL); | ||
| -- A reference to a primary key that now exists -- this will succeed | ||
| INSERT INTO t1 VALUES (2, 1); | ||
|
|
||
| The optional update-or-delete rules look like this: |br| | ||
| ``ON {UPDATE|DELETE} { CASCADE | SET DEFAULT | SET NULL | RESTRICT | NO ACTION}`` |br| | ||
| and the idea is: if something changes the referenced key, then one of these possible "referential actions" takes place: |br| | ||
| ``CASCADE``: the change that is applied for the referenced key is applied for the referencing key. |br| | ||
| ``SET DEFAULT``: the referencing key is set to its default value. |br| | ||
| ``SET NULL``: the referencing key is set to NULL. |br| | ||
| ``RESTRICT``: the UPDATE or DELETE fails if a referencing key exists; checked immediately. |br| | ||
| ``NO ACTION``: the UPDATE or DELETE fails if a referencing key exists; checked at statement end. |br| | ||
| The default is ``NO ACTION``. | ||
| FOREIGN KEY ({referencing_column_name} [, {referencing_column_name}...]) | ||
| REFERENCES {referenced_table_name} [({referenced_column_name} [, {referenced_column_name}...]]) | ||
|
|
||
| For example: | ||
| You can also add a reference in a :ref:`column definition <sql_column_def_constraint>`: | ||
|
|
||
| .. code-block:: sql | ||
|
|
||
| CREATE TABLE f1 (ordinal INTEGER PRIMARY KEY, | ||
| referenced_planet STRING UNIQUE NOT NULL); | ||
| CREATE TABLE f2 ( | ||
| ordinal INTEGER PRIMARY KEY, | ||
| referring_planet STRING DEFAULT 'Earth', | ||
| FOREIGN KEY (referring_planet) REFERENCES f1 (referenced_planet) | ||
| ON UPDATE SET DEFAULT | ||
| ON DELETE CASCADE); | ||
| INSERT INTO f1 VALUES (1, 'Mercury'), (2,' Venus'), (3, 'Earth'); | ||
| INSERT INTO f2 VALUES (1, 'Mercury'), (2, 'Mercury'); | ||
| UPDATE f1 SET referenced_planet = 'Mars' | ||
| WHERE referenced_planet = 'Mercury'; | ||
| SELECT * FROM f2; | ||
| DELETE FROM f1 WHERE referenced_planet = 'Earth'; | ||
| SELECT * FROM f2; | ||
| ... In this example, the UPDATE statement changes the referenced key, | ||
| and the clause is ON UPDATE SET DEFAULT, therefore both of the | ||
| rows in f2 have referring_planet set to their default value, | ||
| which is 'Earth'. The DELETE statement deletes the row that | ||
| has 'Earth', and the clause is ON DELETE CASCADE, | ||
| therefore both of the rows in f2 are deleted. | ||
| {referencing_column_name} {column_definition} | ||
| REFERENCES {referenced_table_name}({referenced_column_name}) | ||
|
|
||
| Limitations: |br| | ||
| * Foreign keys can have a MATCH clause (`Issue#3455 <https://github.com/tarantool/tarantool/issues/3455>`_). | ||
| .. NOTE:: | ||
|
|
||
| .. COMMENT | ||
| Constraint Conflict Clauses are temporarily disabled. | ||
| However, the description is here, as a big comment. | ||
| Since :doc:`2.11.0 </release/2.11.0>`, the following referencing options aren't supported anymore: | ||
|
|
||
| Constraint Conflict Clauses | ||
| * The ``ON UPDATE`` and ``ON DELETE`` triggers. The ``RESTRICT`` trigger action is used implicitly. | ||
| * The ``MATCH`` subclause. ``MATCH FULL`` is used implicitly. | ||
| * ``DEFERRABLE`` constraints. The ``INITIALLY IMMEDIATE`` constraint check time rule is used implicitly. | ||
|
|
||
| In a CREATE TABLE statement: | ||
| CREATE TABLE ... constraint-definition ON CONFLICT {ABORT | FAIL | IGNORE | REPLACE | ROLLBACK} ...; | ||
| Note that a referenced column should meet one of the following requirements: | ||
|
|
||
| In an INSERT or UPDATE statement: | ||
| {INSERT|UPDATE} OR {ABORT | FAIL | IGNORE | REPLACE | ROLLBACK} ...; | ||
| - A referenced column is a PRIMARY KEY column. | ||
| - A referenced column has a UNIQUE constraint. | ||
| - A referenced column has a UNIQUE index. | ||
|
|
||
| The standard way to handle a constraint violation is "statement rollback" -- all rows affected by the statement are restored to their original values -- and an error is returned. However, Tarantool allows the user to specify non-standard ways to handle PRIMARY KEY, UNIQUE, CHECK, and NOT NULL constraint violations. | ||
| **Example** | ||
|
|
||
| ABORT -- do statement rollback and return an error. This is the default and is recommended, so a user's best strategy is to never use constraint conflict clauses. | ||
| This example shows how to create a relation between the parent and child tables through a single-column foreign key: | ||
|
|
||
| FAIL -- return an error but do not do statement rollback. | ||
| 1. First, create a parent ``author`` table: | ||
|
Contributor
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. Nit: "first", "then", and similar words are usually redundant in procedures with numbered steps. |
||
|
|
||
| IGNORE -- do not insert or update the row whose update would cause an error, but do not do statement rollback and do not return an error. Due to optimizations related to NoSQL, handling with IGNORE may be slightly faster than handling with ABORT. | ||
| .. literalinclude:: /code_snippets/test/sql/foreign_key_table_constraint_test.lua | ||
| :language: sql | ||
| :start-after: create_parent_start | ||
| :end-before: create_parent_end | ||
| :dedent: | ||
|
|
||
| REPLACE -- (for a UNIQUE or PRIMARY KEY constraint) -- instead of inserting a new row, delete the old row before putting in the new one; (for a NOT NULL constraint for a column that has a non-NULL default value) replace the NULL value with the column's default value; (for a NOT NULL constraint for a column that has a NULL default value) do statement rollback and return an error; (for a CHECK constraint) -- do statement rollback and return an error. If REPLACE action causes a row to be deleted, and if PRAGMA recursive_triggers was specified earlier, then delete triggers (if any) are activated. | ||
| Then, insert data to this table: | ||
|
|
||
| ROLLBACK -- do transaction rollback and return an error. | ||
| .. literalinclude:: /code_snippets/test/sql/foreign_key_table_constraint_test.lua | ||
| :language: sql | ||
| :start-after: insert_parent_start | ||
| :end-before: insert_parent_end | ||
| :dedent: | ||
|
|
||
| The order of constraint evaluation is described in section Order of Execution in Data-Change Statements. | ||
| 2. Create a child ``book`` table whose ``author_id`` column references the ``id`` column from the ``author`` table: | ||
|
|
||
| For example, suppose a new table t has one column and the column has a unique constraint. | ||
| A transaction starts with START TRANSACTION. | ||
| The first statement in the transaction is INSERT INTO t VALUES (1), (2); | ||
| that is, "insert 1, then insert 2" -- Tarantool processes the new rows in order. | ||
| This statement always succeeds, there are no constraint violations. | ||
| The second SQL statement is INSERT INTO t VALUES (3), (2), (5); | ||
| that is, "insert 3, then insert 2". | ||
| Inserting 3 is not a problem, but inserting 2 is a problem -- it would violate the UNIQUE constraint. | ||
| .. literalinclude:: /code_snippets/test/sql/foreign_key_table_constraint_test.lua | ||
| :language: sql | ||
| :start-after: create_child_start | ||
| :end-before: create_child_end | ||
| :dedent: | ||
|
|
||
| If behavior is ABORT: the second statement is rolled back, there is an error message. The table now contains (1), (2). | ||
| Insert data to the ``book`` table: | ||
|
|
||
| If behavior is FAIL: the second statement is not rolled back, there is an error message. The table now contains (1), (2), (3). | ||
| .. literalinclude:: /code_snippets/test/sql/foreign_key_table_constraint_test.lua | ||
| :language: sql | ||
| :start-after: insert_child_start | ||
| :end-before: insert_child_end | ||
| :dedent: | ||
|
|
||
| If behavior is IGNORE: the second statement is not rolled back, the (2) is not inserted, there is no error message. The table now contains (1), (2), (3), (5). | ||
| 3. Check how the created foreign key constraint enforces data integrity. | ||
| The following error is raised on an attempt to insert a new book with the ``author_id`` value that doesn't exist in the parent ``author`` table: | ||
|
|
||
| If behavior is REPLACE: the second statement is not rolled back, the first (2) is replaced by the second (2), there is no error message. The table now contains (1), (2), (3), (5). | ||
| .. literalinclude:: /code_snippets/test/sql/foreign_key_table_constraint_test.lua | ||
| :language: sql | ||
| :start-after: insert_error_start | ||
| :end-before: insert_error_end | ||
| :dedent: | ||
|
|
||
| If behavior is ROLLBACK: the statement is rolled back, and the first statement is rolled back, | ||
| and there is an error message. The table now contains nothing. | ||
| On an attempt to delete an author that already has books in the ``book`` table, the following error is raised: | ||
|
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. The error shown is actually not what I expected from the description. This is a new limitation for FKs: referencing fields must now have an index in order to remove anything from the referenced space. Otherwise, we will not be able to remove from the referenced space, even if the row is not referenced. For example, if we add To receive expected error I suggest to replace by and mention why we add UNIQUE constraint here. Then the error will be: |
||
|
|
||
| There are two ways to specify the behavior: at the end of the CREATE TABLE statement constraint clause, or as an extra clause in an INSERT or UPDATE statement. Specification in the INSERT or UPDATE statement takes precedence. | ||
| .. literalinclude:: /code_snippets/test/sql/foreign_key_table_constraint_test.lua | ||
| :language: sql | ||
| :start-after: delete_error_start | ||
| :end-before: delete_error_end | ||
| :dedent: | ||
|
|
||
| Another example: | ||
| DROP TABLE t1; | ||
| CREATE TABLE t1 (s1 INTEGER PRIMARY KEY ON CONFLICT REPLACE, s2 INTEGER); | ||
| INSERT INTO t1 VALUES (1, NULL); -- now t1 contains (1,NULL) | ||
| INSERT INTO t1 VALUES (1, 1); -- now t1 contains (1, 1) | ||
| INSERT OR ABORT INTO t1 VALUES (1, 2); -- now t1 contains (1, 1) | ||
| INSERT OR IGNORE INTO t1 VALUES (1, 2), (3, 4); -- now t1 contains (1, 1), (3, 4) | ||
| PRAGMA recursive_triggers(true); | ||
| CREATE TRIGGER t1d | ||
| AFTER DELETE ON t1 FOR EACH ROW | ||
| BEGIN | ||
| INSERT INTO t1 VALUES (18, 25); | ||
| END; | ||
| INSERT INTO t1 VALUES (1, 4); -- now t1 contains (1, 4), (3, 4), (18, 35) | ||
|
|
||
| .. _sql_drop_table: | ||
|
|
||
|
|
||
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Maybe link to box foreign keys documentation? https://www.tarantool.io/en/doc/latest/concepts/data_model/value_store/#foreign-keys