Skip to content

Commit

Permalink
Document fast path deletes for interleaved tables
Browse files Browse the repository at this point in the history
Addresses #3511.

Summary of changes:

- Update 'INTERLEAVE IN PARENT' page with:

  - Some new paragraphs in the **Benefits** explaining fast path deletes
  - A new example in the **Examples** section
  - A reference to the above from the **Tradeoffs** section
  - (Unrelated) Add `div` tags to fix a broken diagram
  • Loading branch information
rmloveland committed Oct 10, 2018
1 parent beea900 commit 88f92e4
Showing 1 changed file with 67 additions and 1 deletion.
68 changes: 67 additions & 1 deletion v2.1/interleave-in-parent.md
Expand Up @@ -62,6 +62,18 @@ In general, reads, writes, and joins of values related through the interleave pr

- Using only tables in the interleaved hierarchy.

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

<span class="version-tag">New in v2.1:</span> 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:

- 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.
- All of the interleaved relationships use `ON DELETE CASCADE` clauses.

The performance boost when using this fast path is several orders of magnitude, potentially reducing delete times from seconds to nanoseconds.

For an example showing how to create tables that meet these criteria, see [Interleaved fast path deletes](#interleaved-fast-path-deletes) below.

### Tradeoffs

- In general, reads and deletes over ranges of table values (e.g., `WHERE column > value`) in interleaved tables are slower.
Expand All @@ -70,13 +82,17 @@ In general, reads, writes, and joins of values related through the interleave pr

For example, if the interleave prefix of `packages` is `(customer, order)`, filtering on the entire interleave prefix with constant values while calculating a range of table values on another column, like `WHERE customer = 1 AND order = 1001 AND delivery_date > DATE '2016-01-25'`, would still be fast.

Another exception is the [fast path delete optimization](#fast-path-deletes), which is available if you set up your tables according to certain criteria.

- If the amount of interleaved data stored for any Primary Key value of the root table is larger than [a key-value range's maximum size](configure-replication-zones.html#replication-zone-format) (64MB by default), the interleaved optimizations will be diminished.

For example, if one customer has 200MB of order data, their data is likely to be spread across multiple key-value ranges and CockroachDB will not be able to access it as quickly, despite it being interleaved.

## Syntax

{% include {{ page.version.version }}/sql/diagrams/interleave.html %}
<div>
{% include {{ page.version.version }}/sql/diagrams/interleave.html %}
</div>

## Parameters

Expand Down Expand Up @@ -145,6 +161,56 @@ This example creates an interleaved hierarchy between `customers`, `orders`, and
) INTERLEAVE IN PARENT orders (customer, "order");
~~~

### Interleaved fast path deletes

This example shows how to create interleaved tables that enable our SQL engine to use a code path optimized to run much faster when deleting rows from these tables. For more information about the criteria for enabling this optimization, see [fast path deletes](#fast-path-deletes) above.

{% include copy-clipboard.html %}
~~~ sql
> CREATE TABLE items (id INT PRIMARY KEY);
~~~

{% include copy-clipboard.html %}
~~~ sql
> CREATE TABLE IF NOT EXISTS bundles (
id INT,
item_id INT,
PRIMARY KEY (item_id, id),
FOREIGN KEY (item_id) REFERENCES items (id) ON DELETE CASCADE ON UPDATE CASCADE
)
INTERLEAVE IN PARENT items (item_id);
~~~

{% include copy-clipboard.html %}
~~~ sql
> CREATE TABLE IF NOT EXISTS suppliers (
id INT,
item_id INT,
PRIMARY KEY (item_id, id),
FOREIGN KEY (item_id) REFERENCES items (id) ON DELETE CASCADE ON UPDATE CASCADE
)
INTERLEAVE IN PARENT items (item_id);
~~~

{% include copy-clipboard.html %}
~~~ sql
> CREATE TABLE IF NOT EXISTS orders (
id INT,
item_id INT,
order_id INT,
FOREIGN KEY (order_id, item_id) REFERENCES bundles (item_id, id) ON DELETE CASCADE ON UPDATE CASCADE,
PRIMARY KEY (order_id, item_id, id)
)
INTERLEAVE IN PARENT bundles (order_id, item_id);
~~~

The following statement will delete some rows from the `parent` table, very quickly:

{% include copy-clipboard.html %}
~~~ sql
> DELETE FROM items WHERE id <= 5;
~~~

### Key-value storage example

It can be easier to understand what interleaving tables does by seeing what it looks like in the key-value store. For example, using the above example of interleaving `orders` in `customers`, we could insert the following values:
Expand Down

0 comments on commit 88f92e4

Please sign in to comment.