Skip to content

Commit daee80e

Browse files
pjungwirCommitfest Bot
authored and
Commitfest Bot
committed
Add UPDATE/DELETE FOR PORTION OF
- 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
1 parent 3446556 commit daee80e

Some content is hidden

Large Commits have some content hidden by default. Use the searchbox below for content that may be hidden.

49 files changed

+3299
-114
lines changed

contrib/postgres_fdw/expected/postgres_fdw.out

+44-1
Original file line numberDiff line numberDiff line change
@@ -57,11 +57,19 @@ CREATE TABLE "S 1"."T 4" (
5757
c3 text,
5858
CONSTRAINT t4_pkey PRIMARY KEY (c1)
5959
);
60+
CREATE TABLE "S 1"."T 5" (
61+
c1 int4range NOT NULL,
62+
c2 int NOT NULL,
63+
c3 text,
64+
c4 daterange NOT NULL,
65+
CONSTRAINT t5_pkey PRIMARY KEY (c1, c4 WITHOUT OVERLAPS)
66+
);
6067
-- Disable autovacuum for these tables to avoid unexpected effects of that
6168
ALTER TABLE "S 1"."T 1" SET (autovacuum_enabled = 'false');
6269
ALTER TABLE "S 1"."T 2" SET (autovacuum_enabled = 'false');
6370
ALTER TABLE "S 1"."T 3" SET (autovacuum_enabled = 'false');
6471
ALTER TABLE "S 1"."T 4" SET (autovacuum_enabled = 'false');
72+
ALTER TABLE "S 1"."T 5" SET (autovacuum_enabled = 'false');
6573
INSERT INTO "S 1"."T 1"
6674
SELECT id,
6775
id % 10,
@@ -88,10 +96,17 @@ INSERT INTO "S 1"."T 4"
8896
'AAA' || to_char(id, 'FM000')
8997
FROM generate_series(1, 100) id;
9098
DELETE FROM "S 1"."T 4" WHERE c1 % 3 != 0; -- delete for outer join tests
99+
INSERT INTO "S 1"."T 5"
100+
SELECT int4range(id, id + 1),
101+
id + 1,
102+
'AAA' || to_char(id, 'FM000'),
103+
'[2000-01-01,2020-01-01)'
104+
FROM generate_series(1, 100) id;
91105
ANALYZE "S 1"."T 1";
92106
ANALYZE "S 1"."T 2";
93107
ANALYZE "S 1"."T 3";
94108
ANALYZE "S 1"."T 4";
109+
ANALYZE "S 1"."T 5";
95110
-- ===================================================================
96111
-- create foreign tables
97112
-- ===================================================================
@@ -139,6 +154,12 @@ CREATE FOREIGN TABLE ft7 (
139154
c2 int NOT NULL,
140155
c3 text
141156
) SERVER loopback3 OPTIONS (schema_name 'S 1', table_name 'T 4');
157+
CREATE FOREIGN TABLE ft8 (
158+
c1 int4range NOT NULL,
159+
c2 int NOT NULL,
160+
c3 text,
161+
c4 daterange NOT NULL
162+
) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 5');
142163
-- ===================================================================
143164
-- tests for validator
144165
-- ===================================================================
@@ -210,7 +231,8 @@ ALTER FOREIGN TABLE ft2 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
210231
public | ft5 | loopback | (schema_name 'S 1', table_name 'T 4') |
211232
public | ft6 | loopback2 | (schema_name 'S 1', table_name 'T 4') |
212233
public | ft7 | loopback3 | (schema_name 'S 1', table_name 'T 4') |
213-
(6 rows)
234+
public | ft8 | loopback | (schema_name 'S 1', table_name 'T 5') |
235+
(7 rows)
214236

215237
-- Test that alteration of server options causes reconnection
216238
-- Remote's errors might be non-English, so hide them to ensure stable results
@@ -6176,6 +6198,27 @@ DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass;
61766198
ft2
61776199
(1 row)
61786200

