Skip to content
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

Multiple foreign key constraints can exist on the same column #7110

Merged
merged 1 commit into from
Apr 13, 2020
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 0 additions & 1 deletion _includes/v20.1/performance/overview.md
Original file line number Diff line number Diff line change
Expand Up @@ -32,7 +32,6 @@ A few notes about the schema:
- There are just three self-explanatory tables: In essence, `users` represents the people registered for the service, `vehicles` represents the pool of vehicles for the service, and `rides` represents when and where users have participated.
- Each table has a composite primary key, with `city` being first in the key. Although not necessary initially in the single-region deployment, once you scale the cluster to multiple regions, these compound primary keys will enable you to [geo-partition data at the row level](partitioning.html#partition-using-primary-key) by `city`. As such, this tutorial demonstrates a schema designed for future scaling.
- The [`IMPORT`](import.html) feature you'll use to import the data does not support foreign keys, so you'll import the data without [foreign key constraints](foreign-key.html). However, the import will create the secondary indexes required to add the foreign keys later.
- The `rides` table contains both `city` and the seemingly redundant `vehicle_city`. This redundancy is necessary because, while it is not possible to apply more than one foreign key constraint to a single column, you will need to apply two foreign key constraints to the `rides` table, and each will require city as part of the constraint. The duplicate `vehicle_city`, which is kept in sync with `city` via a [`CHECK` constraint](check.html), lets you overcome [this limitation](https://github.com/cockroachdb/cockroach/issues/23580).

### Important concepts

Expand Down
126 changes: 118 additions & 8 deletions v20.1/foreign-key.md
Original file line number Diff line number Diff line change
Expand Up @@ -11,14 +11,17 @@ For example, given an `orders` table and a `customers` table, if you create a co
- Each value inserted or updated in `orders.customer_id` must exactly match a value in `customers.id`, or be `NULL`.
- Values in `customers.id` that are referenced by `orders.customer_id` cannot be deleted or updated, unless you have [cascading actions](#use-a-foreign-key-constraint-with-cascade). However, values of `customers.id` that are _not_ present in `orders.customer_id` can be deleted or updated.

{{site.data.alerts.callout_info}}
<span class="version-tag">New in v20.1:</span> A single column can have multiple foreign key constraints. For an example, see [Add multiple foreign key constraints to a single column](#add-multiple-foreign-key-constraints-to-a-single-column).
{{site.data.alerts.end}}

## Details

### Rules for creating foreign keys

**Foreign Key Columns**

- Foreign key columns must use their referenced column's [type](data-types.html).
- Each column cannot belong to more than 1 `FOREIGN KEY` constraint.
- A foreign key column cannot be a [computed column](computed-columns.html).
- Foreign key columns must be [indexed](indexes.html).

Expand Down Expand Up @@ -75,14 +78,9 @@ A `NOT NULL` constraint cannot be added to existing tables.

### Composite foreign key matching

By default, composite foreign keys are matched using the `MATCH SIMPLE` algorithm (which is the same default as Postgres). `MATCH FULL` is available if specified.

In versions 2.1 and earlier, the only option for composite foreign key matching was an incorrect implementation of `MATCH FULL`. This allowed null values in the referencing key columns to correspond to null values in the referenced key columns. This was incorrect in two ways:

1. `MATCH FULL` should not allow mixed null and non-null values. See below for more details on the differences between comparison methods.
2. Null values cannot ever be compared to each other.
By default, composite foreign keys are matched using the `MATCH SIMPLE` algorithm (which is the same default as Postgres). `MATCH FULL` is available if specified. You can specify both `MATCH FULL` and `MATCH SIMPLE`.

To correct these issues, all composite key matches defined prior to version 19.1 will now use the `MATCH SIMPLE` comparison method. We have also added the ability to specify both `MATCH FULL` and `MATCH SIMPLE`. If you had a composite foreign key constraint and have just upgraded to version 19.1, then please check that `MATCH SIMPLE` works for your schema and consider replacing that foreign key constraint with a `MATCH FULL` one.
All composite key matches defined prior to version 19.1 use the `MATCH SIMPLE` comparison method. If you had a composite foreign key constraint and have just upgraded to version 19.1, then please check that `MATCH SIMPLE` works for your schema and consider replacing that foreign key constraint with a `MATCH FULL` one.

#### How it works

Expand Down Expand Up @@ -129,6 +127,10 @@ Parameter | Description
`ON DELETE SET NULL` / `ON UPDATE SET NULL` | When a referenced foreign key is deleted or updated, respectively, the columns of all rows referencing that key will be set to `NULL`. The column must allow `NULL` or this update will fail.
`ON DELETE SET DEFAULT` / `ON UPDATE SET DEFAULT` | When a referenced foreign key is deleted or updated, the columns of all rows referencing that key are set to the default value for that column. <br/><br/> If the default value for the column is null, or if no default value is provided and the column does not have a [`NOT NULL`](not-null.html) constraint, this will have the same effect as `ON DELETE SET NULL` or `ON UPDATE SET NULL`. The default value must still conform with all other constraints, such as `UNIQUE`.

{{site.data.alerts.callout_info}}
<span class="version-tag">New in v20.1:</span> If a foreign key column has multiple constraints that reference the same column, the foreign key action that is specified by the first foreign key takes precedence. For an example, see [Add multiple foreign key constraints to a single column](#add-multiple-foreign-key-constraints-to-a-single-column).
{{site.data.alerts.end}}

### Performance

Because the foreign key constraint requires per-row checks on two tables, statements involving foreign key or referenced columns can take longer to execute. You're most likely to notice this with operations like bulk inserts into the table with the foreign keys. For bulk inserts into new tables, use the [`IMPORT`](import.html) statement instead of [`INSERT`](insert.html).
Expand Down Expand Up @@ -718,6 +720,114 @@ Deleting and updating values in the `customers_5` table sets the referenced valu
(4 rows)
~~~

### Add multiple foreign key constraints to a single column

<span class="version-tag">New in v20.1:</span> You can add more than one foreign key constraint to a single column.

For example, if you create the following tables:

{% include copy-clipboard.html %}
~~~ sql
> CREATE TABLE customers (
id INT PRIMARY KEY,
name STRING,
email STRING
);
~~~

{% include copy-clipboard.html %}
~~~ sql
> CREATE TABLE orders (
id INT PRIMARY KEY,
customer_id INT UNIQUE,
item_number INT
);
~~~

You can create a table with a column that references columns in both the `customers` and `orders` tables:

{% include copy-clipboard.html %}
~~~ sql
> CREATE TABLE shipments (
tracking_number UUID DEFAULT gen_random_uuid() PRIMARY KEY,
carrier STRING,
status STRING,
customer_id INT,
CONSTRAINT fk_customers FOREIGN KEY (customer_id) REFERENCES customers(id),
CONSTRAINT fk_orders FOREIGN KEY (customer_id) REFERENCES orders(customer_id)
);
~~~

Inserts into the `shipments` table must fulfill both foreign key constraints on `customer_id` (`fk_customers` and `fk_customers_2`).

Let's insert a record into each table:

{% include copy-clipboard.html %}
~~~ sql
> INSERT INTO customers VALUES (1001, 'Alexa', '[email protected]'), (1234, 'Evan', '[email protected]');
~~~

{% include copy-clipboard.html %}
~~~ sql
> INSERT INTO orders VALUES (1, 1001, 25), (2, 1234, 15), (3, 2000, 5);
~~~

{% include copy-clipboard.html %}
~~~ sql
> INSERT INTO shipments (carrier, status, customer_id) VALUES ('USPS', 'Out for delivery', 1001);
~~~

The last statement succeeds because `1001` matches a unique `id` value in the `customers` table and a unique `customer_id` value in the `orders` table. If `1001` was in neither of the referenced columns, or in just one of them, the statement would return an error.

For instance, the following statement fulfills just one of the foreign key constraints and returns an error:

{% include copy-clipboard.html %}
~~~ sql
> INSERT INTO shipments (carrier, status, customer_id) VALUES ('DHL', 'At facility', 2000);
~~~

~~~
ERROR: insert on table "shipments" violates foreign key constraint "fk_customers"
SQLSTATE: 23503
DETAIL: Key (customer_id)=(2000) is not present in table "customers".
~~~

CockroachDB allows you to add multiple foreign key constraints on the same column, that reference the same column:

{% include copy-clipboard.html %}
~~~ sql
> ALTER TABLE shipments ADD CONSTRAINT fk_customers_2 FOREIGN KEY (customer_id) REFERENCES customers(id) ON DELETE CASCADE;
~~~

{% include copy-clipboard.html %}
~~~ sql
> SHOW CONSTRAINTS FROM shipments;
~~~

~~~
table_name | constraint_name | constraint_type | details | validated
-------------+-----------------+-----------------+----------------------------------------------------------------------+------------
shipments | fk_customers | FOREIGN KEY | FOREIGN KEY (customer_id) REFERENCES customers(id) | true
shipments | fk_customers_2 | FOREIGN KEY | FOREIGN KEY (customer_id) REFERENCES customers(id) ON DELETE CASCADE | true
shipments | fk_orders | FOREIGN KEY | FOREIGN KEY (customer_id) REFERENCES orders(customer_id) | true
shipments | primary | PRIMARY KEY | PRIMARY KEY (tracking_number ASC) | true
(4 rows)
~~~

There are now two foreign key constraints on `customer_id` that reference the `customers(id)` column (i.e., `fk_customers` and `fk_customers_2`).

In the event of a `DELETE` or `UPDATE` to the referenced column (`customers(id)`), the action for the first foreign key specified takes precedence. In this case, that will be the default [action](#foreign-key-actions) (`ON UPDATE NO ACTION ON DELETE NO ACTION`) on the first foreign key constraint (`fk_customers`). This means that `DELETE`s on referenced columns will fail, even though the second foreign key constraint (`fk_customer_2`) is defined with the `ON DELETE CASCADE` action.

{% include copy-clipboard.html %}
~~~ sql
> DELETE FROM orders WHERE customer_id = 1001;
~~~

~~~
ERROR: delete on table "orders" violates foreign key constraint "fk_orders" on table "shipments"
SQLSTATE: 23503
DETAIL: Key (customer_id)=(1001) is still referenced from table "shipments".
~~~

### Match composite foreign keys with `MATCH SIMPLE` and `MATCH FULL`

Expand Down