PostgreSQL 8.1.23 Documentation | ||||
---|---|---|---|---|
Prev | Fast Backward | Fast Forward | Next |
DELETE deletes rows that satisfy the WHERE clause from the specified table. If the WHERE clause is absent, the effect is to delete all rows in the table. The result is a valid, but empty table.
Tip: TRUNCATE is a PostgreSQL extension that provides a faster mechanism to remove all rows from a table.
By default, DELETE will delete rows in the specified table and all its child tables. If you wish to delete only from the specific table mentioned, you must use the ONLY clause.
There are two ways to delete rows in a table using information contained in other tables in the database: using sub-selects, or specifying additional tables in the USING clause. Which technique is more appropriate depends on the specific circumstances.
You must have the DELETE privilege on the table to delete from it, as well as the SELECT privilege for any table in the USING clause or whose values are read in the condition.
If specified, delete rows from the named table only. When not specified, any tables inheriting from the named table are also processed.
The name (optionally schema-qualified) of an existing table.
A list of table expressions, allowing columns from other tables to appear in the WHERE condition. This is similar to the list of tables that can be specified in the FROM Clause of a SELECT statement; for example, an alias for the table name can be specified. Do not repeat the target table in the usinglist, unless you wish to set up a self-join.
An expression returning a value of type boolean, which determines the rows that are to be deleted.
On successful completion, a DELETE command returns a command tag of the form
DELETE count
The count is the number of rows deleted. If count is 0, no rows matched the condition (this is not considered an error).
PostgreSQL lets you reference columns of other tables in the WHERE condition by specifying the other tables in the USING clause. For example, to delete all films produced by a given producer, one might do
DELETE FROM films USING producers WHERE producer_id = producers.id AND producers.name = 'foo';
What is essentially happening here is a join between films and producers, with all successfully joined films rows being marked for deletion. This syntax is not standard. A more standard way to do it is
DELETE FROM films WHERE producer_id IN (SELECT id FROM producers WHERE name = 'foo');
In some cases the join style is easier to write or faster to execute than the sub-select style.
Delete all films but musicals:
DELETE FROM films WHERE kind <> 'Musical';
Clear the table films:
DELETE FROM films;