6201+
-- Test UPDATE FOR PORTION OF
6202+
UPDATE ft8 FOR PORTION OF c4 FROM '2005-01-01' TO '2006-01-01'
6203+
SET c2 = c2 + 1
6204+
WHERE c1 = '[1,2)';
6205+
ERROR: foreign tables don't support FOR PORTION OF
6206+
SELECT * FROM ft8 WHERE c1 = '[1,2)' ORDER BY c1, c4;
6207+
c1 | c2 | c3 | c4
6208+
-------+----+--------+-------------------------
6209+
[1,2) | 2 | AAA001 | [01-01-2000,01-01-2020)
6210+
(1 row)
6211+
6212+
-- Test DELETE FOR PORTION OF
6213+
DELETE FROM ft8 FOR PORTION OF c4 FROM '2005-01-01' TO '2006-01-01'
6214+
WHERE c1 = '[2,3)';
6215+
ERROR: foreign tables don't support FOR PORTION OF
6216+
SELECT * FROM ft8 WHERE c1 = '[2,3)' ORDER BY c1, c4;
6217+
c1 | c2 | c3 | c4
6218+
-------+----+--------+-------------------------
6219+
[2,3) | 3 | AAA002 | [01-01-2000,01-01-2020)
6220+
(1 row)
6221+
61796222
-- Test UPDATE/DELETE with RETURNING on a three-table join
61806223
INSERT INTO ft2 (c1,c2,c3)
61816224
SELECT id, id - 1200, to_char(id, 'FM00000') FROM generate_series(1201, 1300) id;

contrib/postgres_fdw/sql/postgres_fdw.sql

+34
Original file line numberDiff line numberDiff line change
@@ -61,12 +61,20 @@ CREATE TABLE "S 1"."T 4" (
6161
c3 text,
6262
CONSTRAINT t4_pkey PRIMARY KEY (c1)
6363
);
64+
CREATE TABLE "S 1"."T 5" (
65+
c1 int4range NOT NULL,
66+
c2 int NOT NULL,
67+
c3 text,
68+
c4 daterange NOT NULL,
69+
CONSTRAINT t5_pkey PRIMARY KEY (c1, c4 WITHOUT OVERLAPS)
70+
);
6471

6572
-- Disable autovacuum for these tables to avoid unexpected effects of that
6673
ALTER TABLE "S 1"."T 1" SET (autovacuum_enabled = 'false');
6774
ALTER TABLE "S 1"."T 2" SET (autovacuum_enabled = 'false');
6875
ALTER TABLE "S 1"."T 3" SET (autovacuum_enabled = 'false');
6976
ALTER TABLE "S 1"."T 4" SET (autovacuum_enabled = 'false');
77+
ALTER TABLE "S 1"."T 5" SET (autovacuum_enabled = 'false');
7078

7179
INSERT INTO "S 1"."T 1"
7280
SELECT id,
@@ -94,11 +102,18 @@ INSERT INTO "S 1"."T 4"
94102
'AAA' || to_char(id, 'FM000')
95103
FROM generate_series(1, 100) id;
96104
DELETE FROM "S 1"."T 4" WHERE c1 % 3 != 0; -- delete for outer join tests
105+
INSERT INTO "S 1"."T 5"
106+
SELECT int4range(id, id + 1),
107+
id + 1,
108+
'AAA' || to_char(id, 'FM000'),
109+
'[2000-01-01,2020-01-01)'
110+
FROM generate_series(1, 100) id;
97111

98112
ANALYZE "S 1"."T 1";
99113
ANALYZE "S 1"."T 2";
100114
ANALYZE "S 1"."T 3";
101115
ANALYZE "S 1"."T 4";
116+
ANALYZE "S 1"."T 5";
102117

103118
-- ===================================================================
104119
-- create foreign tables
@@ -153,6 +168,14 @@ CREATE FOREIGN TABLE ft7 (
153168
c3 text
154169
) SERVER loopback3 OPTIONS (schema_name 'S 1', table_name 'T 4');
155170

171+
CREATE FOREIGN TABLE ft8 (
172+
c1 int4range NOT NULL,
173+
c2 int NOT NULL,
174+
c3 text,
175+
c4 daterange NOT NULL
176+
) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 5');
177+
178+
156179
-- ===================================================================
157180
-- tests for validator
158181
-- ===================================================================
@@ -1511,6 +1534,17 @@ EXPLAIN (verbose, costs off)
15111534
DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
15121535
DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass;
15131536

