Skip to content

Commit

Permalink
Document auto-validation of foreign keys
Browse files Browse the repository at this point in the history
Fixes #4891.
Fixes #5187.
  • Loading branch information
jseldess authored and RaduBerinde committed Dec 10, 2019
1 parent e4ada32 commit cda3ce4
Show file tree
Hide file tree
Showing 12 changed files with 94 additions and 42 deletions.
44 changes: 34 additions & 10 deletions v19.2/add-constraint.md
Original file line number Diff line number Diff line change
Expand Up @@ -6,9 +6,9 @@ toc: true

The `ADD CONSTRAINT` [statement](sql-statements.html) is part of `ALTER TABLE` and can add the following [constraints](constraints.html) to columns:

- [`UNIQUE`](#add-the-unique-constraint)
- [`CHECK`](#add-the-check-constraint)
- [Foreign key](#add-the-foreign-key-constraint-with-cascade)
- [`UNIQUE`](#add-a-unique-constraint)
- [`CHECK`](#add-a-check-constraint)
- [`FOREIGN KEY`](#add-a-foreign-key-constraint-with-cascade)

{{site.data.alerts.callout_info}}
The [`PRIMARY KEY`](primary-key.html) can only be applied through [`CREATE TABLE`](create-table.html). The [`DEFAULT`](default-value.html) and [`NOT NULL`](not-null.html) constraints are managed through [`ALTER COLUMN`](alter-column.html).
Expand All @@ -32,26 +32,27 @@ The user must have the `CREATE` [privilege](authorization.html#assign-privileges
-----------|-------------
`table_name` | The name of the table containing the column you want to constrain.
`constraint_name` | The name of the constraint, which must be unique to its table and follow these [identifier rules](keywords-and-identifiers.html#identifiers).
`constraint_elem` | The [`CHECK`](check.html), [foreign key](foreign-key.html), [`UNIQUE`](unique.html) constraint you want to add. <br/><br/>Adding/changing a `DEFAULT` constraint is done through [`ALTER COLUMN`](alter-column.html). <br/><br/>Adding/changing the table's `PRIMARY KEY` is not supported through `ALTER TABLE`; it can only be specified during [table creation](create-table.html).
`constraint_elem` | The [`CHECK`](check.html), [`FOREIGN KEY`](foreign-key.html), [`UNIQUE`](unique.html) constraint you want to add.<br/><br/>Adding/changing a `DEFAULT` constraint is done through [`ALTER COLUMN`](alter-column.html).<br/><br/>Adding/changing the table's `PRIMARY KEY` is not supported through `ALTER TABLE`; it can only be specified during [table creation](create-table.html).<br><br><span class="version-tag">New in v19.2:</span> Applying a foreign key constraint now validates existing rows in addition to enforcing conformance for new rows. As such, it is no longer necessary to use [`VALIDATE CONSTRAINT`](validate-constraint.html) for foreign keys. To create an unvalidated foreign key constraint, the `NOT VALID` keyword can be used.
`opt_validation` | An optional `NOT VALID` modifier used to create unvalidated constraints. When creating an unvalidated constraint, the system does not check that existing table data satisfies the constraint. The constraint is still enforced when table data is modified. An unvalidated constraint can later be validated using [`VALIDATE CONSTRAINT`](validate-constraint.html).

## Viewing schema changes

{% include {{ page.version.version }}/misc/schema-change-view-job.md %}

## Examples

### Add the `UNIQUE` constraint
### Add a `UNIQUE` constraint

Adding the [`UNIQUE` constraint](unique.html) requires that all of a column's values be distinct from one another (except for *NULL* values).
Adding a [`UNIQUE` constraint](unique.html) requires that all of a column's values be distinct from one another (except for *NULL* values).

{% include copy-clipboard.html %}
~~~ sql
> ALTER TABLE orders ADD CONSTRAINT id_customer_unique UNIQUE (id, customer);
~~~

### Add the `CHECK` constraint
### Add a `CHECK` constraint

Adding the [`CHECK` constraint](check.html) requires that all of a column's values evaluate to `TRUE` for a Boolean expression.
Adding a [`CHECK` constraint](check.html) requires that all of a column's values evaluate to `TRUE` for a Boolean expression.

{% include copy-clipboard.html %}
~~~ sql
Expand Down Expand Up @@ -82,9 +83,9 @@ The entire transaction will be rolled back, including any new columns that were
- If a new column has a default value or is a [computed column](computed-columns.html) that would have contained values that violate the new constraint.
{{site.data.alerts.end}}

### Add the foreign key constraint with `CASCADE`
### Add a foreign key constraint with `CASCADE`

To add a foreign key constraint, use the steps shown below.
To add a cascading foreign key constraint, use the steps shown below.

Given two tables, `customers` and `orders`:

Expand Down Expand Up @@ -158,6 +159,29 @@ An index on the referencing columns is automatically created for you when you ad
Adding a foreign key for a non-empty table without an appropriate index will fail, since foreign key columns must be indexed. For more information about the requirements for creating foreign keys, see [Rules for creating foreign keys](foreign-key.html#rules-for-creating-foreign-keys).
{{site.data.alerts.end}}

### Add an unvalidated foreign key constraint

On the same tables as above, we add an unvalidated foreign key constraint.

{% include copy-clipboard.html %}
~~~ sql
> ALTER TABLE orders ADD CONSTRAINT customer_fk FOREIGN KEY (customer_id) REFERENCES customers (id) NOT VALID;
~~~

Even unvalidated, the constraint is enforced during table mutations:
{% include copy-clipboard.html %}
~~~ sql
> INSERT INTO orders VALUES (1, 1, 'open');
pq: foreign key violation: value [1] not found in customers@primary [id] (txn=9d649525-461e-4e0f-906a-712455125f0e)
~~~

To validate the constraint (which checks that all existing data conforms to the
constraint):
{% include copy-clipboard.html %}
~~~ sql
> ALTER TABLE orders VALIDATE CONSTRAINT customer_fk;
~~~

## See also

- [Constraints](constraints.html)
Expand Down
4 changes: 2 additions & 2 deletions v19.2/check.md
Original file line number Diff line number Diff line change
Expand Up @@ -9,7 +9,7 @@ The `CHECK` [constraint](constraints.html) specifies that values for the column
## Details

- If you add a `CHECK` constraint to an existing table, CockroachDB will run a background job to validate existing table data in the process of adding the constraint. If a row is found that violates the constraint during the validation step, the [`ADD CONSTRAINT`](add-constraint.html) statement will fail. This differs from previous versions of CockroachDB, which allowed you to add a check constraint that was enforced for writes but could be violated by rows that existed prior to adding the constraint.
- Check constraints can be added to columns that were created earlier in the same transaction. For an example, see [Add the `CHECK` constraint](add-constraint.html#add-the-check-constraint).
- Check constraints can be added to columns that were created earlier in the same transaction. For an example, see [Add a `CHECK` constraint](add-constraint.html#add-a-check-constraint).
- `CHECK` constraints may be specified at the column or table level and can reference other columns within the table. Internally, all column-level `CHECK` constraints are converted to table-level constraints so they can be handled consistently.
- You can have multiple `CHECK` constraints on a single column but ideally, for performance optimization, these should be combined using the logical operators. For example:

Expand All @@ -28,7 +28,7 @@ The `CHECK` [constraint](constraints.html) specifies that values for the column

`CHECK` constraints can be defined at the [table level](#table-level). However, if you only want the constraint to apply to a single column, it can be applied at the [column level](#column-level).

{{site.data.alerts.callout_info}}You can also add the <code>CHECK</code> constraint to existing tables through <a href="add-constraint.html#add-the-check-constraint"><code>ADD CONSTRAINT</code></a>.{{site.data.alerts.end}}
{{site.data.alerts.callout_info}}You can also add the <code>CHECK</code> constraint to existing tables through <a href="add-constraint.html#add-a-check-constraint"><code>ADD CONSTRAINT</code></a>.{{site.data.alerts.end}}

### Column level

Expand Down
4 changes: 2 additions & 2 deletions v19.2/foreign-key.md
Original file line number Diff line number Diff line change
Expand Up @@ -22,7 +22,7 @@ For example, given an `orders` table and a `customers` table, if you create a co
- Cannot be a [computed column](computed-columns.html).
- Foreign key columns must be [indexed](indexes.html). This is required because updates and deletes on the referenced table will need to search the referencing table for any matching records to ensure those operations would not violate existing references. In practice, such indexes are likely also needed by applications using these tables, since finding all records which belong to some entity, for example all orders for a given customer, is very common.
- To meet this requirement when creating a new table, there are a few options:
- An index on the referencing columns is automatically created for you when you add a foreign key constraint to an empty table, if an appropriate index does not already exist. For an example, see [Add the foreign key constraint with `CASCADE`](add-constraint.html#add-the-foreign-key-constraint-with-cascade).
- An index on the referencing columns is automatically created for you when you add a foreign key constraint to an empty table, if an appropriate index does not already exist. For an example, see [Add the foreign key constraint with `CASCADE`](add-constraint.html#add-a-foreign-key-constraint-with-cascade).
- Create indexes explicitly using the [`INDEX`](create-table.html#create-a-table-with-secondary-and-inverted-indexes) clause of `CREATE TABLE`.
- Rely on indexes created by the [`PRIMARY KEY`](primary-key.html) or [`UNIQUE`](unique.html) constraints.
- Have CockroachDB automatically create an index of the foreign key columns for you. However, it's important to note that if you later remove the Foreign Key constraint, this automatically created index _is not_ removed.
Expand Down Expand Up @@ -118,7 +118,7 @@ You can improve the performance of some statements that use foreign keys by also
Foreign key constraints can be defined at the [table level](#table-level). However, if you only want the constraint to apply to a single column, it can be applied at the [column level](#column-level).

{{site.data.alerts.callout_info}}
You can also add the Foreign Key constraint to existing tables through [`ADD CONSTRAINT`](add-constraint.html#add-the-foreign-key-constraint-with-cascade).
You can also add the Foreign Key constraint to existing tables through [`ADD CONSTRAINT`](add-constraint.html#add-a-foreign-key-constraint-with-cascade).
{{site.data.alerts.end}}

### Column level
Expand Down
2 changes: 1 addition & 1 deletion v19.2/interleave-in-parent.md
Original file line number Diff line number Diff line change
Expand Up @@ -64,7 +64,7 @@ In general, reads, writes, and joins of values related through the interleave pr

<a name="fast-path-deletes"></a>

Fast deletes are available for interleaved tables that use [`ON DELETE CASCADE`](add-constraint.html#add-the-foreign-key-constraint-with-cascade). Deleting rows from such tables will use an optimized code path and run much faster, as long as the following conditions are met:
Fast deletes are available for interleaved tables that use [`ON DELETE CASCADE`](add-constraint.html#add-a-foreign-key-constraint-with-cascade). Deleting rows from such tables will use an optimized code path and run much faster, as long as the following conditions are met:

- The table or any of its interleaved tables do not have any secondary indices.
- The table or any of its interleaved tables are not referenced by any other table outside of them by foreign key.
Expand Down
2 changes: 1 addition & 1 deletion v19.2/unique.md
Original file line number Diff line number Diff line change
Expand Up @@ -19,7 +19,7 @@ The `UNIQUE` [constraint](constraints.html) specifies that each non-`NULL` value

- When using the `UNIQUE` constraint on multiple columns, the collective values of the columns must be unique. This *does not* mean that each value in each column must be unique, as if you had applied the `UNIQUE` constraint to each column individually.

- You can define the `UNIQUE` constraint when [creating a table](#syntax), or you can add it to existing tables through [`ADD CONSTRAINT`](add-constraint.html#add-the-unique-constraint).
- You can define the `UNIQUE` constraint when [creating a table](#syntax), or you can add it to existing tables through [`ADD CONSTRAINT`](add-constraint.html#add-a-unique-constraint).

## Syntax

Expand Down
12 changes: 7 additions & 5 deletions v19.2/validate-constraint.md
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,8 @@ toc: true

The `VALIDATE CONSTRAINT` [statement](sql-statements.html) is part of `ALTER TABLE` and checks whether values in a column match a [constraint](constraints.html) on the column. This statement is especially useful after applying a constraint to an existing column via [`ADD CONSTRAINT`](add-constraint.html). In this case, `VALIDATE CONSTRAINT` can be used to find values already in the column that do not match the constraint.

<span class="version-tag">New in v19.2:</span> Applying a foreign key constraint via `ADD CONSTRAINT` now validates existing rows in addition to enforcing conformance for new rows. As such, it is no longer necessary to use [`VALIDATE CONSTRAINT`](validate-constraint.html) for foreign keys.

{% include {{ page.version.version }}/sql/combine-alter-table-commands.md %}

## Required privileges
Expand All @@ -29,20 +31,20 @@ The user must have the `CREATE` [privilege](authorization.html#assign-privileges

{% include {{ page.version.version }}/misc/schema-change-view-job.md %}

## Examples
## Example

In [`ADD CONSTRAINT`](add-constraint.html), we [added a foreign key constraint](add-constraint.html#add-the-foreign-key-constraint-with-cascade) like so:
In [`ADD CONSTRAINT`](add-constraint.html), we [added a `CHECK` constraint](add-constraint.html#add-a-check-constraint) like so:

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

In order to ensure that the data added to the `orders` table prior to the creation of the `customer_fk` constraint conforms to that constraint, run the following:
In order to ensure that the data added to the `orders` table prior to the creation of the `check_id_non_zer` constraint conforms to that constraint, run the following:

{% include copy-clipboard.html %}
~~~ sql
> ALTER TABLE orders VALIDATE CONSTRAINT customer_fk;
> ALTER TABLE orders VALIDATE CONSTRAINT check_id_non_zero;
~~~

{{site.data.alerts.callout_info}}
Expand Down
44 changes: 34 additions & 10 deletions v20.1/add-constraint.md
Original file line number Diff line number Diff line change
Expand Up @@ -6,9 +6,9 @@ toc: true

The `ADD CONSTRAINT` [statement](sql-statements.html) is part of `ALTER TABLE` and can add the following [constraints](constraints.html) to columns:

- [`UNIQUE`](#add-the-unique-constraint)
- [`CHECK`](#add-the-check-constraint)
- [Foreign key](#add-the-foreign-key-constraint-with-cascade)
- [`UNIQUE`](#add-a-unique-constraint)
- [`CHECK`](#add-a-check-constraint)
- [`FOREIGN KEY`](#add-a-foreign-key-constraint-with-cascade)

{{site.data.alerts.callout_info}}
The [`PRIMARY KEY`](primary-key.html) can only be applied through [`CREATE TABLE`](create-table.html). The [`DEFAULT`](default-value.html) and [`NOT NULL`](not-null.html) constraints are managed through [`ALTER COLUMN`](alter-column.html).
Expand All @@ -32,26 +32,27 @@ The user must have the `CREATE` [privilege](authorization.html#assign-privileges
-----------|-------------
`table_name` | The name of the table containing the column you want to constrain.
`constraint_name` | The name of the constraint, which must be unique to its table and follow these [identifier rules](keywords-and-identifiers.html#identifiers).
`constraint_elem` | The [`CHECK`](check.html), [foreign key](foreign-key.html), [`UNIQUE`](unique.html) constraint you want to add. <br/><br/>Adding/changing a `DEFAULT` constraint is done through [`ALTER COLUMN`](alter-column.html). <br/><br/>Adding/changing the table's `PRIMARY KEY` is not supported through `ALTER TABLE`; it can only be specified during [table creation](create-table.html).
`constraint_elem` | The [`CHECK`](check.html), [`FOREIGN KEY`](foreign-key.html), [`UNIQUE`](unique.html) constraint you want to add.<br/><br/>Adding/changing a `DEFAULT` constraint is done through [`ALTER COLUMN`](alter-column.html).<br/><br/>Adding/changing the table's `PRIMARY KEY` is not supported through `ALTER TABLE`; it can only be specified during [table creation](create-table.html).<br><br><span class="version-tag">New in v19.2:</span> Applying a foreign key constraint now validates existing rows in addition to enforcing conformance for new rows. As such, it is no longer necessary to use [`VALIDATE CONSTRAINT`](validate-constraint.html) for foreign keys. To create an unvalidated foreign key constraint, the `NOT VALID` keyword can be used.
`opt_validation` | An optional `NOT VALID` modifier used to create unvalidated constraints. When creating an unvalidated constraint, the system does not check that existing table data satisfies the constraint. The constraint is still enforced when table data is modified. An unvalidated constraint can later be validated using [`VALIDATE CONSTRAINT`](validate-constraint.html).

## Viewing schema changes

{% include {{ page.version.version }}/misc/schema-change-view-job.md %}

## Examples

### Add the `UNIQUE` constraint
### Add a `UNIQUE` constraint

Adding the [`UNIQUE` constraint](unique.html) requires that all of a column's values be distinct from one another (except for *NULL* values).
Adding a [`UNIQUE` constraint](unique.html) requires that all of a column's values be distinct from one another (except for *NULL* values).

{% include copy-clipboard.html %}
~~~ sql
> ALTER TABLE orders ADD CONSTRAINT id_customer_unique UNIQUE (id, customer);
~~~

### Add the `CHECK` constraint
### Add a `CHECK` constraint

Adding the [`CHECK` constraint](check.html) requires that all of a column's values evaluate to `TRUE` for a Boolean expression.
Adding a [`CHECK` constraint](check.html) requires that all of a column's values evaluate to `TRUE` for a Boolean expression.

{% include copy-clipboard.html %}
~~~ sql
Expand Down Expand Up @@ -82,9 +83,9 @@ The entire transaction will be rolled back, including any new columns that were
- If a new column has a default value or is a [computed column](computed-columns.html) that would have contained values that violate the new constraint.
{{site.data.alerts.end}}

### Add the foreign key constraint with `CASCADE`
### Add a foreign key constraint with `CASCADE`

To add a foreign key constraint, use the steps shown below.
To add a cascading foreign key constraint, use the steps shown below.

Given two tables, `customers` and `orders`:

Expand Down Expand Up @@ -158,6 +159,29 @@ An index on the referencing columns is automatically created for you when you ad
Adding a foreign key for a non-empty table without an appropriate index will fail, since foreign key columns must be indexed. For more information about the requirements for creating foreign keys, see [Rules for creating foreign keys](foreign-key.html#rules-for-creating-foreign-keys).
{{site.data.alerts.end}}

### Add an unvalidated foreign key constraint

On the same tables as above, we add an unvalidated foreign key constraint.

{% include copy-clipboard.html %}
~~~ sql
> ALTER TABLE orders ADD CONSTRAINT customer_fk FOREIGN KEY (customer_id) REFERENCES customers (id) NOT VALID;
~~~

Even unvalidated, the constraint is enforced during table mutations:
{% include copy-clipboard.html %}
~~~ sql
> INSERT INTO orders VALUES (1, 1, 'open');
pq: foreign key violation: value [1] not found in customers@primary [id] (txn=9d649525-461e-4e0f-906a-712455125f0e)
~~~

To validate the constraint (which checks that all existing data conforms to the
constraint):
{% include copy-clipboard.html %}
~~~ sql
> ALTER TABLE orders VALIDATE CONSTRAINT customer_fk;
~~~

## See also

- [Constraints](constraints.html)
Expand Down
Loading

0 comments on commit cda3ce4

Please sign in to comment.