From a5232d39c95ed558c24cf513d0adc18fa0547c58 Mon Sep 17 00:00:00 2001 From: Rich Loveland Date: Wed, 27 Mar 2019 15:45:09 -0400 Subject: [PATCH] `LIMIT` is required on a `DELETE ... ORDER BY` Fixes #4378. Summary of changes: - Update `DELETE`'s `sort_clause` parameter to note that as of 19.1, a `LIMIT` is required on a `DELETE ... ORDER BY` - Add new section 'Sorting the output of deletes' to both the `DELETE` and 'Ordering Query Results' pages. - Add example section 'Sort an return deleted rows' to the `DELETE` page - Update all examples on `DELETE` page to use new SQL CLI output table formatting - Add SQL code needed for `DELETE` examples in a comment at the bottom of the page --- _includes/v19.1/misc/sorting-delete-output.md | 8 ++ v19.1/delete.md | 110 +++++++++++++----- v19.1/query-order.md | 4 + 3 files changed, 94 insertions(+), 28 deletions(-) create mode 100644 _includes/v19.1/misc/sorting-delete-output.md diff --git a/_includes/v19.1/misc/sorting-delete-output.md b/_includes/v19.1/misc/sorting-delete-output.md new file mode 100644 index 00000000000..458376c4466 --- /dev/null +++ b/_includes/v19.1/misc/sorting-delete-output.md @@ -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). diff --git a/v19.1/delete.md b/v19.1/delete.md index dd354500fe1..72af975696d 100644 --- a/v19.1/delete.md +++ b/v19.1/delete.md @@ -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., ` = `). Delete rows that return `TRUE`.

__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.

New in v19.1: 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).

To return nothing in the response, not even the number of rows updated, use `RETURNING NOTHING`. @@ -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 @@ -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 @@ -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. @@ -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 @@ -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 @@ -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 @@ -194,3 +225,26 @@ When `RETURNING` specific columns, you can change their labels using `AS`. [truncate]: truncate.html + + diff --git a/v19.1/query-order.md b/v19.1/query-order.md index 241e7bb99e0..9dc1d37bcc8 100644 --- a/v19.1/query-order.md +++ b/v19.1/query-order.md @@ -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`)