1537+
-- Test UPDATE FOR PORTION OF
1538+
UPDATE ft8 FOR PORTION OF c4 FROM '2005-01-01' TO '2006-01-01'
1539+
SET c2 = c2 + 1
1540+
WHERE c1 = '[1,2)';
1541+
SELECT * FROM ft8 WHERE c1 = '[1,2)' ORDER BY c1, c4;
1542+
1543+
-- Test DELETE FOR PORTION OF
1544+
DELETE FROM ft8 FOR PORTION OF c4 FROM '2005-01-01' TO '2006-01-01'
1545+
WHERE c1 = '[2,3)';
1546+
SELECT * FROM ft8 WHERE c1 = '[2,3)' ORDER BY c1, c4;
1547+
15141548
-- Test UPDATE/DELETE with RETURNING on a three-table join
15151549
INSERT INTO ft2 (c1,c2,c3)
15161550
SELECT id, id - 1200, to_char(id, 'FM00000') FROM generate_series(1201, 1300) id;

contrib/sepgsql/proc.c

+1-1
Original file line numberDiff line numberDiff line change
@@ -161,7 +161,7 @@ sepgsql_proc_drop(Oid functionId)
161161
* check db_schema:{remove_name} permission
162162
*/
163163
object.classId = NamespaceRelationId;
164-
object.objectId = get_func_namespace(functionId);
164+
object.objectId = get_func_namespace(functionId, true);
165165
object.objectSubId = 0;
166166
audit_name = getObjectIdentity(&object, false);
167167

doc/src/sgml/ref/create_publication.sgml

+6
Original file line numberDiff line numberDiff line change
@@ -367,6 +367,12 @@ CREATE PUBLICATION <replaceable class="parameter">name</replaceable>
367367
for each row inserted, updated, or deleted.
368368
</para>
369369

370+
<para>
371+
For a <command>FOR PORTION OF</command> command, the publication will publish an
372+
<command>UPDATE</command> or <command>DELETE</command>, followed by one
373+
<command>INSERT</command> for each leftover row inserted.
374+
</para>
375+
370376
<para>
371377
<command>ATTACH</command>ing a table into a partition tree whose root is
372378
published using a publication with <literal>publish_via_partition_root</literal>

doc/src/sgml/ref/delete.sgml

