summaryrefslogtreecommitdiffstats
path: root/doc/src/sgml/ref/delete.sgml
blob: 1b81b4e7d743f49c52e17deaa6035adec878a7bf (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
<!--
doc/src/sgml/ref/delete.sgml
PostgreSQL documentation
-->

<refentry id="sql-delete">
 <indexterm zone="sql-delete">
  <primary>DELETE</primary>
 </indexterm>

 <refmeta>
  <refentrytitle>DELETE</refentrytitle>
  <manvolnum>7</manvolnum>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>

 <refnamediv>
  <refname>DELETE</refname>
  <refpurpose>delete rows of a table</refpurpose>
 </refnamediv>

 <refsynopsisdiv>
<synopsis>
[ WITH [ RECURSIVE ] <replaceable class="parameter">with_query</replaceable> [, ...] ]
DELETE FROM [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] [ [ AS ] <replaceable class="parameter">alias</replaceable> ]
    [ USING <replaceable class="parameter">from_item</replaceable> [, ...] ]
    [ WHERE <replaceable class="parameter">condition</replaceable> | WHERE CURRENT OF <replaceable class="parameter">cursor_name</replaceable> ]
    [ RETURNING * | <replaceable class="parameter">output_expression</replaceable> [ [ AS ] <replaceable class="parameter">output_name</replaceable> ] [, ...] ]
</synopsis>
 </refsynopsisdiv>

 <refsect1>
  <title>Description</title>

  <para>
   <command>DELETE</command> deletes rows that satisfy the
   <literal>WHERE</literal> clause from the specified table.  If the
   <literal>WHERE</literal> clause is absent, the effect is to delete
   all rows in the table.  The result is a valid, but empty table.
  </para>

   <tip>
    <para>
     <link linkend="sql-truncate"><command>TRUNCATE</command></link> provides a
     faster mechanism to remove all rows from a table.
    </para>
   </tip>

  <para>
   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 <literal>USING</literal> clause.
   Which technique is more appropriate depends on the specific
   circumstances.
  </para>

  <para>
   The optional <literal>RETURNING</literal> clause causes <command>DELETE</command>
   to compute and return value(s) based on each row actually deleted.
   Any expression using the table's columns, and/or columns of other
   tables mentioned in <literal>USING</literal>, can be computed.
   The syntax of the <literal>RETURNING</literal> list is identical to that of the
   output list of <command>SELECT</command>.
  </para>

  <para>
   You must have the <literal>DELETE</literal> privilege on the table
   to delete from it, as well as the <literal>SELECT</literal>
   privilege for any table in the <literal>USING</literal> clause or
   whose values are read in the <replaceable
   class="parameter">condition</replaceable>.
  </para>
 </refsect1>

 <refsect1>
  <title>Parameters</title>

  <variablelist>
   <varlistentry>
    <term><replaceable class="parameter">with_query</replaceable></term>
    <listitem>
     <para>
      The <literal>WITH</literal> clause allows you to specify one or more
      subqueries that can be referenced by name in the <command>DELETE</command>
      query. See <xref linkend="queries-with"/> and <xref linkend="sql-select"/>
      for details.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">table_name</replaceable></term>
    <listitem>
     <para>
      The name (optionally schema-qualified) of the table to delete rows
      from.  If <literal>ONLY</literal> is specified before the table name,
      matching rows are deleted from the named table only.  If
      <literal>ONLY</literal> is not specified, matching rows are also deleted
      from any tables inheriting from the named table.  Optionally,
      <literal>*</literal> can be specified after the table name to explicitly
      indicate that descendant tables are included.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">alias</replaceable></term>
    <listitem>
     <para>
      A substitute name for the target table. When an alias is
      provided, it completely hides the actual name of the table.  For
      example, given <literal>DELETE FROM foo AS f</literal>, the remainder
      of the <command>DELETE</command> statement must refer to this
      table as <literal>f</literal> not <literal>foo</literal>.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">from_item</replaceable></term>
    <listitem>
     <para>
      A table expression allowing columns from other tables to appear
      in the <literal>WHERE</literal> condition.  This uses the same
      syntax as the <link linkend="sql-from"><literal>FROM</literal></link>
      clause of a <command>SELECT</command> statement; for example, an alias
      for the table name can be specified.  Do not repeat the target
      table as a <replaceable class="parameter">from_item</replaceable>
      unless you wish to set up a self-join (in which case it must appear
      with an alias in the <replaceable>from_item</replaceable>).
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">condition</replaceable></term>
    <listitem>
     <para>
      An expression that returns a value of type <type>boolean</type>.
      Only rows for which this expression returns <literal>true</literal>
      will be deleted.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">cursor_name</replaceable></term>
    <listitem>
     <para>
      The name of the cursor to use in a <literal>WHERE CURRENT OF</literal>
      condition.  The row to be deleted is the one most recently fetched
      from this cursor.  The cursor must be a non-grouping
      query on the <command>DELETE</command>'s target table.
      Note that <literal>WHERE CURRENT OF</literal> cannot be
      specified together with a Boolean condition.  See
      <xref linkend="sql-declare"/>
      for more information about using cursors with
      <literal>WHERE CURRENT OF</literal>.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">output_expression</replaceable></term>
    <listitem>
     <para>
      An expression to be computed and returned by the <command>DELETE</command>
      command after each row is deleted.  The expression can use any
      column names of the table named by <replaceable class="parameter">table_name</replaceable>
      or table(s) listed in <literal>USING</literal>.
      Write <literal>*</literal> to return all columns.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">output_name</replaceable></term>
    <listitem>
     <para>
      A name to use for a returned column.
     </para>
    </listitem>
   </varlistentry>
  </variablelist>
 </refsect1>

 <refsect1>
  <title>Outputs</title>

  <para>
   On successful completion, a <command>DELETE</command> command returns a command
   tag of the form
<screen>
DELETE <replaceable class="parameter">count</replaceable>
</screen>
   The <replaceable class="parameter">count</replaceable> is the number
   of rows deleted.  Note that the number may be less than the number of
   rows that matched the <replaceable
   class="parameter">condition</replaceable> when deletes were
   suppressed by a <literal>BEFORE DELETE</literal> trigger.  If <replaceable
   class="parameter">count</replaceable> is 0, no rows were deleted by
   the query (this is not considered an error).
  </para>

  <para>
   If the <command>DELETE</command> command contains a <literal>RETURNING</literal>
   clause, the result will be similar to that of a <command>SELECT</command>
   statement containing the columns and values defined in the
   <literal>RETURNING</literal> list, computed over the row(s) deleted by the
   command.
  </para>
 </refsect1>

 <refsect1>
  <title>Notes</title>

  <para>
   <productname>PostgreSQL</productname> lets you reference columns of
   other tables in the <literal>WHERE</literal> condition by specifying the
   other tables in the <literal>USING</literal> clause.  For example,
   to delete all films produced by a given producer, one can do:
<programlisting>
DELETE FROM films USING producers
  WHERE producer_id = producers.id AND producers.name = 'foo';
</programlisting>
   What is essentially happening here is a join between <structname>films</structname>
   and <structname>producers</structname>, with all successfully joined
   <structname>films</structname> rows being marked for deletion.
   This syntax is not standard.  A more standard way to do it is:
<programlisting>
DELETE FROM films
  WHERE producer_id IN (SELECT id FROM producers WHERE name = 'foo');
</programlisting>
   In some cases the join style is easier to write or faster to
   execute than the sub-select style.
  </para>
 </refsect1>

 <refsect1>
  <title>Examples</title>

  <para>
   Delete all films but musicals:
<programlisting>
DELETE FROM films WHERE kind &lt;&gt; 'Musical';
</programlisting>
  </para>

  <para>
   Clear the table <literal>films</literal>:
<programlisting>
DELETE FROM films;
</programlisting>
  </para>

  <para>
   Delete completed tasks, returning full details of the deleted rows:
<programlisting>
DELETE FROM tasks WHERE status = 'DONE' RETURNING *;
</programlisting>
  </para>

   <para>
   Delete the row of <structname>tasks</structname> on which the cursor
   <literal>c_tasks</literal> is currently positioned:
<programlisting>
DELETE FROM tasks WHERE CURRENT OF c_tasks;
</programlisting></para>
 </refsect1>

 <refsect1>
  <title>Compatibility</title>

  <para>
   This command conforms to the <acronym>SQL</acronym> standard, except
   that the <literal>USING</literal> and <literal>RETURNING</literal> clauses
   are <productname>PostgreSQL</productname> extensions, as is the ability
   to use <literal>WITH</literal> with <command>DELETE</command>.
  </para>
 </refsect1>

 <refsect1>
  <title>See Also</title>

  <simplelist type="inline">
   <member><xref linkend="sql-truncate"/></member>
  </simplelist>
 </refsect1>
</refentry>