Skip to content

Commit

Permalink
Merge pull request #4581 from cockroachdb/20190327-delete-order-by-limit
Browse files Browse the repository at this point in the history
`LIMIT` is required on a `DELETE ... ORDER BY`
  • Loading branch information
rmloveland authored Apr 15, 2019
2 parents 5339b0a + a5232d3 commit 0d37ad3
Show file tree
Hide file tree
Showing 3 changed files with 94 additions and 28 deletions.
8 changes: 8 additions & 0 deletions _includes/v19.1/misc/sorting-delete-output.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
To sort the output of a `DELETE` statement, use:

{% include copy-clipboard.html %}
~~~ sql
> SELECT ... FROM [DELETE ...] ORDER BY ...
~~~

For an example, see [Sort and return deleted rows](delete.html#sort-and-return-deleted-rows).
110 changes: 82 additions & 28 deletions v19.1/delete.md
Original file line number Diff line number Diff line change
Expand Up @@ -34,7 +34,7 @@ table td:first-child {
`table_name` | The name of the table that contains the rows you want to update.
`AS table_alias_name` | An alias for the table name. When an alias is provided, it completely hides the actual table name.
`WHERE a_expr`| `a_expr` must be an expression that returns Boolean values using columns (e.g., `<column> = <value>`). Delete rows that return `TRUE`.<br><br/>__Without a `WHERE` clause in your statement, `DELETE` removes all rows from the table.__
`sort_clause` | An `ORDER BY` clause. See [Ordering Query Results](query-order.html) for more details.
`sort_clause` | An `ORDER BY` clause. <br /><br /> <span class="version-tag">New in v19.1</span>: The `ORDER BY` clause can no longer be used with a `DELETE` statement when there is no `LIMIT` clause present.
`limit_clause` | A `LIMIT` clause. See [Limiting Query Results](limit-offset.html) for more details.
`RETURNING target_list` | Return values based on rows deleted, where `target_list` can be specific column names from the table, `*` for all columns, or computations using [scalar expressions](scalar-expressions.html). <br><br>To return nothing in the response, not even the number of rows updated, use `RETURNING NOTHING`.

Expand Down Expand Up @@ -68,6 +68,13 @@ and delete lots of rows will want to reduce the
[time-to-live](configure-replication-zones.html) values to clean up
deleted rows more frequently.

## Sorting the output of deletes

{% include {{page.version.version}}/misc/sorting-delete-output.md %}

For more information about ordering query results in general, see
[Ordering Query Results](query-order.html).

## Examples

### Delete all rows
Expand Down Expand Up @@ -101,11 +108,12 @@ In this example, `account_id` is our primary key and we want to delete the row w
> DELETE FROM account_details WHERE account_id = 1 RETURNING *;
~~~
~~~
+------------+---------+--------------+
| account_id | balance | account_type |
+------------+---------+--------------+
| 1 | 32000 | Savings |
+------------+---------+--------------+
account_id | balance | account_type
------------+---------+--------------
1 | 32000 | Savings
(1 row)
DELETE 1
~~~

#### Delete rows using non-unique columns
Expand All @@ -117,12 +125,13 @@ Deleting rows using non-unique columns removes _every_ row that returns `TRUE` f
> DELETE FROM account_details WHERE balance = 30000 RETURNING *;
~~~
~~~
+------------+---------+--------------+
| account_id | balance | account_type |
+------------+---------+--------------+
| 2 | 30000 | Checking |
| 3 | 30000 | Savings |
+------------+---------+--------------+
account_id | balance | account_type
------------+---------+--------------
2 | 30000 | Checking
3 | 30000 | Savings
(2 rows)
DELETE 2
~~~

The example statement deleted two rows, which might be unexpected.
Expand All @@ -140,11 +149,12 @@ By specifying `*`, you retrieve all columns of the delete rows.
> DELETE FROM account_details WHERE balance < 23000 RETURNING *;
~~~
~~~
+------------+---------+--------------+
| account_id | balance | account_type |
+------------+---------+--------------+
| 4 | 22000 | Savings |
+------------+---------+--------------+
account_id | balance | account_type
------------+---------+--------------
4 | 22000 | Savings
(1 row)
DELETE 1
~~~

#### Use specific columns
Expand All @@ -156,11 +166,12 @@ To retrieve specific columns, name them in the `RETURNING` clause.
> DELETE FROM account_details WHERE account_id = 5 RETURNING account_id, account_type;
~~~
~~~
+------------+--------------+
| account_id | account_type |
+------------+--------------+
| 5 | Checking |
+------------+--------------+
account_id | account_type
------------+--------------
5 | Checking
(1 row)
DELETE 1
~~~

#### Change column labels
Expand All @@ -169,14 +180,34 @@ When `RETURNING` specific columns, you can change their labels using `AS`.

{% include copy-clipboard.html %}
~~~ sql
> DELETE FROM account_details WHERE balance < 22500 RETURNING account_id, balance AS final_balance;
> DELETE FROM account_details WHERE balance < 24500 RETURNING account_id, balance AS final_balance;
~~~
~~~
account_id | final_balance
------------+---------------
6 | 23500
(1 row)
DELETE 1
~~~

#### Sort and return deleted rows

To sort and return deleted rows, use a statement like the following:

{% include copy-clipboard.html %}
~~~ sql
> SELECT * FROM [DELETE FROM account_details RETURNING *] ORDER BY account_id;
~~~

~~~
+------------+---------------+
| account_id | final_balance |
+------------+---------------+
| 6 | 23500 |
+------------+---------------+
account_id | balance | account_type
------------+----------+--------------
7 | 79493.51 | Checking
8 | 40761.66 | Savings
9 | 2111.67 | Checking
10 | 59173.15 | Savings
(4 rows)
~~~

## See also
Expand All @@ -194,3 +225,26 @@ When `RETURNING` specific columns, you can change their labels using `AS`.
<!-- Reference Links -->

[truncate]: truncate.html

<!--
SQL for example table:
CREATE TABLE account_details (
account_id INT PRIMARY KEY,
balance FLOAT,
account_type VARCHAR
);
INSERT INTO account_details (account_id, balance, account_type) VALUES (1, 32000, 'Savings');
INSERT INTO account_details (account_id, balance, account_type) VALUES (2, 30000, 'Checking');
INSERT INTO account_details (account_id, balance, account_type) VALUES (3, 30000, 'Savings');
INSERT INTO account_details (account_id, balance, account_type) VALUES (4, 22000, 'Savings');
INSERT INTO account_details (account_id, balance, account_type) VALUES (5, 43696.95, 'Checking');
INSERT INTO account_details (account_id, balance, account_type) VALUES (6, 23500, 'Savings');
INSERT INTO account_details (account_id, balance, account_type) VALUES (7, 79493.51, 'Checking');
INSERT INTO account_details (account_id, balance, account_type) VALUES (8, 40761.66, 'Savings');
INSERT INTO account_details (account_id, balance, account_type) VALUES (9, 2111.67, 'Checking');
INSERT INTO account_details (account_id, balance, account_type) VALUES (10, 59173.15, 'Savings');
-->
4 changes: 4 additions & 0 deletions v19.1/query-order.md
Original file line number Diff line number Diff line change
Expand Up @@ -246,6 +246,10 @@ will be flipped (cancelled) if the `ORDER BY` clause also uses
-- The index order is inverted.
~~~

## Sorting the output of deletes

{% include {{page.version.version}}/misc/sorting-delete-output.md %}

## Processing order during aggregations

CockroachDB currently processes aggregations (e.g., `SELECT ... GROUP BY`)
Expand Down

0 comments on commit 0d37ad3

Please sign in to comment.