+71-1
Original file line numberDiff line numberDiff line change
@@ -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_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> ]
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,39 @@ 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 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+
5893
<para>
5994
The optional <literal>RETURNING</literal> clause causes <command>DELETE</command>
6095
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> [ *
117152
</listitem>
118153
</varlistentry>
119154

155+
<varlistentry>
156+
<term><replaceable class="parameter">range_or_period_name</replaceable></term>
157+
<listitem>
158+
<para>
159+
The range column or period to use when performing a temporal delete.
160+
</para>
161+
</listitem>
162+
</varlistentry>
163+
164+
<varlistentry>
165+
<term><replaceable class="parameter">start_time</replaceable></term>
166+
<listitem>
167+
<para>
168+
The earliest time (inclusive) to change in a temporal delete.
169+
This must be a value matching the base type of the range or period from
170+
<replaceable class="parameter">range_or_period_name</replaceable>. A
171+
<literal>NULL</literal> here indicates a delete whose beginning is
172+
unbounded (as with range types).
173+
</para>
174+
</listitem>
175+
</varlistentry>
176+
177+
<varlistentry>
178+
<term><replaceable class="parameter">end_time</replaceable></term>
179+
<listitem>
180+
<para>
181+
The latest time (exclusive) to change in a temporal delete.
182+
This must be a value matching the base type of the range or period from
183+
<replaceable class="parameter">range_or_period_name</replaceable>. A
184+
<literal>NULL</literal> here indicates a delete whose end is unbounded
185+
(as with range types).
186+
</para>
187+
</listitem>
188+
</varlistentry>
189+
120190
<varlistentry>
121191
<term><replaceable class="parameter">from_item</replaceable></term>
122192
<listitem>

doc/src/sgml/ref/update.sgml

+89-1
Original file line numberDiff line numberDiff line change
@@ -22,7 +22,9 @@ PostgreSQL documentation
2222
<refsynopsisdiv>
2323
<synopsis>
2424
[ 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> ]
2628
SET { <replaceable class="parameter">column_name</replaceable> = { <replaceable class="parameter">expression</replaceable> | DEFAULT } |
2729
( <replaceable class="parameter">column_name</replaceable> [, ...] ) = [ ROW ] ( { <replaceable class="parameter">expression</replaceable> | DEFAULT } [, ...] ) |
2830
( <replaceable class="parameter">column_name</replaceable> [, ...] ) = ( <replaceable class="parameter">sub-SELECT</replaceable> )
@@ -52,6 +54,41 @@ UPDATE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] [
5254
circumstances.
5355
</para>
5456

57+
<para>
58+
If the table has a range or multirange column,
59+
you may supply a <literal>FOR PORTION OF</literal> clause, and your update will
60+
only affect rows that overlap the given interval. Furthermore, if a row's span
61+
extends outside the <literal>FOR PORTION OF</literal> bounds, then your update
62+
will only change the span within those bounds. In effect you are updating any
63+
moment targeted by <literal>FOR PORTION OF</literal> and no moments outside.
64+
</para>
65+
66+
<para>
67+
Specifically, when <productname>PostgreSQL</productname> updates the existing row,
68+
it will also change the range or start/end column(s) so that their interval
69+
no longer extends beyond the targeted <literal>FOR PORTION OF</literal> bounds.
70+
Then <productname>PostgreSQL</productname> will <literal>INSERT</literal>
71+
new rows whose range or start/end column(s) receive the remaining span outside
72+
the targeted bounds, containing the un-updated values in other columns.
73+
There will be zero to two inserted records,
74+
depending on whether the original span extended before the targeted
75+
<literal>FROM</literal>, after the targeted <literal>TO</literal>, both, or neither.
76+
</para>
77+
78+
<para>
79+
These secondary inserts fire <literal>INSERT</literal> triggers. First
80+
<literal>BEFORE UPDATE</literal> triggers first, then
81+
<literal>BEFORE INSERT</literal>, then <literal>AFTER INSERT</literal>,
82+
then <literal>AFTER UPDATE</literal>.
83+
</para>
84+
85+
<para>
86+
These secondary inserts do not require <literal>INSERT</literal> privilege on the table.
87+
This is because conceptually no new information has been added. The inserted rows only preserve
88+
existing data about the untargeted time period. Note this may result in users firing <literal>INSERT</literal>
89+
triggers who don't have insert privileges, so be careful about <literal>SECURITY DEFINER</literal> trigger functions!
90+
</para>
91+
5592
<para>
5693
The optional <literal>RETURNING</literal> clause causes <command>UPDATE</command>
5794
to compute and return value(s) based on each row actually updated.
@@ -115,6 +152,57 @@ UPDATE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] [
115152
</listitem>
116153
</varlistentry>
117154

155+
<varlistentry>
156+
<term><replaceable class="parameter">range_or_period_name</replaceable></term>
157+
<listitem>
158+
<para>
159+
The range column or period to use when performing a temporal update.
160+
</para>
161+
</listitem>
162+
</varlistentry>
163+
164+
<varlistentry>
165+
<term><replaceable class="parameter">for_portion_of_target</replaceable></term>
166+
<listitem>
167+
<para>
168+
The interval to update. If you are targeting a range column or <literal>PERIOD</literal>,
169+
you may give this in the form <literal>FROM</literal>
170+
<replaceable class="parameter">start_time</replaceable> <literal>TO</literal>
171+
<replaceable class="parameter">end_time</replaceable>.
172+
Otherwise you must use
173+
<literal>(</literal><replaceable class="parameter">expression</replaceable><literal>)</literal>
174+
where the expression yields a value for the same type as
175+
<replaceable class="parameter">range_or_period_name</replaceable>.
176+
</para>
177+
</listitem>
178+
</varlistentry>
179+
180+
<varlistentry>
181+
<term><replaceable class="parameter">start_time</replaceable></term>
182+
<listitem>
183+
<para>
184+
The earliest time (inclusive) to change in a temporal update.
185+
This must be a value matching the base type of the range or period from
186+
<replaceable class="parameter">range_or_period_name</replaceable>. A
187+
<literal>NULL</literal> here indicates an update whose beginning is
188+
unbounded (as with range types).
189+
</para>
190+
</listitem>
191+
</varlistentry>
192+
193+
<varlistentry>
194+
<term><replaceable class="parameter">end_time</replaceable></term>
195+
<listitem>
196+
<para>
197+
The latest time (exclusive) to change in a temporal update.
198+
This must be a value matching the base type of the range or period from
199+
<replaceable class="parameter">range_or_period_name</replaceable>. A
200+
<literal>NULL</literal> here indicates an update whose end is unbounded
201+
(as with range types).
202+
</para>
203+
</listitem>
204+
</varlistentry>
205+
118206
<varlistentry>
119207
<term><replaceable class="parameter">column_name</replaceable></term>
120208
<listitem>

0 commit comments

Comments
 (0)