@@ -22,7 +22,9 @@ PostgreSQL documentation
2222 <refsynopsisdiv>
2323<synopsis>
2424[ WITH [ RECURSIVE ] <replaceable class="parameter">with_query</replaceable> [, ...] ]
25- DELETE FROM [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] [ [ AS ] <replaceable class="parameter">alias</replaceable> ]
25+ DELETE FROM [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ]
26+ [ FOR PORTION OF <replaceable class="parameter">range_name</replaceable> <replaceable class="parameter">for_portion_of_target</replaceable> ]
27+ [ [ AS ] <replaceable class="parameter">alias</replaceable> ]
2628 [ USING <replaceable class="parameter">from_item</replaceable> [, ...] ]
2729 [ WHERE <replaceable class="parameter">condition</replaceable> | WHERE CURRENT OF <replaceable class="parameter">cursor_name</replaceable> ]
2830 [ RETURNING [ WITH ( { OLD | NEW } AS <replaceable class="parameter">output_alias</replaceable> [, ...] ) ]
@@ -55,6 +57,43 @@ DELETE FROM [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ *
5557 circumstances.
5658 </para>
5759
60+ <para>
61+ If the table has a range or multirange column,
62+ you may supply a <literal>FOR PORTION OF</literal> clause, and your delete will
63+ only affect rows that overlap the given interval. Furthermore, if a row's history
64+ extends outside the <literal>FOR PORTION OF</literal> bounds, then your delete
65+ will only change the history within those bounds. In effect you are deleting any
66+ moment targeted by <literal>FOR PORTION OF</literal> and no moments outside.
67+ </para>
68+
69+ <para>
70+ Specifically, after <productname>PostgreSQL</productname> deletes the existing row,
71+ it will <literal>INSERT</literal>
72+ new <glossterm linkend="glossary-temporal-leftovers">temporal leftovers</glossterm>:
73+ rows whose range or multirange receive the remaining history outside
74+ the targeted bounds, with un-updated values in their other columns.
75+ There will be zero to two inserted records,
76+ depending on whether the original history extended before the targeted
77+ <literal>FROM</literal>, after the targeted <literal>TO</literal>, both, or neither.
78+ Multiranges never require two temporal leftovers, because one value can always contain
79+ whatever history remains.
80+ </para>
81+
82+ <para>
83+ These secondary inserts fire <literal>INSERT</literal> triggers.
84+ Both <literal>STATEMENT</literal> and <literal>ROW</literal> triggers are fired.
85+ The <literal>BEFORE DELETE</literal> triggers are fired first, then
86+ <literal>BEFORE INSERT</literal>, then <literal>AFTER INSERT</literal>,
87+ then <literal>AFTER DELETE</literal>.
88+ </para>
89+
90+ <para>
91+ These secondary inserts do not require <literal>INSERT</literal> privilege on the table.
92+ This is because conceptually no new information has been added. The inserted rows only preserve
93+ existing data about the untargeted time period. Note this may result in users firing <literal>INSERT</literal>
94+ triggers who don't have insert privileges, so be careful about <literal>SECURITY DEFINER</literal> trigger functions!
95+ </para>
96+
5897 <para>
5998 The optional <literal>RETURNING</literal> clause causes <command>DELETE</command>
6099 to compute and return value(s) based on each row actually deleted.
@@ -117,6 +156,57 @@ DELETE FROM [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ *
117156 </listitem>
118157 </varlistentry>
119158
159+ <varlistentry>
160+ <term><replaceable class="parameter">range_name</replaceable></term>
161+ <listitem>
162+ <para>
163+ The range or multirange column to use when performing a temporal delete.
164+ </para>
165+ </listitem>
166+ </varlistentry>
167+
168+ <varlistentry>
169+ <term><replaceable class="parameter">for_portion_of_target</replaceable></term>
170+ <listitem>
171+ <para>
172+ The interval to delete. If you are targeting a range column,
173+ you may give this in the form <literal>FROM</literal>
174+ <replaceable class="parameter">start_time</replaceable> <literal>TO</literal>
175+ <replaceable class="parameter">end_time</replaceable>.
176+ Otherwise you must use
177+ <literal>(</literal><replaceable class="parameter">expression</replaceable><literal>)</literal>
178+ where the expression yields a value of the same type as
179+ <replaceable class="parameter">range_name</replaceable>.
180+ </para>
181+ </listitem>
182+ </varlistentry>
183+
184+ <varlistentry>
185+ <term><replaceable class="parameter">start_time</replaceable></term>
186+ <listitem>
187+ <para>
188+ The earliest time (inclusive) to change in a temporal delete.
189+ This must be a value matching the base type of the range from
190+ <replaceable class="parameter">range_name</replaceable>. A
191+ <literal>NULL</literal> here indicates a delete whose beginning is
192+ unbounded (as with range types).
193+ </para>
194+ </listitem>
195+ </varlistentry>
196+
197+ <varlistentry>
198+ <term><replaceable class="parameter">end_time</replaceable></term>
199+ <listitem>
200+ <para>
201+ The latest time (exclusive) to change in a temporal delete.
202+ This must be a value matching the base type of the range from
203+ <replaceable class="parameter">range_name</replaceable>. A
204+ <literal>NULL</literal> here indicates a delete whose end is unbounded
205+ (as with range types).
206+ </para>
207+ </listitem>
208+ </varlistentry>
209+
120210 <varlistentry>
121211 <term><replaceable class="parameter">from_item</replaceable></term>
122212 <listitem>
@@ -238,6 +328,10 @@ DELETE <replaceable class="parameter">count</replaceable>
238328 suppressed by a <literal>BEFORE DELETE</literal> trigger. If <replaceable
239329 class="parameter">count</replaceable> is 0, no rows were deleted by
240330 the query (this is not considered an error).
331+ If <literal>FOR PORTION OF</literal> was used, the
332+ <replaceable class="parameter">count</replaceable> also includes
333+ <glossterm linkend="glossary-temporal-leftovers">temporal leftovers</glossterm>
334+ that were inserted.
241335 </para>
242336
243337 <para>
0 commit comments