You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
- Added bison support for FOR PORTION OF syntax. The bounds must be
constant, so we forbid column references, subqueries, etc. We do
accept functions like NOW().
- Added logic to executor to insert new rows for the "leftover" part of
a record touched by a FOR PORTION OF query.
- Added tg_temporal descriptor to the TriggerData struct that we pass to
trigger functions. Our foreign key triggers use this to learn what
bounds were given in the FOR PORTION OF clause.
- Documented FOR PORTION OF.
- Documented tg_temporal struct.
- Added tests.
Author: Paul Jungwirth
Copy file name to clipboardExpand all lines: doc/src/sgml/ref/delete.sgml
+71-1
Original file line number
Diff line number
Diff line change
@@ -22,7 +22,9 @@ PostgreSQL documentation
22
22
<refsynopsisdiv>
23
23
<synopsis>
24
24
[ 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_or_period_name</replaceable> FROM <replaceable class="parameter">start_time</replaceable> TO <replaceable class="parameter">end_time</replaceable> ]
27
+
[ [ AS ] <replaceable class="parameter">alias</replaceable> ]
26
28
[ USING <replaceable class="parameter">from_item</replaceable> [, ...] ]
27
29
[ WHERE <replaceable class="parameter">condition</replaceable> | WHERE CURRENT OF <replaceable class="parameter">cursor_name</replaceable> ]
28
30
[ RETURNING [ WITH ( { OLD | NEW } AS <replaceable class="parameter">output_alias</replaceable> [, ...] ) ]
@@ -55,6 +57,39 @@ DELETE FROM [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ *
55
57
circumstances.
56
58
</para>
57
59
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 span
64
+
extends outside the <literal>FOR PORTION OF</literal> bounds, then your delete
65
+
will only change the span 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 rows whose range or start/end column(s) receive the remaining span outside
73
+
the targeted bounds, containing the original values in other columns.
74
+
There will be zero to two inserted records,
75
+
depending on whether the original span extended before the targeted
76
+
<literal>FROM</literal>, after the targeted <literal>TO</literal>, both, or neither.
77
+
</para>
78
+
79
+
<para>
80
+
These secondary inserts fire <literal>INSERT</literal> triggers. First
81
+
<literal>BEFORE DELETE</literal> triggers first, then
82
+
<literal>BEFORE INSERT</literal>, then <literal>AFTER INSERT</literal>,
83
+
then <literal>AFTER DELETE</literal>.
84
+
</para>
85
+
86
+
<para>
87
+
These secondary inserts do not require <literal>INSERT</literal> privilege on the table.
88
+
This is because conceptually no new information has been added. The inserted rows only preserve
89
+
existing data about the untargeted time period. Note this may result in users firing <literal>INSERT</literal>
90
+
triggers who don't have insert privileges, so be careful about <literal>SECURITY DEFINER</literal> trigger functions!
91
+
</para>
92
+
58
93
<para>
59
94
The optional <literal>RETURNING</literal> clause causes <command>DELETE</command>
60
95
to compute and return value(s) based on each row actually deleted.
@@ -117,6 +152,41 @@ DELETE FROM [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ *
Copy file name to clipboardExpand all lines: doc/src/sgml/ref/update.sgml
+89-1
Original file line number
Diff line number
Diff line change
@@ -22,7 +22,9 @@ PostgreSQL documentation
22
22
<refsynopsisdiv>
23
23
<synopsis>
24
24
[ WITH [ RECURSIVE ] <replaceable class="parameter">with_query</replaceable> [, ...] ]
25
-
UPDATE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] [ [ AS ] <replaceable class="parameter">alias</replaceable> ]
25
+
UPDATE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ]
26
+
[ FOR PORTION OF <replaceable class="parameter">range_or_period_name</replaceable> <replaceable class="parameter">for_portion_of_target</replaceable> ]
27
+
[ [ AS ] <replaceable class="parameter">alias</replaceable> ]
0 commit comments