1DELETE(7) SQL Commands DELETE(7)
2
3
4
6 DELETE - delete rows of a table
7
8
10 DELETE FROM [ ONLY ] table [ [ AS ] alias ]
11 [ USING usinglist ]
12 [ WHERE condition | WHERE CURRENT OF cursor_name ]
13 [ RETURNING * | output_expression [ [ AS ] output_name ] [, ...] ]
14
15
17 DELETE deletes rows that satisfy the WHERE clause from the specified
18 table. If the WHERE clause is absent, the effect is to delete all rows
19 in the table. The result is a valid, but empty table.
20
21 Tip: TRUNCATE [truncate(7)] is a PostgreSQL extension that pro‐
22 vides a faster mechanism to remove all rows from a table.
23
24
25 By default, DELETE will delete rows in the specified table and all its
26 child tables. If you wish to delete only from the specific table men‐
27 tioned, you must use the ONLY clause.
28
29 There are two ways to delete rows in a table using information con‐
30 tained in other tables in the database: using sub-selects, or specify‐
31 ing additional tables in the USING clause. Which technique is more
32 appropriate depends on the specific circumstances.
33
34 The optional RETURNING clause causes DELETE to compute and return
35 value(s) based on each row actually deleted. Any expression using the
36 table's columns, and/or columns of other tables mentioned in USING, can
37 be computed. The syntax of the RETURNING list is identical to that of
38 the output list of SELECT.
39
40 You must have the DELETE privilege on the table to delete from it, as
41 well as the SELECT privilege for any table in the USING clause or whose
42 values are read in the condition.
43
45 ONLY If specified, delete rows from the named table only. When not
46 specified, any tables inheriting from the named table are also
47 processed.
48
49 table The name (optionally schema-qualified) of an existing table.
50
51 alias A substitute name for the target table. When an alias is pro‐
52 vided, it completely hides the actual name of the table. For
53 example, given DELETE FROM foo AS f, the remainder of the DELETE
54 statement must refer to this table as f not foo.
55
56 usinglist
57 A list of table expressions, allowing columns from other tables
58 to appear in the WHERE condition. This is similar to the list of
59 tables that can be specified in the FROM Clause [select(7)] of a
60 SELECT statement; for example, an alias for the table name can
61 be specified. Do not repeat the target table in the usinglist,
62 unless you wish to set up a self-join.
63
64 condition
65 An expression that returns a value of type boolean. Only rows
66 for which this expression returns true will be deleted.
67
68 cursor_name
69 The name of the cursor to use in a WHERE CURRENT OF condition.
70 The row to be deleted is the one most recently fetched from this
71 cursor. The cursor must be a non-grouping query on the DELETE's
72 target table. Note that WHERE CURRENT OF cannot be specified
73 together with a Boolean condition. See DECLARE [declare(7)] for
74 more information about using cursors with WHERE CURRENT OF.
75
76 output_expression
77 An expression to be computed and returned by the DELETE command
78 after each row is deleted. The expression can use any column
79 names of the table or table(s) listed in USING. Write * to
80 return all columns.
81
82 output_name
83 A name to use for a returned column.
84
86 On successful completion, a DELETE command returns a command tag of the
87 form
88
89 DELETE count
90
91 The count is the number of rows deleted. If count is 0, no rows matched
92 the condition (this is not considered an error).
93
94 If the DELETE command contains a RETURNING clause, the result will be
95 similar to that of a SELECT statement containing the columns and values
96 defined in the RETURNING list, computed over the row(s) deleted by the
97 command.
98
100 PostgreSQL lets you reference columns of other tables in the WHERE con‐
101 dition by specifying the other tables in the USING clause. For example,
102 to delete all films produced by a given producer, one can do:
103
104 DELETE FROM films USING producers
105 WHERE producer_id = producers.id AND producers.name = 'foo';
106
107 What is essentially happening here is a join between films and produc‐
108 ers, with all successfully joined films rows being marked for deletion.
109 This syntax is not standard. A more standard way to do it is:
110
111 DELETE FROM films
112 WHERE producer_id IN (SELECT id FROM producers WHERE name = 'foo');
113
114 In some cases the join style is easier to write or faster to execute
115 than the sub-select style.
116
118 Delete all films but musicals:
119
120 DELETE FROM films WHERE kind <> 'Musical';
121
122
123 Clear the table films:
124
125 DELETE FROM films;
126
127
128 Delete completed tasks, returning full details of the deleted rows:
129
130 DELETE FROM tasks WHERE status = 'DONE' RETURNING *;
131
132
133 Delete the row of tasks on which the cursor c_tasks is currently posi‐
134 tioned:
135
136 DELETE FROM tasks WHERE CURRENT OF c_tasks;
137
138
140 This command conforms to the SQL standard, except that the USING and
141 RETURNING clauses are PostgreSQL extensions.
142
143
144
145SQL - Language Statements 2011-09-22 DELETE(7)