1 <?xml version="1.0" encoding="UTF-8" standalone="no"?>
2 <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>DELETE</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="sql-declare.html" title="DECLARE" /><link rel="next" href="sql-discard.html" title="DISCARD" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">DELETE</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="sql-declare.html" title="DECLARE">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="sql-commands.html" title="SQL Commands">Up</a></td><th width="60%" align="center">SQL Commands</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="sql-discard.html" title="DISCARD">Next</a></td></tr></table><hr /></div><div class="refentry" id="SQL-DELETE"><div class="titlepage"></div><a id="id-1.9.3.100.1" class="indexterm"></a><div class="refnamediv"><h2><span class="refentrytitle">DELETE</span></h2><p>DELETE — delete rows of a table</p></div><div class="refsynopsisdiv"><h2>Synopsis</h2><pre class="synopsis">
3 [ WITH [ RECURSIVE ] <em class="replaceable"><code>with_query</code></em> [, ...] ]
4 DELETE FROM [ ONLY ] <em class="replaceable"><code>table_name</code></em> [ * ] [ [ AS ] <em class="replaceable"><code>alias</code></em> ]
5 [ USING <em class="replaceable"><code>from_item</code></em> [, ...] ]
6 [ WHERE <em class="replaceable"><code>condition</code></em> | WHERE CURRENT OF <em class="replaceable"><code>cursor_name</code></em> ]
7 [ RETURNING [ WITH ( { OLD | NEW } AS <em class="replaceable"><code>output_alias</code></em> [, ...] ) ]
8 { * | <em class="replaceable"><code>output_expression</code></em> [ [ AS ] <em class="replaceable"><code>output_name</code></em> ] } [, ...] ]
9 </pre></div><div class="refsect1" id="id-1.9.3.100.5"><h2>Description</h2><p>
10 <code class="command">DELETE</code> deletes rows that satisfy the
11 <code class="literal">WHERE</code> clause from the specified table. If the
12 <code class="literal">WHERE</code> clause is absent, the effect is to delete
13 all rows in the table. The result is a valid, but empty table.
14 </p><div class="tip"><h3 class="title">Tip</h3><p>
15 <a class="link" href="sql-truncate.html" title="TRUNCATE"><code class="command">TRUNCATE</code></a> provides a
16 faster mechanism to remove all rows from a table.
18 There are two ways to delete rows in a table using information
19 contained in other tables in the database: using sub-selects, or
20 specifying additional tables in the <code class="literal">USING</code> clause.
21 Which technique is more appropriate depends on the specific
24 The optional <code class="literal">RETURNING</code> clause causes <code class="command">DELETE</code>
25 to compute and return value(s) based on each row actually deleted.
26 Any expression using the table's columns, and/or columns of other
27 tables mentioned in <code class="literal">USING</code>, can be computed.
28 The syntax of the <code class="literal">RETURNING</code> list is identical to that of the
29 output list of <code class="command">SELECT</code>.
31 You must have the <code class="literal">DELETE</code> privilege on the table
32 to delete from it, as well as the <code class="literal">SELECT</code>
33 privilege for any table in the <code class="literal">USING</code> clause or
34 whose values are read in the <em class="replaceable"><code>condition</code></em>.
35 </p></div><div class="refsect1" id="id-1.9.3.100.6"><h2>Parameters</h2><div class="variablelist"><dl class="variablelist"><dt><span class="term"><em class="replaceable"><code>with_query</code></em></span></dt><dd><p>
36 The <code class="literal">WITH</code> clause allows you to specify one or more
37 subqueries that can be referenced by name in the <code class="command">DELETE</code>
38 query. See <a class="xref" href="queries-with.html" title="7.8. WITH Queries (Common Table Expressions)">Section 7.8</a> and <a class="xref" href="sql-select.html" title="SELECT"><span class="refentrytitle">SELECT</span></a>
40 </p></dd><dt><span class="term"><em class="replaceable"><code>table_name</code></em></span></dt><dd><p>
41 The name (optionally schema-qualified) of the table to delete rows
42 from. If <code class="literal">ONLY</code> is specified before the table name,
43 matching rows are deleted from the named table only. If
44 <code class="literal">ONLY</code> is not specified, matching rows are also deleted
45 from any tables inheriting from the named table. Optionally,
46 <code class="literal">*</code> can be specified after the table name to explicitly
47 indicate that descendant tables are included.
48 </p></dd><dt><span class="term"><em class="replaceable"><code>alias</code></em></span></dt><dd><p>
49 A substitute name for the target table. When an alias is
50 provided, it completely hides the actual name of the table. For
51 example, given <code class="literal">DELETE FROM foo AS f</code>, the remainder
52 of the <code class="command">DELETE</code> statement must refer to this
53 table as <code class="literal">f</code> not <code class="literal">foo</code>.
54 </p></dd><dt><span class="term"><em class="replaceable"><code>from_item</code></em></span></dt><dd><p>
55 A table expression allowing columns from other tables to appear
56 in the <code class="literal">WHERE</code> condition. This uses the same
57 syntax as the <a class="link" href="sql-select.html#SQL-FROM" title="FROM Clause"><code class="literal">FROM</code></a>
58 clause of a <code class="command">SELECT</code> statement; for example, an alias
59 for the table name can be specified. Do not repeat the target
60 table as a <em class="replaceable"><code>from_item</code></em>
61 unless you wish to set up a self-join (in which case it must appear
62 with an alias in the <em class="replaceable"><code>from_item</code></em>).
63 </p></dd><dt><span class="term"><em class="replaceable"><code>condition</code></em></span></dt><dd><p>
64 An expression that returns a value of type <code class="type">boolean</code>.
65 Only rows for which this expression returns <code class="literal">true</code>
67 </p></dd><dt><span class="term"><em class="replaceable"><code>cursor_name</code></em></span></dt><dd><p>
68 The name of the cursor to use in a <code class="literal">WHERE CURRENT OF</code>
69 condition. The row to be deleted is the one most recently fetched
70 from this cursor. The cursor must be a non-grouping
71 query on the <code class="command">DELETE</code>'s target table.
72 Note that <code class="literal">WHERE CURRENT OF</code> cannot be
73 specified together with a Boolean condition. See
74 <a class="xref" href="sql-declare.html" title="DECLARE"><span class="refentrytitle">DECLARE</span></a>
75 for more information about using cursors with
76 <code class="literal">WHERE CURRENT OF</code>.
77 </p></dd><dt><span class="term"><em class="replaceable"><code>output_alias</code></em></span></dt><dd><p>
78 An optional substitute name for <code class="literal">OLD</code> or
79 <code class="literal">NEW</code> rows in the <code class="literal">RETURNING</code> list.
81 By default, old values from the target table can be returned by writing
82 <code class="literal">OLD.<em class="replaceable"><code>column_name</code></em></code>
83 or <code class="literal">OLD.*</code>, and new values can be returned by writing
84 <code class="literal">NEW.<em class="replaceable"><code>column_name</code></em></code>
85 or <code class="literal">NEW.*</code>. When an alias is provided, these names are
86 hidden and the old or new rows must be referred to using the alias.
87 For example <code class="literal">RETURNING WITH (OLD AS o, NEW AS n) o.*, n.*</code>.
88 </p></dd><dt><span class="term"><em class="replaceable"><code>output_expression</code></em></span></dt><dd><p>
89 An expression to be computed and returned by the <code class="command">DELETE</code>
90 command after each row is deleted. The expression can use any
91 column names of the table named by <em class="replaceable"><code>table_name</code></em>
92 or table(s) listed in <code class="literal">USING</code>.
93 Write <code class="literal">*</code> to return all columns.
95 A column name or <code class="literal">*</code> may be qualified using
96 <code class="literal">OLD</code> or <code class="literal">NEW</code>, or the corresponding
97 <em class="replaceable"><code>output_alias</code></em> for
98 <code class="literal">OLD</code> or <code class="literal">NEW</code>, to cause old or new
99 values to be returned. An unqualified column name, or
100 <code class="literal">*</code>, or a column name or <code class="literal">*</code> qualified
101 using the target table name or alias will return old values.
103 For a simple <code class="command">DELETE</code>, all new values will be
104 <code class="literal">NULL</code>. However, if an <code class="literal">ON DELETE</code>
105 rule causes an <code class="command">INSERT</code> or <code class="command">UPDATE</code>
106 to be executed instead, the new values may be non-<code class="literal">NULL</code>.
107 </p></dd><dt><span class="term"><em class="replaceable"><code>output_name</code></em></span></dt><dd><p>
108 A name to use for a returned column.
109 </p></dd></dl></div></div><div class="refsect1" id="id-1.9.3.100.7"><h2>Outputs</h2><p>
110 On successful completion, a <code class="command">DELETE</code> command returns a command
112 </p><pre class="screen">
113 DELETE <em class="replaceable"><code>count</code></em>
115 The <em class="replaceable"><code>count</code></em> is the number
116 of rows deleted. Note that the number may be less than the number of
117 rows that matched the <em class="replaceable"><code>condition</code></em> when deletes were
118 suppressed by a <code class="literal">BEFORE DELETE</code> trigger. If <em class="replaceable"><code>count</code></em> is 0, no rows were deleted by
119 the query (this is not considered an error).
121 If the <code class="command">DELETE</code> command contains a <code class="literal">RETURNING</code>
122 clause, the result will be similar to that of a <code class="command">SELECT</code>
123 statement containing the columns and values defined in the
124 <code class="literal">RETURNING</code> list, computed over the row(s) deleted by the
126 </p></div><div class="refsect1" id="id-1.9.3.100.8"><h2>Notes</h2><p>
127 <span class="productname">PostgreSQL</span> lets you reference columns of
128 other tables in the <code class="literal">WHERE</code> condition by specifying the
129 other tables in the <code class="literal">USING</code> clause. For example,
130 to delete all films produced by a given producer, one can do:
131 </p><pre class="programlisting">
132 DELETE FROM films USING producers
133 WHERE producer_id = producers.id AND producers.name = 'foo';
135 What is essentially happening here is a join between <code class="structname">films</code>
136 and <code class="structname">producers</code>, with all successfully joined
137 <code class="structname">films</code> rows being marked for deletion.
138 This syntax is not standard. A more standard way to do it is:
139 </p><pre class="programlisting">
141 WHERE producer_id IN (SELECT id FROM producers WHERE name = 'foo');
143 In some cases the join style is easier to write or faster to
144 execute than the sub-select style.
145 </p></div><div class="refsect1" id="id-1.9.3.100.9"><h2>Examples</h2><p>
146 Delete all films but musicals:
147 </p><pre class="programlisting">
148 DELETE FROM films WHERE kind <> 'Musical';
151 Clear the table <code class="literal">films</code>:
152 </p><pre class="programlisting">
156 Delete completed tasks, returning full details of the deleted rows:
157 </p><pre class="programlisting">
158 DELETE FROM tasks WHERE status = 'DONE' RETURNING *;
161 Delete the row of <code class="structname">tasks</code> on which the cursor
162 <code class="literal">c_tasks</code> is currently positioned:
163 </p><pre class="programlisting">
164 DELETE FROM tasks WHERE CURRENT OF c_tasks;
167 While there is no <code class="literal">LIMIT</code> clause
168 for <code class="command">DELETE</code>, it is possible to get a similar effect
169 using the same method described in <a class="link" href="sql-update.html#UPDATE-LIMIT">the
170 documentation of <code class="command">UPDATE</code></a>:
171 </p><pre class="programlisting">
172 WITH delete_batch AS (
173 SELECT l.ctid FROM user_logs AS l
174 WHERE l.status = 'archived'
175 ORDER BY l.creation_date
179 DELETE FROM user_logs AS dl
180 USING delete_batch AS del
181 WHERE dl.ctid = del.ctid;
183 </p></div><div class="refsect1" id="id-1.9.3.100.10"><h2>Compatibility</h2><p>
184 This command conforms to the <acronym class="acronym">SQL</acronym> standard, except
185 that the <code class="literal">USING</code> and <code class="literal">RETURNING</code> clauses
186 are <span class="productname">PostgreSQL</span> extensions, as is the ability
187 to use <code class="literal">WITH</code> with <code class="command">DELETE</code>.
188 </p></div><div class="refsect1" id="id-1.9.3.100.11"><h2>See Also</h2><span class="simplelist"><a class="xref" href="sql-truncate.html" title="TRUNCATE"><span class="refentrytitle">TRUNCATE</span></a></span></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="sql-declare.html" title="DECLARE">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="sql-commands.html" title="SQL Commands">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="sql-discard.html" title="DISCARD">Next</a></td></tr><tr><td width="40%" align="left" valign="top">DECLARE </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="40%" align="right" valign="top"> DISCARD</td></tr></table></div></body></html>