From b148ec52709df3b46652214ee3d93451311c2d86 Mon Sep 17 00:00:00 2001 From: "Paul A. Jungwirth" Date: Tue, 17 Jun 2025 17:12:10 -0700 Subject: [PATCH 01/11] Add docs section for temporal tables, with primary keys This section introduces temporal tables, with a focus on Application Time (which we support) and only a brief mention of System Time (which we don't). It covers temporal primary keys and unique constraints. Temporal foreign keys are documented in the next commit. We will document temporal update/delete and periods as we add those features. This commit also adds glossary entries for temporal table, application time, and system time. Author: Paul A. Jungwirth --- doc/src/sgml/ddl.sgml | 198 ++++++++++++++++++++++ doc/src/sgml/glossary.sgml | 47 +++++ doc/src/sgml/images/Makefile | 3 +- doc/src/sgml/images/temporal-entities.svg | 34 ++++ doc/src/sgml/images/temporal-entities.txt | 16 ++ 5 files changed, 297 insertions(+), 1 deletion(-) create mode 100644 doc/src/sgml/images/temporal-entities.svg create mode 100644 doc/src/sgml/images/temporal-entities.txt diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index 65bc070d2e5f..74b55005ffe3 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -1585,6 +1585,204 @@ CREATE TABLE circles ( + + + Temporal Tables + + + temporal + + + + Temporal tables allow users to track different dimensions of + history. Application time tracks the history of a thing out in the + world, and system time tracks the history of the database itself. This + chapter describes how to express and manage such histories in temporal + tables. + + + + Application Time + + + application time + + + + Application time refers to a history of the + entity described by a table. In a typical non-temporal table, there is + single row for each entity. In a temporal table, an entity may have + multiple rows, as long as those rows describe non-overlapping periods + from its history. Application time requires each row to have a start + and end time, expressing when the row is true. + + + + The following SQL creates a temporal table that can store application time: + +CREATE TABLE products ( + id integer NOT NULL, + price decimal NOT NULL, + valid_at daterange NOT NULL +); + + + + + Records in a temporal table can be plotted on a timeline, as in + . Here we show three records + describing two products. Each record is a tuple with three attributes: + the id, the price, and the application time. So product 5 was first + offered for 5.00 starting January 1, 2020, but then became 8.00 starting + January 1, 2022. Its second record has no specified end time, + indicating that it is true indefinitely, or for all future time. The + last record shows that product 6 was introduced January 1, 2021 for 9.00, + then canceled January 1, 2024. + + +
+ Application Time Example + + + + + +
+ + + In a table, these records would be: + + id | price | valid_at +----+-------+------------------------- + 5 | 5 | [2020-01-01,2022-01-01) + 5 | 8 | [2022-01-01,) + 6 | 9 | [2021-01-01,2024-01-01) + + + + + We show the application time using rangetype notation, because it + is stored as a single column (either a range or multirange). By + convention ranges include their start point but exclude their end + point. That way two adjacent ranges cover all points without + overlapping. + + + + In principle, a table with application-time ranges/multiranges is + equivalent to a table that stores application-time "instants": one for + each second, millisecond, nanosecond, or whatever finest granularity is + available. But such a table would contain far too many rows, so + ranges/multiranges offer an optimization to represent the same + information in a compact form. In addition, ranges and multiranges + offer a more convenient interface for typical temporal operations, + where records change infrequently enough that separate "versions" + persist for extended periods of time. + + + + Temporal Primary Keys and Unique Constraints + + + A table with application time has a different concept of entity + integrity than a non-temporal table. Temporal entity integrity can be + enforced with a temporal primary key. A regular primary key has at + least one element, all elements are NOT NULL, and + the combined value of all elements is unique. A temporal primary key + also has at least one such element, but in addition it has a final + element that is a rangetype or multirangetype that shows when it was + true. The regular parts of the key must be unique for any moment in + time, but non-unique records are allowed if their application time does + not overlap. + + + + The syntax to create a temporal primary key is as follows: + + +ALTER TABLE products + ADD CONSTRAINT products_pkey + PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); + + + In this example, id is the non-temporal part of + the key, and valid_at is a range column containing + the application time. You can also create the primary key as part of + the CREATE + TABLE command. + + + + The WITHOUT OVERLAPS column must be NOT + NULL (like the other parts of the key). In addition it may + not contain empty values: a rangetype of 'empty' or + a multirange of {}. An empty application time would + have no meaning. + + + + It is also possible to create a temporal unique constraint that is + not a primary key. The syntax is similar: + + +ALTER TABLE products + ADD CONSTRAINT products_id_valid_at_key + UNIQUE (id, valid_at WITHOUT OVERLAPS); + + + You can also create the unique constraint as part of the CREATE TABLE + command. + + + + Temporal unique constraints also forbid empty ranges/multiranges + for their application time, although that column is permitted to be + null (like other elements of the key). + + + + Temporal primary keys and unique constraints are backed by + GiST indexes rather than B-Tree indexes. In + practice, creating a temporal primary key or exclusion constraint + requires installing the extension, so that + the database has opclasses for the non-temporal parts of the key. + + + + Temporal primary keys and unique constraints have the same behavior + as exclusion constraints, + where each regular key part is compared with equality, and the application + time is compared with overlaps, for example EXCLUDE USING gist + (id WITH =, valid_at WITH &&). The only difference is + that they also forbid an empty application time. + + +
+ + + System Time + + + system time + + + + System time refers to the history of the + database table, not the entity it describes. It captures when each row + was inserted/updated/deleted. + + + + PostgreSQL does not currently support + system time, but there are several extensions that provide its + functionality. See + the SQL:2011 + Temporal wiki page for possibilities. + + +
+ Modifying Tables diff --git a/doc/src/sgml/glossary.sgml b/doc/src/sgml/glossary.sgml index 8651f0cdb919..a76cf5c383fc 100644 --- a/doc/src/sgml/glossary.sgml +++ b/doc/src/sgml/glossary.sgml @@ -81,6 +81,21 @@ + + Application time + + + In a temporal table, + the dimension of time that represents when the entity described by the table + changed (as opposed to the table itself). + + + For more information, see + . + + + + Asynchronous I/O AIO @@ -1847,6 +1862,22 @@ + + System time + + + In a temporal table, + the dimension of time that represents when the table itself was changed + (as opposed to the entity the table describes). + Often used for auditing, compliance, and debugging. + + + For more information, see + . + + + + Table @@ -1885,6 +1916,22 @@ + + Temporal table + + + Tables + that track application time + or system time (or both). + Not to be confused with temporary tables. + + + For more information, see + . + + + + Temporary table diff --git a/doc/src/sgml/images/Makefile b/doc/src/sgml/images/Makefile index 645519095d06..1d99d4e30c8c 100644 --- a/doc/src/sgml/images/Makefile +++ b/doc/src/sgml/images/Makefile @@ -5,7 +5,8 @@ ALL_IMAGES = \ genetic-algorithm.svg \ gin.svg \ - pagelayout.svg + pagelayout.svg \ + temporal-entities.svg DITAA = ditaa DOT = dot diff --git a/doc/src/sgml/images/temporal-entities.svg b/doc/src/sgml/images/temporal-entities.svg new file mode 100644 index 000000000000..7355be472e8c --- /dev/null +++ b/doc/src/sgml/images/temporal-entities.svg @@ -0,0 +1,34 @@ + + + + + + + + + + + + + + + + + + + + + products + (5, 5.00, [1 Jan 2020,1 Jan 2022)) + 2021 + products + (6, 9.00, [1 Jan 2021,1 Jan 2024)) + 2020 + products + (5, 8.00, [1 Jan 2022,)) + 2023 + 2022 + 2024 + ... + + diff --git a/doc/src/sgml/images/temporal-entities.txt b/doc/src/sgml/images/temporal-entities.txt new file mode 100644 index 000000000000..15a86d2a2768 --- /dev/null +++ b/doc/src/sgml/images/temporal-entities.txt @@ -0,0 +1,16 @@ + + ++-------------------------------------+-------------------------------------------------------+ +| cGRE | cGRE | +| products | products | +| (5, 5.00, [1 Jan 2020,1 Jan 2022)) | (5, 8.00, [1 Jan 2022,)) | +| | | ++------------------+------------------+-------------------------------------+-----------------+ + | cGRE | + | products | + | (6, 9.00, [1 Jan 2021,1 Jan 2024)) | + | | + +--------------------------------------------------------+ + +| | | | | | +2020 2021 2022 2023 2024 ... From 3abc48dae9454af3f7ef9fb2c97b1d80876e60f1 Mon Sep 17 00:00:00 2001 From: "Paul A. Jungwirth" Date: Tue, 17 Jun 2025 23:23:28 -0700 Subject: [PATCH 02/11] Document temporal foreign keys Author: Paul A. Jungwirth --- doc/src/sgml/ddl.sgml | 98 +++++++++++++++++++++ doc/src/sgml/images/Makefile | 3 +- doc/src/sgml/images/temporal-references.svg | 37 ++++++++ doc/src/sgml/images/temporal-references.txt | 21 +++++ 4 files changed, 158 insertions(+), 1 deletion(-) create mode 100644 doc/src/sgml/images/temporal-references.svg create mode 100644 doc/src/sgml/images/temporal-references.txt diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index 74b55005ffe3..53d849bf34ca 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -1758,6 +1758,103 @@ ALTER TABLE products that they also forbid an empty application time. + + + Temporal Foreign Keys + + + A temporal foreign key is a reference from one application-time + table to another application-time table. Just as a non-temporal + reference requires a referenced key to exist, so a temporal reference + requires a referenced key to exist, but during whatever history the + reference exists (at least). So if the products table is + referenced by a variants table, and a variant of + product 5 has an application-time of + [2020-01-01,2026-01-01), then product 5 must exist + throughout that period. + + + + We can create the variants table with the following + schema (without a foreign key yet to enforce referential integrity): + + +CREATE TABLE variants ( + id integer NOT NULL, + product_id integer NOT NULL, + name text NOT NULL, + valid_at daterange NOT NULL, + CONSTRAINT variants_pkey + PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), +); + + + We have included a temporal primary key as a best practice, but it is not + strictly required by foreign keys. + + + + plots product 5 (in + green) and two variants referencing it (in yellow) on the same + timeline. Variant 8 (Medium) was introduced first, then variant 9 (XXL). + Both satisfy the foreign key constraint, because the referenced product + exists throughout their entire history. + + +
+ Temporal Foreign Key Example + + + + + +
+ + + + In a table, these records would be: + + id | product_id | name | valid_at +----+------------+--------+------------------------- + 8 | 5 | Medium | [2021-01-01,2023-06-01) + 9 | 5 | XXL | [2022-03-01,2024-06-01) + + + + + Note that a temporal reference need not be fulfilled by a single + row in the referenced table. Product 5 had a price change in the middle + of variant 8's history, but the reference is still valid. The + combination of all matching rows is used to test whether the referenced + history contains the referencing row. + + + + The syntax to add a temporal foreign key to our table is: + + +ALTER TABLE variants + ADD CONSTRAINT variants_id_valid_at_fkey + FOREIGN KEY (product_id, PERIOD valid_at) + REFERENCES products (id, PERIOD valid_at); + + + Note that the keyword PERIOD must be used for the + application-time column in both the referencing and referenced table. + + + + A temporal primary key or unique constraint matching the referenced columns + must exist on the referenced table. + + + + PostgreSQL supports NO ACTION + temporal foreign keys, but not RESTRICT, + CASCADE, SET NULL, or + SET DEFAULT. + +
@@ -1781,6 +1878,7 @@ ALTER TABLE products Temporal wiki page for possibilities. +
diff --git a/doc/src/sgml/images/Makefile b/doc/src/sgml/images/Makefile index 1d99d4e30c8c..fd55b9ad23f4 100644 --- a/doc/src/sgml/images/Makefile +++ b/doc/src/sgml/images/Makefile @@ -6,7 +6,8 @@ ALL_IMAGES = \ genetic-algorithm.svg \ gin.svg \ pagelayout.svg \ - temporal-entities.svg + temporal-entities.svg \ + temporal-references.svg DITAA = ditaa DOT = dot diff --git a/doc/src/sgml/images/temporal-references.svg b/doc/src/sgml/images/temporal-references.svg new file mode 100644 index 000000000000..15f40413a64a --- /dev/null +++ b/doc/src/sgml/images/temporal-references.svg @@ -0,0 +1,37 @@ + + + + + + + + + + + + + + + + + + + + + + products + (5, 5.00, [1 Jan 2020,1 Jan 2022)) + 2021 + variants + (8, 5, 'Medium', [1 Jan 2021,1 Jun 2023)) + 2020 + variants + (9, 5, 'XXL', [1 Mar 2022,1 Jun 2024)) + products + (5, 8.00, [1 Jan 2022,)) + 2023 + 2022 + 2024 + ... + + diff --git a/doc/src/sgml/images/temporal-references.txt b/doc/src/sgml/images/temporal-references.txt new file mode 100644 index 000000000000..f49040e88466 --- /dev/null +++ b/doc/src/sgml/images/temporal-references.txt @@ -0,0 +1,21 @@ + + ++------------------------------------+------------------------------------------------------+ +| cGRE | cGRE | +| products | products | +| (5, 5.00, [1 Jan 2020,1 Jan 2022)) | (5, 8.00, [1 Jan 2022,)) | +| | | ++------------------+-----------------+----------------------------+-------------------------+ + | cYEL | + | variants | + | (8, 5, 'Medium', [1 Jan 2021,1 Jun 2023)) | + | | + +-----------------------+----------------------+------------------+ + | cYEL | + | variants | + | (9, 5, 'XXL', [1 Mar 2022,1 Jun 2024)) | + | | + +-----------------------------------------+ + +| | | | | | +2020 2021 2022 2023 2024 ... From 2217b2d365985b2b90475f97c58ecbee4b3d3854 Mon Sep 17 00:00:00 2001 From: "Paul A. Jungwirth" Date: Tue, 17 Jun 2025 21:38:40 -0700 Subject: [PATCH 03/11] Document temporal update/delete The FOR PORTION OF syntax will also be documented in the reference pages for UPDATE and DELETE, but this commit adds a new section to the DML chapter, called "Updating and Deleting Temporal Data," giving a conceptual description, as well as a glossary term for "temporal leftovers". The SQL standard doesn't give any term for the supplementary INSERTs after an UPDATE/DELETE FOR PORTION OF, but it is really handy to have a name for them. Author: Paul A. Jungwirth --- doc/src/sgml/dml.sgml | 140 ++++++++++++++++++++++++ doc/src/sgml/glossary.sgml | 15 +++ doc/src/sgml/images/Makefile | 4 +- doc/src/sgml/images/temporal-delete.svg | 41 +++++++ doc/src/sgml/images/temporal-delete.txt | 12 ++ doc/src/sgml/images/temporal-update.svg | 45 ++++++++ doc/src/sgml/images/temporal-update.txt | 12 ++ 7 files changed, 268 insertions(+), 1 deletion(-) create mode 100644 doc/src/sgml/images/temporal-delete.svg create mode 100644 doc/src/sgml/images/temporal-delete.txt create mode 100644 doc/src/sgml/images/temporal-update.svg create mode 100644 doc/src/sgml/images/temporal-update.txt diff --git a/doc/src/sgml/dml.sgml b/doc/src/sgml/dml.sgml index 458aee788b7f..a899c9ab447a 100644 --- a/doc/src/sgml/dml.sgml +++ b/doc/src/sgml/dml.sgml @@ -261,6 +261,146 @@ DELETE FROM products; + + Updating and Deleting Temporal Data + + + Special syntax is available to update and delete from application-time temporal tables. (No + extra syntax is required to insert into them: the user just + provides the application time like any other attribute.) When updating + or deleting, the user can target a specific portion of history. Only + rows overlapping that history are affected, and within those rows only + the targeted history is changed. If a row contains more history beyond + what is targeted, its application time is reduced to fit within the + targeted interval, and new rows are inserted to preserve the history + that was not targeted. + + + + Recall the example table from , + containing this data: + + + id | price | valid_at +----+-------+------------------------- + 5 | 5 | [2020-01-01,2022-01-01) + 5 | 8 | [2022-01-01,) + 6 | 9 | [2021-01-01,2024-01-01) + + + A temporal update might look like this: + + +UPDATE products + FOR PORTION OF valid_at FROM '2023-09-01' TO '2025-03-01' + AS p + SET price = 12 + WHERE id = 5; + + + That command will update the second record for product 5. It will set the + price to 12 and + the application time to [2023-09-01,2025-03-01). + Then, since the row's application time was originally + [2022-01-01,), the command must insert two + temporal + leftovers: one for history before September 1, 2023, and + another for history since March 1, 2025. After the update, the table + has four rows for product 5: + + + id | price | valid_at +----+-------+------------------------- + 5 | 5 | [2020-01-01,2022-01-01) + 5 | 8 | [2022-01-01,2023-09-01) + 5 | 12 | [2023-09-01,2025-03-01) + 5 | 8 | [2025-03-01,) + + + The new history could be plotted as in . + + +
+ Temporal Update Example + + + + + +
+ + + Similarly, a specific portion of history may be targeted when + deleting rows from a table. In that case, the original rows are + removed, but new + temporal leftovers + are inserted to preserve the untouched history. The syntax for a + temporal delete is: + + +DELETE FROM products + FOR PORTION OF valid_at FROM '2021-08-01' TO '2023-09-01' + AS p +WHERE id = 5; + + + Continuing the example, this command would delete two records. The + first record would yield a single temporal leftover, and the second + would be deleted entirely. The rows for product 5 would now be: + + + id | price | valid_at +----+-------+------------------------- + 5 | 5 | [2020-01-01,2021-08-01) + 5 | 12 | [2023-09-01,2025-03-01) + 5 | 8 | [2025-03-01,) + + + The new history could be plotted as in . + + +
+ Temporal Delete Example + + + + + +
+ + + Instead of using the FROM ... TO ... syntax, + temporal update/delete commands can also give the targeted + range/multirange directly, inside parentheses. For example: + DELETE FROM products FOR PORTION OF valid_at ('[2028-01-01,)') .... + This syntax is required when application time is stored + in a multirange column. + + + + When application time is stored in a rangetype column, zero, one or + two temporal leftovers are produced by each row that is + updated/deleted. With a multirange column, only zero or one temporal + leftover is produced. The leftover bounds are computed using + range_minus_multi and + multirange_minus_multi + (see ). + + + + The bounds given to FOR PORTION OF must be + constant. Functions like NOW() are allowed, but + column references are not. + + + + When temporal leftovers are inserted, all INSERT + triggers are fired, but permission checks for inserting rows are + skipped. + +
+ Returning Data from Modified Rows diff --git a/doc/src/sgml/glossary.sgml b/doc/src/sgml/glossary.sgml index a76cf5c383fc..1f74dca58974 100644 --- a/doc/src/sgml/glossary.sgml +++ b/doc/src/sgml/glossary.sgml @@ -1916,6 +1916,21 @@ + + Temporal leftovers + + + After a temporal update or delete, the portion of history that was not + updated/deleted. When using ranges to track application time, there may be + zero, one, or two stretches of history that where not updated/deleted + (before and/or after the portion that was updated/deleted). New rows are + automatically inserted into the table to preserve that history. A single + multirange can accommodate the untouched history before and after the + update/delete, so there will be only zero or one leftover. + + + + Temporal table diff --git a/doc/src/sgml/images/Makefile b/doc/src/sgml/images/Makefile index fd55b9ad23f4..38f8869d78dd 100644 --- a/doc/src/sgml/images/Makefile +++ b/doc/src/sgml/images/Makefile @@ -7,7 +7,9 @@ ALL_IMAGES = \ gin.svg \ pagelayout.svg \ temporal-entities.svg \ - temporal-references.svg + temporal-references.svg \ + temporal-update.svg \ + temporal-delete.svg DITAA = ditaa DOT = dot diff --git a/doc/src/sgml/images/temporal-delete.svg b/doc/src/sgml/images/temporal-delete.svg new file mode 100644 index 000000000000..2d8b1d6ec7b0 --- /dev/null +++ b/doc/src/sgml/images/temporal-delete.svg @@ -0,0 +1,41 @@ + + + + + + + + + + + + + + + + + + + + + + + products + (5, 5.00, + [1 Jan 2020,1 Aug 2021)) + 2020 + 2021 + 2022 + 2023 + products + (5, 12.00, + [1 Sep 2023,1 Mar 2025)) + 2024 + 2025 + products + (5, 8.00, + [1 Mar 2025,)) + 2026 + ... + + diff --git a/doc/src/sgml/images/temporal-delete.txt b/doc/src/sgml/images/temporal-delete.txt new file mode 100644 index 000000000000..611df5215692 --- /dev/null +++ b/doc/src/sgml/images/temporal-delete.txt @@ -0,0 +1,12 @@ + + ++----------------------------+ +-------------------------------+--------------------------+ +| cGRE | | cGRE | cGRE | +| products | | products | products | +| (5, 5.00, | | (5, 12.00, | (5, 8.00, | +| [1 Jan 2020,1 Aug 2021)) | | [1 Sep 2023,1 Mar 2025)) | [1 Mar 2025,)) | +| | | | | ++----------------------------+ +-------------------------------+--------------------------+ + +| | | | | | | | +2020 2021 2022 2023 2024 2025 2026 ... diff --git a/doc/src/sgml/images/temporal-update.svg b/doc/src/sgml/images/temporal-update.svg new file mode 100644 index 000000000000..6c7c43c8d226 --- /dev/null +++ b/doc/src/sgml/images/temporal-update.svg @@ -0,0 +1,45 @@ + + + + + + + + + + + + + + + + + + + + + + + + products + (5, 5.00, + [1 Jan 2020,1 Jan 2022)) + 2020 + 2021 + products + (5, 8.00, + [1 Jan 2022,1 Sep 2023)) + 2022 + 2023 + products + (5, 12.00, + [1 Sep 2023,1 Mar 2025)) + 2024 + 2025 + products + (5, 8.00, + [1 Mar 2025,)) + 2026 + ... + + diff --git a/doc/src/sgml/images/temporal-update.txt b/doc/src/sgml/images/temporal-update.txt new file mode 100644 index 000000000000..7e862d894376 --- /dev/null +++ b/doc/src/sgml/images/temporal-update.txt @@ -0,0 +1,12 @@ + + ++-----------------------------------+-----------------------------+----------------------------+------------------------------+ +| cGRE | cGRE | cGRE | cGRE | +| products | products | products | products | +| (5, 5.00, | (5, 8.00, | (5, 12.00, | (5, 8.00, | +| [1 Jan 2020,1 Jan 2022)) | [1 Jan 2022,1 Sep 2023)) | [1 Sep 2023,1 Mar 2025)) | [1 Mar 2025,)) | +| | | | | ++-----------------------------------+-----------------------------+----------------------------+------------------------------+ + +| | | | | | | | +2020 2021 2022 2023 2024 2025 2026 ... From 4397d927842b672cdd1dd8a27bb8a852d6b26ab5 Mon Sep 17 00:00:00 2001 From: "Paul A. Jungwirth" Date: Sat, 30 Dec 2023 23:10:59 -0800 Subject: [PATCH 04/11] Add range_minus_multi and multirange_minus_multi functions The existing range_minus function raises an exception when the range is "split", because then the result can't be represented by a single range. For example '[0,10)'::int4range - '[4,5)' would be '[0,4)' and '[5,10)'. This commit adds new set-returning functions so that callers can get results even in the case of splits. There is no risk of an exception for multiranges, but a set-returning function lets us handle them the same way we handle ranges. Both functions return zero results if the subtraction would give an empty range/multirange. The main use-case for these functions is to implement UPDATE/DELETE FOR PORTION OF, which must compute the application-time of "temporal leftovers": the part of history in an updated/deleted row that was not changed. To preserve the untouched history, we will implicitly insert one record for each result returned by range/multirange_minus_multi. Using a set-returning function will also let us support user-defined types for application-time update/delete in the future. Author: Paul A. Jungwirth --- doc/src/sgml/func/func-range.sgml | 42 +++++ src/backend/utils/adt/multirangetypes.c | 71 ++++++++ src/backend/utils/adt/rangetypes.c | 166 ++++++++++++++++++ src/include/catalog/pg_proc.dat | 8 + src/include/utils/rangetypes.h | 2 + src/test/regress/expected/multirangetypes.out | 116 ++++++++++++ src/test/regress/expected/rangetypes.out | 54 ++++++ src/test/regress/sql/multirangetypes.sql | 22 +++ src/test/regress/sql/rangetypes.sql | 10 ++ 9 files changed, 491 insertions(+) diff --git a/doc/src/sgml/func/func-range.sgml b/doc/src/sgml/func/func-range.sgml index 2dc40348a57f..a4187d8406c5 100644 --- a/doc/src/sgml/func/func-range.sgml +++ b/doc/src/sgml/func/func-range.sgml @@ -842,6 +842,29 @@ [1,4) + + + + + range_minus_multi + + range_minus_multi ( anyrange, anyrange ) + setof anyrange + + + Returns the non-empty range(s) remaining after subtracting the second range from the first. + One row is returned for each range, so if the second range splits the first into two parts, + there will be two results. If the subtraction yields an empty range, no rows are returned. + + + range_minus_multi('[0,10)'::int4range, '[3,4)'::int4range) + + + [0,3) + [4,10) + + + @@ -1041,6 +1064,25 @@ + + + + + multirange_minus_multi + + multirange_minus_multi ( anymultirange, anymultirange ) + setof anymultirange + + + Returns the non-empty multirange(s) remaining after subtracting the second multirange from the first. + If the subtraction yields an empty multirange, no rows are returned. + Two rows are never returned, because a single multirange can always accommodate any result. + + + range_minus_multi('[0,10)'::int4range, '[3,4)'::int4range) + {[0,3), [4,10)} + + diff --git a/src/backend/utils/adt/multirangetypes.c b/src/backend/utils/adt/multirangetypes.c index 84733dc50195..e3e10318f27b 100644 --- a/src/backend/utils/adt/multirangetypes.c +++ b/src/backend/utils/adt/multirangetypes.c @@ -1226,6 +1226,77 @@ multirange_minus_internal(Oid mltrngtypoid, TypeCacheEntry *rangetyp, return make_multirange(mltrngtypoid, rangetyp, range_count3, ranges3); } +/* + * multirange_minus_multi - like multirange_minus but returning the result as a SRF, + * with no rows if the result would be empty. + */ +Datum +multirange_minus_multi(PG_FUNCTION_ARGS) +{ + FuncCallContext *funcctx; + MemoryContext oldcontext; + + if (!SRF_IS_FIRSTCALL()) + { + /* We never have more than one result */ + funcctx = SRF_PERCALL_SETUP(); + SRF_RETURN_DONE(funcctx); + } + else + { + MultirangeType *mr1; + MultirangeType *mr2; + Oid mltrngtypoid; + TypeCacheEntry *typcache; + TypeCacheEntry *rangetyp; + int32 range_count1; + int32 range_count2; + RangeType **ranges1; + RangeType **ranges2; + MultirangeType *mr; + + funcctx = SRF_FIRSTCALL_INIT(); + + /* + * switch to memory context appropriate for multiple function calls + */ + oldcontext = MemoryContextSwitchTo(funcctx->multi_call_memory_ctx); + + /* get args, detoasting into multi-call memory context */ + mr1 = PG_GETARG_MULTIRANGE_P(0); + mr2 = PG_GETARG_MULTIRANGE_P(1); + + mltrngtypoid = MultirangeTypeGetOid(mr1); + typcache = lookup_type_cache(mltrngtypoid, TYPECACHE_MULTIRANGE_INFO); + if (typcache->rngtype == NULL) + elog(ERROR, "type %u is not a multirange type", mltrngtypoid); + rangetyp = typcache->rngtype; + + if (MultirangeIsEmpty(mr1) || MultirangeIsEmpty(mr2)) + mr = mr1; + else + { + multirange_deserialize(rangetyp, mr1, &range_count1, &ranges1); + multirange_deserialize(rangetyp, mr2, &range_count2, &ranges2); + + mr = multirange_minus_internal(mltrngtypoid, + rangetyp, + range_count1, + ranges1, + range_count2, + ranges2); + } + + MemoryContextSwitchTo(oldcontext); + + funcctx = SRF_PERCALL_SETUP(); + if (MultirangeIsEmpty(mr)) + SRF_RETURN_DONE(funcctx); + else + SRF_RETURN_NEXT(funcctx, MultirangeTypePGetDatum(mr)); + } +} + /* multirange intersection */ Datum multirange_intersect(PG_FUNCTION_ARGS) diff --git a/src/backend/utils/adt/rangetypes.c b/src/backend/utils/adt/rangetypes.c index 0b2ad8b09758..6c88fa8c9b99 100644 --- a/src/backend/utils/adt/rangetypes.c +++ b/src/backend/utils/adt/rangetypes.c @@ -31,6 +31,7 @@ #include "postgres.h" #include "common/hashfn.h" +#include "funcapi.h" #include "libpq/pqformat.h" #include "miscadmin.h" #include "nodes/makefuncs.h" @@ -39,6 +40,7 @@ #include "optimizer/clauses.h" #include "optimizer/cost.h" #include "optimizer/optimizer.h" +#include "utils/array.h" #include "utils/builtins.h" #include "utils/date.h" #include "utils/lsyscache.h" @@ -1214,6 +1216,170 @@ range_split_internal(TypeCacheEntry *typcache, const RangeType *r1, const RangeT return false; } +/* + * range_minus_multi - like range_minus but as a SRF to accommodate splits, + * with no result rows if the result would be empty. + */ +Datum +range_minus_multi(PG_FUNCTION_ARGS) +{ + typedef struct + { + RangeType *rs[2]; + int n; + } range_minus_multi_fctx; + + FuncCallContext *funcctx; + range_minus_multi_fctx *fctx; + MemoryContext oldcontext; + + /* stuff done only on the first call of the function */ + if (SRF_IS_FIRSTCALL()) + { + RangeType *r1; + RangeType *r2; + Oid rngtypid; + TypeCacheEntry *typcache; + + /* create a function context for cross-call persistence */ + funcctx = SRF_FIRSTCALL_INIT(); + + /* + * switch to memory context appropriate for multiple function calls + */ + oldcontext = MemoryContextSwitchTo(funcctx->multi_call_memory_ctx); + + r1 = PG_GETARG_RANGE_P(0); + r2 = PG_GETARG_RANGE_P(1); + + /* Different types should be prevented by ANYRANGE matching rules */ + if (RangeTypeGetOid(r1) != RangeTypeGetOid(r2)) + elog(ERROR, "range types do not match"); + + /* allocate memory for user context */ + fctx = (range_minus_multi_fctx *) palloc(sizeof(range_minus_multi_fctx)); + + /* + * Initialize state. We can't store the range typcache in fn_extra + * because the caller uses that for the SRF state. + */ + rngtypid = RangeTypeGetOid(r1); + typcache = lookup_type_cache(rngtypid, TYPECACHE_RANGE_INFO); + if (typcache->rngelemtype == NULL) + elog(ERROR, "type %u is not a range type", rngtypid); + range_minus_multi_internal(typcache, r1, r2, fctx->rs, &fctx->n); + + funcctx->user_fctx = fctx; + MemoryContextSwitchTo(oldcontext); + } + + /* stuff done on every call of the function */ + funcctx = SRF_PERCALL_SETUP(); + fctx = funcctx->user_fctx; + + if (funcctx->call_cntr < fctx->n) + { + /* + * We must keep these on separate lines because SRF_RETURN_NEXT does + * call_cntr++: + */ + RangeType *ret = fctx->rs[funcctx->call_cntr]; + + SRF_RETURN_NEXT(funcctx, RangeTypePGetDatum(ret)); + } + else + /* do when there is no more left */ + SRF_RETURN_DONE(funcctx); +} + +/* + * range_minus_multi_internal - Sets outputs and outputn to the ranges + * remaining and their count (respectively) after subtracting r2 from r1. + * The array should never contain empty ranges. + * The outputs will be ordered. We expect that outputs is an array of + * RangeType pointers, already allocated with two elements. + */ +void +range_minus_multi_internal(TypeCacheEntry *typcache, RangeType *r1, + RangeType *r2, RangeType **outputs, int *outputn) +{ + int cmp_l1l2, + cmp_l1u2, + cmp_u1l2, + cmp_u1u2; + RangeBound lower1, + lower2; + RangeBound upper1, + upper2; + bool empty1, + empty2; + + range_deserialize(typcache, r1, &lower1, &upper1, &empty1); + range_deserialize(typcache, r2, &lower2, &upper2, &empty2); + + if (empty1) + { + /* if r1 is empty then r1 - r2 is empty, so return zero results */ + *outputn = 0; + return; + } + else if (empty2) + { + /* r2 is empty so the result is just r1 (which we know is not empty) */ + outputs[0] = r1; + *outputn = 1; + return; + } + + /* + * Use the same logic as range_minus_internal, but support the split case + */ + cmp_l1l2 = range_cmp_bounds(typcache, &lower1, &lower2); + cmp_l1u2 = range_cmp_bounds(typcache, &lower1, &upper2); + cmp_u1l2 = range_cmp_bounds(typcache, &upper1, &lower2); + cmp_u1u2 = range_cmp_bounds(typcache, &upper1, &upper2); + + if (cmp_l1l2 < 0 && cmp_u1u2 > 0) + { + lower2.inclusive = !lower2.inclusive; + lower2.lower = false; /* it will become the upper bound */ + outputs[0] = make_range(typcache, &lower1, &lower2, false, NULL); + + upper2.inclusive = !upper2.inclusive; + upper2.lower = true; /* it will become the lower bound */ + outputs[1] = make_range(typcache, &upper2, &upper1, false, NULL); + + *outputn = 2; + } + else if (cmp_l1u2 > 0 || cmp_u1l2 < 0) + { + outputs[0] = r1; + *outputn = 1; + } + else if (cmp_l1l2 >= 0 && cmp_u1u2 <= 0) + { + *outputn = 0; + } + else if (cmp_l1l2 <= 0 && cmp_u1l2 >= 0 && cmp_u1u2 <= 0) + { + lower2.inclusive = !lower2.inclusive; + lower2.lower = false; /* it will become the upper bound */ + outputs[0] = make_range(typcache, &lower1, &lower2, false, NULL); + *outputn = 1; + } + else if (cmp_l1l2 >= 0 && cmp_u1u2 >= 0 && cmp_l1u2 <= 0) + { + upper2.inclusive = !upper2.inclusive; + upper2.lower = true; /* it will become the lower bound */ + outputs[0] = make_range(typcache, &upper2, &upper1, false, NULL); + *outputn = 1; + } + else + { + elog(ERROR, "unexpected case in range_minus_multi"); + } +} + /* range -> range aggregate functions */ Datum diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat index 34b7fddb0e7a..4aca47919ed4 100644 --- a/src/include/catalog/pg_proc.dat +++ b/src/include/catalog/pg_proc.dat @@ -10939,6 +10939,10 @@ { oid => '3869', proname => 'range_minus', prorettype => 'anyrange', proargtypes => 'anyrange anyrange', prosrc => 'range_minus' }, +{ oid => '8412', descr => 'remove portion from range', + proname => 'range_minus_multi', prorows => '2', + proretset => 't', prorettype => 'anyrange', + proargtypes => 'anyrange anyrange', prosrc => 'range_minus_multi' }, { oid => '3870', descr => 'less-equal-greater', proname => 'range_cmp', prorettype => 'int4', proargtypes => 'anyrange anyrange', prosrc => 'range_cmp' }, @@ -11229,6 +11233,10 @@ { oid => '4271', proname => 'multirange_minus', prorettype => 'anymultirange', proargtypes => 'anymultirange anymultirange', prosrc => 'multirange_minus' }, +{ oid => '8411', descr => 'remove portion from multirange', + proname => 'multirange_minus_multi', prorows => '1', + proretset => 't', prorettype => 'anymultirange', + proargtypes => 'anymultirange anymultirange', prosrc => 'multirange_minus_multi' }, { oid => '4272', proname => 'multirange_intersect', prorettype => 'anymultirange', proargtypes => 'anymultirange anymultirange', diff --git a/src/include/utils/rangetypes.h b/src/include/utils/rangetypes.h index 50adb3c8c139..836f2b0914b4 100644 --- a/src/include/utils/rangetypes.h +++ b/src/include/utils/rangetypes.h @@ -164,5 +164,7 @@ extern RangeType *make_empty_range(TypeCacheEntry *typcache); extern bool range_split_internal(TypeCacheEntry *typcache, const RangeType *r1, const RangeType *r2, RangeType **output1, RangeType **output2); +extern void range_minus_multi_internal(TypeCacheEntry *typcache, RangeType *r1, + RangeType *r2, RangeType **outputs, int *outputn); #endif /* RANGETYPES_H */ diff --git a/src/test/regress/expected/multirangetypes.out b/src/test/regress/expected/multirangetypes.out index 63de4d09b153..f5e7df8df430 100644 --- a/src/test/regress/expected/multirangetypes.out +++ b/src/test/regress/expected/multirangetypes.out @@ -2200,6 +2200,122 @@ SELECT nummultirange(numrange(1,2), numrange(4,5)) - nummultirange(numrange(-2,0 {[1,2),[4,5)} (1 row) +-- multirange_minus_multi +SELECT multirange_minus_multi(nummultirange(), nummultirange()); + multirange_minus_multi +------------------------ +(0 rows) + +SELECT multirange_minus_multi(nummultirange(), nummultirange(numrange(1,2))); + multirange_minus_multi +------------------------ +(0 rows) + +SELECT multirange_minus_multi(nummultirange(numrange(1,2)), nummultirange()); + multirange_minus_multi +------------------------ + {[1,2)} +(1 row) + +SELECT multirange_minus_multi(nummultirange(numrange(1,2), numrange(3,4)), nummultirange()); + multirange_minus_multi +------------------------ + {[1,2),[3,4)} +(1 row) + +SELECT multirange_minus_multi(nummultirange(numrange(1,2)), nummultirange(numrange(1,2))); + multirange_minus_multi +------------------------ +(0 rows) + +SELECT multirange_minus_multi(nummultirange(numrange(1,2)), nummultirange(numrange(2,4))); + multirange_minus_multi +------------------------ + {[1,2)} +(1 row) + +SELECT multirange_minus_multi(nummultirange(numrange(1,2)), nummultirange(numrange(3,4))); + multirange_minus_multi +------------------------ + {[1,2)} +(1 row) + +SELECT multirange_minus_multi(nummultirange(numrange(1,4)), nummultirange(numrange(1,2))); + multirange_minus_multi +------------------------ + {[2,4)} +(1 row) + +SELECT multirange_minus_multi(nummultirange(numrange(1,4)), nummultirange(numrange(2,3))); + multirange_minus_multi +------------------------ + {[1,2),[3,4)} +(1 row) + +SELECT multirange_minus_multi(nummultirange(numrange(1,4)), nummultirange(numrange(0,8))); + multirange_minus_multi +------------------------ +(0 rows) + +SELECT multirange_minus_multi(nummultirange(numrange(1,4)), nummultirange(numrange(0,2))); + multirange_minus_multi +------------------------ + {[2,4)} +(1 row) + +SELECT multirange_minus_multi(nummultirange(numrange(1,8)), nummultirange(numrange(0,2), numrange(3,4))); + multirange_minus_multi +------------------------ + {[2,3),[4,8)} +(1 row) + +SELECT multirange_minus_multi(nummultirange(numrange(1,8)), nummultirange(numrange(2,3), numrange(5,null))); + multirange_minus_multi +------------------------ + {[1,2),[3,5)} +(1 row) + +SELECT multirange_minus_multi(nummultirange(numrange(1,2), numrange(4,5)), nummultirange(numrange(-2,0))); + multirange_minus_multi +------------------------ + {[1,2),[4,5)} +(1 row) + +SELECT multirange_minus_multi(nummultirange(numrange(1,2), numrange(4,5)), nummultirange(numrange(2,4))); + multirange_minus_multi +------------------------ + {[1,2),[4,5)} +(1 row) + +SELECT multirange_minus_multi(nummultirange(numrange(1,2), numrange(4,5)), nummultirange(numrange(3,5))); + multirange_minus_multi +------------------------ + {[1,2)} +(1 row) + +SELECT multirange_minus_multi(nummultirange(numrange(1,2), numrange(4,5)), nummultirange(numrange(0,9))); + multirange_minus_multi +------------------------ +(0 rows) + +SELECT multirange_minus_multi(nummultirange(numrange(1,3), numrange(4,5)), nummultirange(numrange(2,9))); + multirange_minus_multi +------------------------ + {[1,2)} +(1 row) + +SELECT multirange_minus_multi(nummultirange(numrange(1,2), numrange(4,5)), nummultirange(numrange(8,9))); + multirange_minus_multi +------------------------ + {[1,2),[4,5)} +(1 row) + +SELECT multirange_minus_multi(nummultirange(numrange(1,2), numrange(4,5)), nummultirange(numrange(-2,0), numrange(8,9))); + multirange_minus_multi +------------------------ + {[1,2),[4,5)} +(1 row) + -- intersection SELECT nummultirange() * nummultirange(); ?column? diff --git a/src/test/regress/expected/rangetypes.out b/src/test/regress/expected/rangetypes.out index cdd95799cd5c..e062a4e5c2c8 100644 --- a/src/test/regress/expected/rangetypes.out +++ b/src/test/regress/expected/rangetypes.out @@ -481,6 +481,60 @@ select range_minus(numrange(10.1,12.2,'[]'), numrange(0.0,120.2,'(]')); empty (1 row) +select range_minus_multi('empty'::numrange, numrange(2.0, 3.0)); + range_minus_multi +------------------- +(0 rows) + +select range_minus_multi(numrange(1.1, 2.2), 'empty'::numrange); + range_minus_multi +------------------- + [1.1,2.2) +(1 row) + +select range_minus_multi(numrange(1.1, 2.2), numrange(2.0, 3.0)); + range_minus_multi +------------------- + [1.1,2.0) +(1 row) + +select range_minus_multi(numrange(1.1, 2.2), numrange(2.2, 3.0)); + range_minus_multi +------------------- + [1.1,2.2) +(1 row) + +select range_minus_multi(numrange(1.1, 2.2,'[]'), numrange(2.0, 3.0)); + range_minus_multi +------------------- + [1.1,2.0) +(1 row) + +select range_minus_multi(numrange(1.0, 3.0), numrange(1.5, 2.0)); + range_minus_multi +------------------- + [1.0,1.5) + [2.0,3.0) +(2 rows) + +select range_minus_multi(numrange(10.1,12.2,'[]'), numrange(110.0,120.2,'(]')); + range_minus_multi +------------------- + [10.1,12.2] +(1 row) + +select range_minus_multi(numrange(10.1,12.2,'[]'), numrange(0.0,120.2,'(]')); + range_minus_multi +------------------- +(0 rows) + +select range_minus_multi(numrange(1.0,3.0,'[]'), numrange(1.5,2.0,'(]')); + range_minus_multi +------------------- + [1.0,1.5] + (2.0,3.0] +(2 rows) + select numrange(4.5, 5.5, '[]') && numrange(5.5, 6.5); ?column? ---------- diff --git a/src/test/regress/sql/multirangetypes.sql b/src/test/regress/sql/multirangetypes.sql index 41d5524285a3..112334b03ebb 100644 --- a/src/test/regress/sql/multirangetypes.sql +++ b/src/test/regress/sql/multirangetypes.sql @@ -414,6 +414,28 @@ SELECT nummultirange(numrange(1,3), numrange(4,5)) - nummultirange(numrange(2,9) SELECT nummultirange(numrange(1,2), numrange(4,5)) - nummultirange(numrange(8,9)); SELECT nummultirange(numrange(1,2), numrange(4,5)) - nummultirange(numrange(-2,0), numrange(8,9)); +-- multirange_minus_multi +SELECT multirange_minus_multi(nummultirange(), nummultirange()); +SELECT multirange_minus_multi(nummultirange(), nummultirange(numrange(1,2))); +SELECT multirange_minus_multi(nummultirange(numrange(1,2)), nummultirange()); +SELECT multirange_minus_multi(nummultirange(numrange(1,2), numrange(3,4)), nummultirange()); +SELECT multirange_minus_multi(nummultirange(numrange(1,2)), nummultirange(numrange(1,2))); +SELECT multirange_minus_multi(nummultirange(numrange(1,2)), nummultirange(numrange(2,4))); +SELECT multirange_minus_multi(nummultirange(numrange(1,2)), nummultirange(numrange(3,4))); +SELECT multirange_minus_multi(nummultirange(numrange(1,4)), nummultirange(numrange(1,2))); +SELECT multirange_minus_multi(nummultirange(numrange(1,4)), nummultirange(numrange(2,3))); +SELECT multirange_minus_multi(nummultirange(numrange(1,4)), nummultirange(numrange(0,8))); +SELECT multirange_minus_multi(nummultirange(numrange(1,4)), nummultirange(numrange(0,2))); +SELECT multirange_minus_multi(nummultirange(numrange(1,8)), nummultirange(numrange(0,2), numrange(3,4))); +SELECT multirange_minus_multi(nummultirange(numrange(1,8)), nummultirange(numrange(2,3), numrange(5,null))); +SELECT multirange_minus_multi(nummultirange(numrange(1,2), numrange(4,5)), nummultirange(numrange(-2,0))); +SELECT multirange_minus_multi(nummultirange(numrange(1,2), numrange(4,5)), nummultirange(numrange(2,4))); +SELECT multirange_minus_multi(nummultirange(numrange(1,2), numrange(4,5)), nummultirange(numrange(3,5))); +SELECT multirange_minus_multi(nummultirange(numrange(1,2), numrange(4,5)), nummultirange(numrange(0,9))); +SELECT multirange_minus_multi(nummultirange(numrange(1,3), numrange(4,5)), nummultirange(numrange(2,9))); +SELECT multirange_minus_multi(nummultirange(numrange(1,2), numrange(4,5)), nummultirange(numrange(8,9))); +SELECT multirange_minus_multi(nummultirange(numrange(1,2), numrange(4,5)), nummultirange(numrange(-2,0), numrange(8,9))); + -- intersection SELECT nummultirange() * nummultirange(); SELECT nummultirange() * nummultirange(numrange(1,2)); diff --git a/src/test/regress/sql/rangetypes.sql b/src/test/regress/sql/rangetypes.sql index a5ecdf5372f5..5c4b0337b7a8 100644 --- a/src/test/regress/sql/rangetypes.sql +++ b/src/test/regress/sql/rangetypes.sql @@ -107,6 +107,16 @@ select numrange(1.1, 2.2,'[]') - numrange(2.0, 3.0); select range_minus(numrange(10.1,12.2,'[]'), numrange(110.0,120.2,'(]')); select range_minus(numrange(10.1,12.2,'[]'), numrange(0.0,120.2,'(]')); +select range_minus_multi('empty'::numrange, numrange(2.0, 3.0)); +select range_minus_multi(numrange(1.1, 2.2), 'empty'::numrange); +select range_minus_multi(numrange(1.1, 2.2), numrange(2.0, 3.0)); +select range_minus_multi(numrange(1.1, 2.2), numrange(2.2, 3.0)); +select range_minus_multi(numrange(1.1, 2.2,'[]'), numrange(2.0, 3.0)); +select range_minus_multi(numrange(1.0, 3.0), numrange(1.5, 2.0)); +select range_minus_multi(numrange(10.1,12.2,'[]'), numrange(110.0,120.2,'(]')); +select range_minus_multi(numrange(10.1,12.2,'[]'), numrange(0.0,120.2,'(]')); +select range_minus_multi(numrange(1.0,3.0,'[]'), numrange(1.5,2.0,'(]')); + select numrange(4.5, 5.5, '[]') && numrange(5.5, 6.5); select numrange(1.0, 2.0) << numrange(3.0, 4.0); select numrange(1.0, 3.0,'[]') << numrange(3.0, 4.0,'[]'); From d415afc1ebc9ec4d8983794c546545ac68c3ae3f Mon Sep 17 00:00:00 2001 From: "Paul A. Jungwirth" Date: Fri, 25 Jun 2021 18:54:35 -0700 Subject: [PATCH 05/11] 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 "temporal leftover" part of a record touched by a FOR PORTION OF query. - Documented FOR PORTION OF. - Added tests. Author: Paul A. Jungwirth --- .../postgres_fdw/expected/postgres_fdw.out | 45 +- contrib/postgres_fdw/sql/postgres_fdw.sql | 34 + doc/src/sgml/ref/create_publication.sgml | 6 + doc/src/sgml/ref/delete.sgml | 96 +- doc/src/sgml/ref/update.sgml | 98 +- doc/src/sgml/trigger.sgml | 9 + src/backend/executor/execMain.c | 1 + src/backend/executor/nodeModifyTable.c | 330 ++++- src/backend/nodes/nodeFuncs.c | 24 + src/backend/optimizer/plan/createplan.c | 6 +- src/backend/optimizer/plan/planner.c | 1 + src/backend/optimizer/util/pathnode.c | 3 +- src/backend/parser/analyze.c | 248 +++- src/backend/parser/gram.y | 100 +- src/backend/parser/parse_agg.c | 10 + src/backend/parser/parse_collate.c | 1 + src/backend/parser/parse_expr.c | 8 + src/backend/parser/parse_func.c | 3 + src/backend/parser/parse_merge.c | 2 +- src/backend/rewrite/rewriteHandler.c | 43 + src/backend/utils/adt/ri_triggers.c | 2 +- src/backend/utils/cache/lsyscache.c | 27 + src/include/nodes/execnodes.h | 22 + src/include/nodes/parsenodes.h | 20 + src/include/nodes/pathnodes.h | 1 + src/include/nodes/plannodes.h | 2 + src/include/nodes/primnodes.h | 27 + src/include/optimizer/pathnode.h | 2 +- src/include/parser/analyze.h | 3 +- src/include/parser/kwlist.h | 1 + src/include/parser/parse_node.h | 1 + src/include/utils/lsyscache.h | 1 + src/test/regress/expected/for_portion_of.out | 1248 +++++++++++++++++ src/test/regress/expected/privileges.out | 18 + src/test/regress/expected/updatable_views.out | 32 + .../regress/expected/without_overlaps.out | 245 +++- src/test/regress/parallel_schedule | 2 +- src/test/regress/sql/for_portion_of.sql | 905 ++++++++++++ src/test/regress/sql/privileges.sql | 18 + src/test/regress/sql/updatable_views.sql | 14 + src/test/regress/sql/without_overlaps.sql | 120 +- src/test/subscription/t/034_temporal.pl | 110 +- src/tools/pgindent/typedefs.list | 4 + 43 files changed, 3804 insertions(+), 89 deletions(-) create mode 100644 src/test/regress/expected/for_portion_of.out create mode 100644 src/test/regress/sql/for_portion_of.sql diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out index cd28126049df..8c0f1e8b7710 100644 --- a/contrib/postgres_fdw/expected/postgres_fdw.out +++ b/contrib/postgres_fdw/expected/postgres_fdw.out @@ -50,11 +50,19 @@ CREATE TABLE "S 1"."T 4" ( c3 text, CONSTRAINT t4_pkey PRIMARY KEY (c1) ); +CREATE TABLE "S 1"."T 5" ( + c1 int4range NOT NULL, + c2 int NOT NULL, + c3 text, + c4 daterange NOT NULL, + CONSTRAINT t5_pkey PRIMARY KEY (c1, c4 WITHOUT OVERLAPS) +); -- Disable autovacuum for these tables to avoid unexpected effects of that ALTER TABLE "S 1"."T 1" SET (autovacuum_enabled = 'false'); ALTER TABLE "S 1"."T 2" SET (autovacuum_enabled = 'false'); ALTER TABLE "S 1"."T 3" SET (autovacuum_enabled = 'false'); ALTER TABLE "S 1"."T 4" SET (autovacuum_enabled = 'false'); +ALTER TABLE "S 1"."T 5" SET (autovacuum_enabled = 'false'); INSERT INTO "S 1"."T 1" SELECT id, id % 10, @@ -81,10 +89,17 @@ INSERT INTO "S 1"."T 4" 'AAA' || to_char(id, 'FM000') FROM generate_series(1, 100) id; DELETE FROM "S 1"."T 4" WHERE c1 % 3 != 0; -- delete for outer join tests +INSERT INTO "S 1"."T 5" + SELECT int4range(id, id + 1), + id + 1, + 'AAA' || to_char(id, 'FM000'), + '[2000-01-01,2020-01-01)' + FROM generate_series(1, 100) id; ANALYZE "S 1"."T 1"; ANALYZE "S 1"."T 2"; ANALYZE "S 1"."T 3"; ANALYZE "S 1"."T 4"; +ANALYZE "S 1"."T 5"; -- =================================================================== -- create foreign tables -- =================================================================== @@ -132,6 +147,12 @@ CREATE FOREIGN TABLE ft7 ( c2 int NOT NULL, c3 text ) SERVER loopback3 OPTIONS (schema_name 'S 1', table_name 'T 4'); +CREATE FOREIGN TABLE ft8 ( + c1 int4range NOT NULL, + c2 int NOT NULL, + c3 text, + c4 daterange NOT NULL +) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 5'); -- =================================================================== -- tests for validator -- =================================================================== @@ -214,7 +235,8 @@ ALTER FOREIGN TABLE ft2 ALTER COLUMN c1 OPTIONS (column_name 'C 1'); public | ft5 | loopback | (schema_name 'S 1', table_name 'T 4') | public | ft6 | loopback2 | (schema_name 'S 1', table_name 'T 4') | public | ft7 | loopback3 | (schema_name 'S 1', table_name 'T 4') | -(6 rows) + public | ft8 | loopback | (schema_name 'S 1', table_name 'T 5') | +(7 rows) -- Test that alteration of server options causes reconnection -- Remote's errors might be non-English, so hide them to ensure stable results @@ -6303,6 +6325,27 @@ DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass; ft2 (1 row) +-- Test UPDATE FOR PORTION OF +UPDATE ft8 FOR PORTION OF c4 FROM '2005-01-01' TO '2006-01-01' +SET c2 = c2 + 1 +WHERE c1 = '[1,2)'; +ERROR: foreign tables don't support FOR PORTION OF +SELECT * FROM ft8 WHERE c1 = '[1,2)' ORDER BY c1, c4; + c1 | c2 | c3 | c4 +-------+----+--------+------------------------- + [1,2) | 2 | AAA001 | [01-01-2000,01-01-2020) +(1 row) + +-- Test DELETE FOR PORTION OF +DELETE FROM ft8 FOR PORTION OF c4 FROM '2005-01-01' TO '2006-01-01' +WHERE c1 = '[2,3)'; +ERROR: foreign tables don't support FOR PORTION OF +SELECT * FROM ft8 WHERE c1 = '[2,3)' ORDER BY c1, c4; + c1 | c2 | c3 | c4 +-------+----+--------+------------------------- + [2,3) | 3 | AAA002 | [01-01-2000,01-01-2020) +(1 row) + -- Test UPDATE/DELETE with RETURNING on a three-table join INSERT INTO ft2 (c1,c2,c3) SELECT id, id - 1200, to_char(id, 'FM00000') FROM generate_series(1201, 1300) id; diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql index 9a8f9e281353..738fc24fb071 100644 --- a/contrib/postgres_fdw/sql/postgres_fdw.sql +++ b/contrib/postgres_fdw/sql/postgres_fdw.sql @@ -54,12 +54,20 @@ CREATE TABLE "S 1"."T 4" ( c3 text, CONSTRAINT t4_pkey PRIMARY KEY (c1) ); +CREATE TABLE "S 1"."T 5" ( + c1 int4range NOT NULL, + c2 int NOT NULL, + c3 text, + c4 daterange NOT NULL, + CONSTRAINT t5_pkey PRIMARY KEY (c1, c4 WITHOUT OVERLAPS) +); -- Disable autovacuum for these tables to avoid unexpected effects of that ALTER TABLE "S 1"."T 1" SET (autovacuum_enabled = 'false'); ALTER TABLE "S 1"."T 2" SET (autovacuum_enabled = 'false'); ALTER TABLE "S 1"."T 3" SET (autovacuum_enabled = 'false'); ALTER TABLE "S 1"."T 4" SET (autovacuum_enabled = 'false'); +ALTER TABLE "S 1"."T 5" SET (autovacuum_enabled = 'false'); INSERT INTO "S 1"."T 1" SELECT id, @@ -87,11 +95,18 @@ INSERT INTO "S 1"."T 4" 'AAA' || to_char(id, 'FM000') FROM generate_series(1, 100) id; DELETE FROM "S 1"."T 4" WHERE c1 % 3 != 0; -- delete for outer join tests +INSERT INTO "S 1"."T 5" + SELECT int4range(id, id + 1), + id + 1, + 'AAA' || to_char(id, 'FM000'), + '[2000-01-01,2020-01-01)' + FROM generate_series(1, 100) id; ANALYZE "S 1"."T 1"; ANALYZE "S 1"."T 2"; ANALYZE "S 1"."T 3"; ANALYZE "S 1"."T 4"; +ANALYZE "S 1"."T 5"; -- =================================================================== -- create foreign tables @@ -146,6 +161,14 @@ CREATE FOREIGN TABLE ft7 ( c3 text ) SERVER loopback3 OPTIONS (schema_name 'S 1', table_name 'T 4'); +CREATE FOREIGN TABLE ft8 ( + c1 int4range NOT NULL, + c2 int NOT NULL, + c3 text, + c4 daterange NOT NULL +) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 5'); + + -- =================================================================== -- tests for validator -- =================================================================== @@ -1538,6 +1561,17 @@ EXPLAIN (verbose, costs off) DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass; +-- Test UPDATE FOR PORTION OF +UPDATE ft8 FOR PORTION OF c4 FROM '2005-01-01' TO '2006-01-01' +SET c2 = c2 + 1 +WHERE c1 = '[1,2)'; +SELECT * FROM ft8 WHERE c1 = '[1,2)' ORDER BY c1, c4; + +-- Test DELETE FOR PORTION OF +DELETE FROM ft8 FOR PORTION OF c4 FROM '2005-01-01' TO '2006-01-01' +WHERE c1 = '[2,3)'; +SELECT * FROM ft8 WHERE c1 = '[2,3)' ORDER BY c1, c4; + -- Test UPDATE/DELETE with RETURNING on a three-table join INSERT INTO ft2 (c1,c2,c3) SELECT id, id - 1200, to_char(id, 'FM00000') FROM generate_series(1201, 1300) id; diff --git a/doc/src/sgml/ref/create_publication.sgml b/doc/src/sgml/ref/create_publication.sgml index 66a70e5c5b55..6ac8f935a78e 100644 --- a/doc/src/sgml/ref/create_publication.sgml +++ b/doc/src/sgml/ref/create_publication.sgml @@ -390,6 +390,12 @@ CREATE PUBLICATION name for each row inserted, updated, or deleted. + + For a FOR PORTION OF command, the publication will publish an + UPDATE or DELETE, followed by one + INSERT for each temporal leftover row inserted. + + ATTACHing a table into a partition tree whose root is published using a publication with publish_via_partition_root diff --git a/doc/src/sgml/ref/delete.sgml b/doc/src/sgml/ref/delete.sgml index 29649f6afd65..f425309fd5da 100644 --- a/doc/src/sgml/ref/delete.sgml +++ b/doc/src/sgml/ref/delete.sgml @@ -22,7 +22,9 @@ PostgreSQL documentation [ WITH [ RECURSIVE ] with_query [, ...] ] -DELETE FROM [ ONLY ] table_name [ * ] [ [ AS ] alias ] +DELETE FROM [ ONLY ] table_name [ * ] + [ FOR PORTION OF range_name for_portion_of_target ] + [ [ AS ] alias ] [ USING from_item [, ...] ] [ WHERE condition | WHERE CURRENT OF cursor_name ] [ RETURNING [ WITH ( { OLD | NEW } AS output_alias [, ...] ) ] @@ -55,6 +57,43 @@ DELETE FROM [ ONLY ] table_name [ * circumstances. + + If the table has a range or multirange column, + you may supply a FOR PORTION OF clause, and your delete will + only affect rows that overlap the given interval. Furthermore, if a row's history + extends outside the FOR PORTION OF bounds, then your delete + will only change the history within those bounds. In effect you are deleting any + moment targeted by FOR PORTION OF and no moments outside. + + + + Specifically, after PostgreSQL deletes the existing row, + it will INSERT + new temporal leftovers: + rows whose range or multirange receive the remaining history outside + the targeted bounds, with un-updated values in their other columns. + There will be zero to two inserted records, + depending on whether the original history extended before the targeted + FROM, after the targeted TO, both, or neither. + Multiranges never require two temporal leftovers, because one value can always contain + whatever history remains. + + + + These secondary inserts fire INSERT triggers. + Both STATEMENT and ROW triggers are fired. + The BEFORE DELETE triggers are fired first, then + BEFORE INSERT, then AFTER INSERT, + then AFTER DELETE. + + + + These secondary inserts do not require INSERT privilege on the table. + This is because conceptually no new information has been added. The inserted rows only preserve + existing data about the untargeted time period. Note this may result in users firing INSERT + triggers who don't have insert privileges, so be careful about SECURITY DEFINER trigger functions! + + The optional RETURNING clause causes DELETE to compute and return value(s) based on each row actually deleted. @@ -117,6 +156,57 @@ DELETE FROM [ ONLY ] table_name [ * + + range_name + + + The range or multirange column to use when performing a temporal delete. + + + + + + for_portion_of_target + + + The interval to delete. If you are targeting a range column, + you may give this in the form FROM + start_time TO + end_time. + Otherwise you must use + (expression) + where the expression yields a value of the same type as + range_name. + + + + + + start_time + + + The earliest time (inclusive) to change in a temporal delete. + This must be a value matching the base type of the range from + range_name. A + NULL here indicates a delete whose beginning is + unbounded (as with range types). + + + + + + end_time + + + The latest time (exclusive) to change in a temporal delete. + This must be a value matching the base type of the range from + range_name. A + NULL here indicates a delete whose end is unbounded + (as with range types). + + + + from_item @@ -238,6 +328,10 @@ DELETE count suppressed by a BEFORE DELETE trigger. If count is 0, no rows were deleted by the query (this is not considered an error). + If FOR PORTION OF was used, the + count also includes + temporal leftovers + that were inserted. diff --git a/doc/src/sgml/ref/update.sgml b/doc/src/sgml/ref/update.sgml index 40cca0639463..ad3224c2df22 100644 --- a/doc/src/sgml/ref/update.sgml +++ b/doc/src/sgml/ref/update.sgml @@ -22,7 +22,9 @@ PostgreSQL documentation [ WITH [ RECURSIVE ] with_query [, ...] ] -UPDATE [ ONLY ] table_name [ * ] [ [ AS ] alias ] +UPDATE [ ONLY ] table_name [ * ] + [ FOR PORTION OF range_name for_portion_of_target ] + [ [ AS ] alias ] SET { column_name = { expression | DEFAULT } | ( column_name [, ...] ) = [ ROW ] ( { expression | DEFAULT } [, ...] ) | ( column_name [, ...] ) = ( sub-SELECT ) @@ -52,6 +54,45 @@ UPDATE [ ONLY ] table_name [ * ] [ circumstances. + + If the table has a range or multirange column, + you may supply a FOR PORTION OF clause, and your update will + only affect rows that overlap the given interval. Furthermore, if a row's history + extends outside the FOR PORTION OF bounds, then your update + will only change the history within those bounds. In effect you are updating any + moment targeted by FOR PORTION OF and no moments outside. + + + + Specifically, when PostgreSQL updates the existing row, + it will also change the range or multirange so that their interval + no longer extends beyond the targeted FOR PORTION OF bounds. + Then PostgreSQL will INSERT + new temporal leftovers: + rows whose range or multirange receive the remaining history outside + the targeted bounds, with un-updated values in their other columns. + There will be zero to two inserted records, + depending on whether the original history extended before the targeted + FROM, after the targeted TO, both, or neither. + Multiranges never require two temporal leftovers, because one value can always contain + whatever history remains. + + + + These secondary inserts fire INSERT triggers. + Both STATEMENT and ROW triggers are fired. + The BEFORE UPDATE triggers are fired first, then + BEFORE INSERT, then AFTER INSERT, + then AFTER UPDATE. + + + + These secondary inserts do not require INSERT privilege on the table. + This is because conceptually no new information has been added. The inserted rows only preserve + existing data about the untargeted time period. Note this may result in users firing INSERT + triggers who don't have insert privileges, so be careful about SECURITY DEFINER trigger functions! + + The optional RETURNING clause causes UPDATE to compute and return value(s) based on each row actually updated. @@ -116,6 +157,57 @@ UPDATE [ ONLY ] table_name [ * ] [ + + range_name + + + The range or multirange column to use when performing a temporal update. + + + + + + for_portion_of_target + + + The interval to update. If you are targeting a range column, + you may give this in the form FROM + start_time TO + end_time. + Otherwise you must use + (expression) + where the expression yields a value of the same type as + range_name. + + + + + + start_time + + + The earliest time (inclusive) to change in a temporal update. + This must be a value matching the base type of the range from + range_name. A + NULL here indicates an update whose beginning is + unbounded (as with range types). + + + + + + end_time + + + The latest time (exclusive) to change in a temporal update. + This must be a value matching the base type of the range from + range_name. A + NULL here indicates an update whose end is unbounded + (as with range types). + + + + column_name @@ -283,6 +375,10 @@ UPDATE count updates were suppressed by a BEFORE UPDATE trigger. If count is 0, no rows were updated by the query (this is not considered an error). + If FOR PORTION OF was used, the + count also includes + temporal leftovers + that were inserted. diff --git a/doc/src/sgml/trigger.sgml b/doc/src/sgml/trigger.sgml index bb1b5faf34e3..e3ad98065282 100644 --- a/doc/src/sgml/trigger.sgml +++ b/doc/src/sgml/trigger.sgml @@ -373,6 +373,15 @@ responsibility to avoid that. + + If an UPDATE or DELETE uses + FOR PORTION OF, causing new rows to be inserted + to preserve the leftover untargeted part of modified records, then + INSERT triggers are fired for each inserted + row. Each row is inserted separately, so they fire their own + statement triggers, and they have their own transition tables. + + trigger diff --git a/src/backend/executor/execMain.c b/src/backend/executor/execMain.c index 27c9eec697b1..269c877dbcf5 100644 --- a/src/backend/executor/execMain.c +++ b/src/backend/executor/execMain.c @@ -1295,6 +1295,7 @@ InitResultRelInfo(ResultRelInfo *resultRelInfo, resultRelInfo->ri_projectReturning = NULL; resultRelInfo->ri_onConflictArbiterIndexes = NIL; resultRelInfo->ri_onConflict = NULL; + resultRelInfo->ri_forPortionOf = NULL; resultRelInfo->ri_ReturningSlot = NULL; resultRelInfo->ri_TrigOldSlot = NULL; resultRelInfo->ri_TrigNewSlot = NULL; diff --git a/src/backend/executor/nodeModifyTable.c b/src/backend/executor/nodeModifyTable.c index 4c5647ac38a1..665dbc182391 100644 --- a/src/backend/executor/nodeModifyTable.c +++ b/src/backend/executor/nodeModifyTable.c @@ -68,6 +68,7 @@ #include "storage/lmgr.h" #include "utils/builtins.h" #include "utils/datum.h" +#include "utils/rangetypes.h" #include "utils/rel.h" #include "utils/snapmgr.h" @@ -131,7 +132,6 @@ typedef struct UpdateContext LockTupleMode lockmode; } UpdateContext; - static void ExecBatchInsert(ModifyTableState *mtstate, ResultRelInfo *resultRelInfo, TupleTableSlot **slots, @@ -152,6 +152,10 @@ static bool ExecOnConflictUpdate(ModifyTableContext *context, TupleTableSlot *excludedSlot, bool canSetTag, TupleTableSlot **returning); +static void ExecForPortionOfLeftovers(ModifyTableContext *context, + EState *estate, + ResultRelInfo *resultRelInfo, + ItemPointer tupleid); static TupleTableSlot *ExecPrepareTupleRouting(ModifyTableState *mtstate, EState *estate, PartitionTupleRouting *proute, @@ -174,6 +178,9 @@ static TupleTableSlot *ExecMergeMatched(ModifyTableContext *context, static TupleTableSlot *ExecMergeNotMatched(ModifyTableContext *context, ResultRelInfo *resultRelInfo, bool canSetTag); +static void ExecSetupTransitionCaptureState(ModifyTableState *mtstate, EState *estate); +static void fireBSTriggers(ModifyTableState *node); +static void fireASTriggers(ModifyTableState *node); /* @@ -1355,6 +1362,192 @@ ExecInsert(ModifyTableContext *context, return result; } +/* ---------------------------------------------------------------- + * ExecForPortionOfLeftovers + * + * Insert tuples for the untouched portion of a row in a FOR + * PORTION OF UPDATE/DELETE + * ---------------------------------------------------------------- + */ +static void +ExecForPortionOfLeftovers(ModifyTableContext *context, + EState *estate, + ResultRelInfo *resultRelInfo, + ItemPointer tupleid) +{ + ModifyTableState *mtstate = context->mtstate; + ModifyTable *node = (ModifyTable *) mtstate->ps.plan; + ForPortionOfExpr *forPortionOf = (ForPortionOfExpr *) node->forPortionOf; + AttrNumber rangeAttno; + Datum oldRange; + TypeCacheEntry *typcache; + ForPortionOfState *fpoState = resultRelInfo->ri_forPortionOf; + TupleTableSlot *oldtupleSlot = fpoState->fp_Existing; + TupleTableSlot *leftoverSlot = fpoState->fp_Leftover; + TupleConversionMap *map = NULL; + HeapTuple oldtuple = NULL; + CmdType oldOperation; + TransitionCaptureState *oldTcs; + FmgrInfo flinfo; + ReturnSetInfo rsi; + bool didInit = false; + bool shouldFree = false; + + LOCAL_FCINFO(fcinfo, 2); + + /* + * Get the old pre-UPDATE/DELETE tuple. We will use its range to compute + * untouched parts of history, and if necessary we will insert copies + * with truncated start/end times. + * + * We have already locked the tuple in ExecUpdate/ExecDelete, and it has + * passed EvalPlanQual. This ensures that concurrent updates in READ + * COMMITTED can't insert conflicting temporal leftovers. + */ + if (!table_tuple_fetch_row_version(resultRelInfo->ri_RelationDesc, tupleid, SnapshotAny, oldtupleSlot)) + elog(ERROR, "failed to fetch tuple for FOR PORTION OF"); + + /* + * Get the old range of the record being updated/deleted. Must read with + * the attno of the leaf partition being updated. + */ + + rangeAttno = forPortionOf->rangeVar->varattno; + if (resultRelInfo->ri_RootResultRelInfo) + map = ExecGetChildToRootMap(resultRelInfo); + if (map != NULL) + rangeAttno = map->attrMap->attnums[rangeAttno - 1]; + slot_getallattrs(oldtupleSlot); + + if (oldtupleSlot->tts_isnull[rangeAttno - 1]) + elog(ERROR, "found a NULL range in a temporal table"); + oldRange = oldtupleSlot->tts_values[rangeAttno - 1]; + + /* + * Get the range's type cache entry. This is worth caching for the whole + * UPDATE/DELETE as range functions do. + */ + + typcache = fpoState->fp_leftoverstypcache; + if (typcache == NULL) + { + typcache = lookup_type_cache(forPortionOf->rangeType, 0); + fpoState->fp_leftoverstypcache = typcache; + } + + /* + * Get the ranges to the left/right of the targeted range. We call a SETOF + * support function and insert as many temporal leftovers as it gives us. + * Although rangetypes have 0/1/2 leftovers, multiranges have 0/1, and + * other types may have more. + */ + + fmgr_info(forPortionOf->withoutPortionProc, &flinfo); + rsi.type = T_ReturnSetInfo; + rsi.econtext = mtstate->ps.ps_ExprContext; + rsi.expectedDesc = NULL; + rsi.allowedModes = (int) (SFRM_ValuePerCall); + rsi.returnMode = SFRM_ValuePerCall; + rsi.setResult = NULL; + rsi.setDesc = NULL; + + InitFunctionCallInfoData(*fcinfo, &flinfo, 2, InvalidOid, NULL, (Node *) &rsi); + fcinfo->args[0].value = oldRange; + fcinfo->args[0].isnull = false; + fcinfo->args[1].value = fpoState->fp_targetRange; + fcinfo->args[1].isnull = false; + + /* + * If there are partitions, we must insert into the root table, so we get + * tuple routing. We already set up leftoverSlot with the root tuple + * descriptor. + */ + if (resultRelInfo->ri_RootResultRelInfo) + resultRelInfo = resultRelInfo->ri_RootResultRelInfo; + + /* + * Insert a leftover for each value returned by the without_portion helper + * function + */ + while (true) + { + Datum leftover = FunctionCallInvoke(fcinfo); + + /* Are we done? */ + if (rsi.isDone == ExprEndResult) + break; + + if (fcinfo->isnull) + elog(ERROR, "Got a null from without_portion function"); + + if (!didInit) + { + /* + * Make a copy of the pre-UPDATE row. Then we'll overwrite the + * range column below. Convert oldtuple to the base table's format + * if necessary. We need to insert temporal leftovers through the + * root partition so they get routed correctly. + */ + if (map != NULL) + { + leftoverSlot = execute_attr_map_slot(map->attrMap, + oldtupleSlot, + leftoverSlot); + } + else + { + oldtuple = ExecFetchSlotHeapTuple(oldtupleSlot, false, &shouldFree); + ExecForceStoreHeapTuple(oldtuple, leftoverSlot, false); + } + + /* + * Save some mtstate things so we can restore them below. XXX: + * Should we create our own ModifyTableState instead? + */ + oldOperation = mtstate->operation; + mtstate->operation = CMD_INSERT; + oldTcs = mtstate->mt_transition_capture; + + didInit = true; + } + + leftoverSlot->tts_values[forPortionOf->rangeVar->varattno - 1] = leftover; + leftoverSlot->tts_isnull[forPortionOf->rangeVar->varattno - 1] = false; + ExecMaterializeSlot(leftoverSlot); + + /* + * If there are partitions, we must insert into the root table, so we + * get tuple routing. We already set up leftoverSlot with the root + * tuple descriptor. + */ + if (resultRelInfo->ri_RootResultRelInfo) + resultRelInfo = resultRelInfo->ri_RootResultRelInfo; + + /* + * The standard says that each temporal leftover should execute its + * own INSERT statement, firing all statement and row triggers, but + * skipping insert permission checks. Therefore we give each insert + * its own transition table. If we just push & pop a new trigger level + * for each insert, we get exactly what we need. + */ + AfterTriggerBeginQuery(); + ExecSetupTransitionCaptureState(mtstate, estate); + fireBSTriggers(mtstate); + ExecInsert(context, resultRelInfo, leftoverSlot, node->canSetTag, NULL, NULL); + fireASTriggers(mtstate); + AfterTriggerEndQuery(estate); + } + + if (didInit) + { + mtstate->operation = oldOperation; + mtstate->mt_transition_capture = oldTcs; + + if (shouldFree) + heap_freetuple(oldtuple); + } +} + /* ---------------------------------------------------------------- * ExecBatchInsert * @@ -1508,7 +1701,8 @@ ExecDeleteAct(ModifyTableContext *context, ResultRelInfo *resultRelInfo, * * Closing steps of tuple deletion; this invokes AFTER FOR EACH ROW triggers, * including the UPDATE triggers if the deletion is being done as part of a - * cross-partition tuple move. + * cross-partition tuple move. It also inserts temporal leftovers from a + * DELETE FOR PORTION OF. */ static void ExecDeleteEpilogue(ModifyTableContext *context, ResultRelInfo *resultRelInfo, @@ -1541,6 +1735,10 @@ ExecDeleteEpilogue(ModifyTableContext *context, ResultRelInfo *resultRelInfo, ar_delete_trig_tcs = NULL; } + /* Compute temporal leftovers in FOR PORTION OF */ + if (((ModifyTable *) context->mtstate->ps.plan)->forPortionOf) + ExecForPortionOfLeftovers(context, estate, resultRelInfo, tupleid); + /* AFTER ROW DELETE Triggers */ ExecARDeleteTriggers(estate, resultRelInfo, tupleid, oldtuple, ar_delete_trig_tcs, changingPart); @@ -1966,7 +2164,10 @@ ExecCrossPartitionUpdate(ModifyTableContext *context, if (resultRelInfo == mtstate->rootResultRelInfo) ExecPartitionCheckEmitError(resultRelInfo, slot, estate); - /* Initialize tuple routing info if not already done. */ + /* + * Initialize tuple routing info if not already done. Note whatever we do + * here must be done in ExecInitModifyTable for FOR PORTION OF as well. + */ if (mtstate->mt_partition_tuple_routing == NULL) { Relation rootRel = mtstate->rootResultRelInfo->ri_RelationDesc; @@ -2315,7 +2516,8 @@ ExecUpdateAct(ModifyTableContext *context, ResultRelInfo *resultRelInfo, * ExecUpdateEpilogue -- subroutine for ExecUpdate * * Closing steps of updating a tuple. Must be called if ExecUpdateAct - * returns indicating that the tuple was updated. + * returns indicating that the tuple was updated. It also inserts temporal + * leftovers from an UPDATE FOR PORTION OF. */ static void ExecUpdateEpilogue(ModifyTableContext *context, UpdateContext *updateCxt, @@ -2333,6 +2535,10 @@ ExecUpdateEpilogue(ModifyTableContext *context, UpdateContext *updateCxt, NULL, NIL, (updateCxt->updateIndexes == TU_Summarizing)); + /* Compute temporal leftovers in FOR PORTION OF */ + if (((ModifyTable *) context->mtstate->ps.plan)->forPortionOf) + ExecForPortionOfLeftovers(context, context->estate, resultRelInfo, tupleid); + /* AFTER ROW UPDATE Triggers */ ExecARUpdateTriggers(context->estate, resultRelInfo, NULL, NULL, @@ -5062,6 +5268,122 @@ ExecInitModifyTable(ModifyTable *node, EState *estate, int eflags) } } + /* + * If needed, initialize the target range for FOR PORTION OF. + */ + if (node->forPortionOf) + { + ResultRelInfo *rootResultRelInfo; + TupleDesc tupDesc; + ForPortionOfExpr *forPortionOf; + Datum targetRange; + bool isNull; + ExprContext *econtext; + ExprState *exprState; + ForPortionOfState *fpoState; + + rootResultRelInfo = mtstate->resultRelInfo; + if (rootResultRelInfo->ri_RootResultRelInfo) + rootResultRelInfo = rootResultRelInfo->ri_RootResultRelInfo; + + tupDesc = rootResultRelInfo->ri_RelationDesc->rd_att; + forPortionOf = (ForPortionOfExpr *) node->forPortionOf; + + /* Eval the FOR PORTION OF target */ + if (mtstate->ps.ps_ExprContext == NULL) + ExecAssignExprContext(estate, &mtstate->ps); + econtext = mtstate->ps.ps_ExprContext; + + exprState = ExecPrepareExpr((Expr *) forPortionOf->targetRange, estate); + targetRange = ExecEvalExpr(exprState, econtext, &isNull); + if (isNull) + elog(ERROR, "Got a NULL FOR PORTION OF target range"); + + /* Create state for FOR PORTION OF operation */ + + fpoState = makeNode(ForPortionOfState); + fpoState->fp_rangeName = forPortionOf->range_name; + fpoState->fp_rangeType = forPortionOf->rangeType; + fpoState->fp_rangeAttno = forPortionOf->rangeVar->varattno; + fpoState->fp_targetRange = targetRange; + + /* Initialize slot for the existing tuple */ + + fpoState->fp_Existing = + table_slot_create(rootResultRelInfo->ri_RelationDesc, + &mtstate->ps.state->es_tupleTable); + + /* Create the tuple slot for INSERTing the temporal leftovers */ + + fpoState->fp_Leftover = + ExecInitExtraTupleSlot(mtstate->ps.state, tupDesc, &TTSOpsVirtual); + + /* + * We must attach the ForPortionOfState to all result rels, in case of + * a cross-partition update or triggers firing on partitions. XXX: Can + * we defer this to only the leafs we touch? + */ + for (i = 0; i < nrels; i++) + { + ForPortionOfState *leafState; + + resultRelInfo = &mtstate->resultRelInfo[i]; + + leafState = makeNode(ForPortionOfState); + leafState->fp_rangeName = fpoState->fp_rangeName; + leafState->fp_rangeType = fpoState->fp_rangeType; + leafState->fp_rangeAttno = fpoState->fp_rangeAttno; + leafState->fp_targetRange = fpoState->fp_targetRange; + leafState->fp_Leftover = fpoState->fp_Leftover; + /* Each partition needs a slot matching its tuple descriptor */ + leafState->fp_Existing = + table_slot_create(resultRelInfo->ri_RelationDesc, + &mtstate->ps.state->es_tupleTable); + + resultRelInfo->ri_forPortionOf = leafState; + } + + /* Make sure the root relation has the FOR PORTION OF clause too. */ + if (node->rootRelation > 0) + mtstate->rootResultRelInfo->ri_forPortionOf = fpoState; + + if (rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE && + mtstate->mt_partition_tuple_routing == NULL) + { + /* + * We will need tuple routing to insert temporal leftovers. Since + * we are initializing things before ExecCrossPartitionUpdate + * runs, we must do everything it needs as well. + */ + if (mtstate->mt_partition_tuple_routing == NULL) + { + Relation rootRel = mtstate->rootResultRelInfo->ri_RelationDesc; + MemoryContext oldcxt; + + /* Things built here have to last for the query duration. */ + oldcxt = MemoryContextSwitchTo(estate->es_query_cxt); + + mtstate->mt_partition_tuple_routing = + ExecSetupPartitionTupleRouting(estate, rootRel); + + /* + * Before a partition's tuple can be re-routed, it must first + * be converted to the root's format, so we'll need a slot for + * storing such tuples. + */ + Assert(mtstate->mt_root_tuple_slot == NULL); + mtstate->mt_root_tuple_slot = table_slot_create(rootRel, NULL); + + MemoryContextSwitchTo(oldcxt); + } + } + + /* + * Don't free the ExprContext here because the result must last for + * the whole query + */ + } + /* * If we have any secondary relations in an UPDATE or DELETE, they need to * be treated like non-locked relations in SELECT FOR UPDATE, i.e., the diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c index ede838cd40c4..e40e8eecf732 100644 --- a/src/backend/nodes/nodeFuncs.c +++ b/src/backend/nodes/nodeFuncs.c @@ -2567,6 +2567,14 @@ expression_tree_walker_impl(Node *node, return true; } break; + case T_ForPortionOfExpr: + { + ForPortionOfExpr *forPortionOf = (ForPortionOfExpr *) node; + + if (WALK(forPortionOf->targetRange)) + return true; + } + break; case T_PartitionPruneStepOp: { PartitionPruneStepOp *opstep = (PartitionPruneStepOp *) node; @@ -2715,6 +2723,8 @@ query_tree_walker_impl(Query *query, return true; if (WALK(query->mergeJoinCondition)) return true; + if (WALK(query->forPortionOf)) + return true; if (WALK(query->returningList)) return true; if (WALK(query->jointree)) @@ -3609,6 +3619,19 @@ expression_tree_mutator_impl(Node *node, return (Node *) newnode; } break; + case T_ForPortionOfExpr: + { + ForPortionOfExpr *fpo = (ForPortionOfExpr *) node; + ForPortionOfExpr *newnode; + + FLATCOPY(newnode, fpo, ForPortionOfExpr); + MUTATE(newnode->rangeVar, fpo->rangeVar, Var *); + MUTATE(newnode->targetRange, fpo->targetRange, Node *); + MUTATE(newnode->rangeTargetList, fpo->rangeTargetList, List *); + + return (Node *) newnode; + } + break; case T_PartitionPruneStepOp: { PartitionPruneStepOp *opstep = (PartitionPruneStepOp *) node; @@ -3790,6 +3813,7 @@ query_tree_mutator_impl(Query *query, MUTATE(query->onConflict, query->onConflict, OnConflictExpr *); MUTATE(query->mergeActionList, query->mergeActionList, List *); MUTATE(query->mergeJoinCondition, query->mergeJoinCondition, Node *); + MUTATE(query->forPortionOf, query->forPortionOf, ForPortionOfExpr *); MUTATE(query->returningList, query->returningList, List *); MUTATE(query->jointree, query->jointree, FromExpr *); MUTATE(query->setOperations, query->setOperations, Node *); diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c index 8af091ba6471..4a43f579f84f 100644 --- a/src/backend/optimizer/plan/createplan.c +++ b/src/backend/optimizer/plan/createplan.c @@ -316,7 +316,7 @@ static ModifyTable *make_modifytable(PlannerInfo *root, Plan *subplan, List *withCheckOptionLists, List *returningLists, List *rowMarks, OnConflictExpr *onconflict, List *mergeActionLists, List *mergeJoinConditions, - int epqParam); + ForPortionOfExpr *forPortionOf, int epqParam); static GatherMerge *create_gather_merge_plan(PlannerInfo *root, GatherMergePath *best_path); @@ -2675,6 +2675,7 @@ create_modifytable_plan(PlannerInfo *root, ModifyTablePath *best_path) best_path->onconflict, best_path->mergeActionLists, best_path->mergeJoinConditions, + best_path->forPortionOf, best_path->epqParam); copy_generic_path_info(&plan->plan, &best_path->path); @@ -7001,7 +7002,7 @@ make_modifytable(PlannerInfo *root, Plan *subplan, List *withCheckOptionLists, List *returningLists, List *rowMarks, OnConflictExpr *onconflict, List *mergeActionLists, List *mergeJoinConditions, - int epqParam) + ForPortionOfExpr *forPortionOf, int epqParam) { ModifyTable *node = makeNode(ModifyTable); bool returning_old_or_new = false; @@ -7070,6 +7071,7 @@ make_modifytable(PlannerInfo *root, Plan *subplan, node->exclRelTlist = onconflict->exclRelTlist; } node->updateColnosLists = updateColnosLists; + node->forPortionOf = (Node *) forPortionOf; node->withCheckOptionLists = withCheckOptionLists; node->returningOldAlias = root->parse->returningOldAlias; node->returningNewAlias = root->parse->returningNewAlias; diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c index c4fd646b999c..7e2f19fb5e2e 100644 --- a/src/backend/optimizer/plan/planner.c +++ b/src/backend/optimizer/plan/planner.c @@ -2151,6 +2151,7 @@ grouping_planner(PlannerInfo *root, double tuple_fraction, parse->onConflict, mergeActionLists, mergeJoinConditions, + parse->forPortionOf, assign_special_exec_param(root)); } diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c index e4fd6950fad1..32b1930b9452 100644 --- a/src/backend/optimizer/util/pathnode.c +++ b/src/backend/optimizer/util/pathnode.c @@ -3635,7 +3635,7 @@ create_modifytable_path(PlannerInfo *root, RelOptInfo *rel, List *withCheckOptionLists, List *returningLists, List *rowMarks, OnConflictExpr *onconflict, List *mergeActionLists, List *mergeJoinConditions, - int epqParam) + ForPortionOfExpr *forPortionOf, int epqParam) { ModifyTablePath *pathnode = makeNode(ModifyTablePath); @@ -3701,6 +3701,7 @@ create_modifytable_path(PlannerInfo *root, RelOptInfo *rel, pathnode->returningLists = returningLists; pathnode->rowMarks = rowMarks; pathnode->onconflict = onconflict; + pathnode->forPortionOf = forPortionOf; pathnode->epqParam = epqParam; pathnode->mergeActionLists = mergeActionLists; pathnode->mergeJoinConditions = mergeJoinConditions; diff --git a/src/backend/parser/analyze.c b/src/backend/parser/analyze.c index 3b392b084ad6..5cf73278e16f 100644 --- a/src/backend/parser/analyze.c +++ b/src/backend/parser/analyze.c @@ -24,7 +24,10 @@ #include "postgres.h" +#include "access/stratnum.h" #include "access/sysattr.h" +#include "catalog/pg_am.h" +#include "catalog/pg_operator.h" #include "catalog/pg_proc.h" #include "catalog/pg_type.h" #include "commands/defrem.h" @@ -50,7 +53,9 @@ #include "parser/parsetree.h" #include "utils/backend_status.h" #include "utils/builtins.h" +#include "utils/fmgroids.h" #include "utils/guc.h" +#include "utils/lsyscache.h" #include "utils/rel.h" #include "utils/syscache.h" @@ -67,10 +72,16 @@ typedef struct SelectStmtPassthrough post_parse_analyze_hook_type post_parse_analyze_hook = NULL; static Query *transformOptionalSelectInto(ParseState *pstate, Node *parseTree); +static Node *addForPortionOfWhereConditions(Query *qry, ForPortionOfClause *forPortionOf, + Node *whereClause); static Query *transformDeleteStmt(ParseState *pstate, DeleteStmt *stmt); static Query *transformInsertStmt(ParseState *pstate, InsertStmt *stmt); static OnConflictExpr *transformOnConflictClause(ParseState *pstate, OnConflictClause *onConflictClause); +static ForPortionOfExpr *transformForPortionOfClause(ParseState *pstate, + int rtindex, + ForPortionOfClause *forPortionOfClause, + bool isUpdate); static int count_rowexpr_columns(ParseState *pstate, Node *expr); static Query *transformSelectStmt(ParseState *pstate, SelectStmt *stmt, SelectStmtPassthrough *passthru); @@ -493,6 +504,20 @@ stmt_requires_parse_analysis(RawStmt *parseTree) return result; } +static Node * +addForPortionOfWhereConditions(Query *qry, ForPortionOfClause *forPortionOf, Node *whereClause) +{ + if (forPortionOf) + { + if (whereClause) + return (Node *) makeBoolExpr(AND_EXPR, list_make2(qry->forPortionOf->overlapsExpr, whereClause), -1); + else + return qry->forPortionOf->overlapsExpr; + } + else + return whereClause; +} + /* * analyze_requires_snapshot * Returns true if a snapshot must be set before doing parse analysis @@ -565,6 +590,7 @@ transformDeleteStmt(ParseState *pstate, DeleteStmt *stmt) { Query *qry = makeNode(Query); ParseNamespaceItem *nsitem; + Node *whereClause; Node *qual; qry->commandType = CMD_DELETE; @@ -603,7 +629,11 @@ transformDeleteStmt(ParseState *pstate, DeleteStmt *stmt) nsitem->p_lateral_only = false; nsitem->p_lateral_ok = true; - qual = transformWhereClause(pstate, stmt->whereClause, + if (stmt->forPortionOf) + qry->forPortionOf = transformForPortionOfClause(pstate, qry->resultRelation, stmt->forPortionOf, false); + + whereClause = addForPortionOfWhereConditions(qry, stmt->forPortionOf, stmt->whereClause); + qual = transformWhereClause(pstate, whereClause, EXPR_KIND_WHERE, "WHERE"); transformReturningClause(pstate, qry, stmt->returningClause, @@ -1238,7 +1268,7 @@ transformOnConflictClause(ParseState *pstate, * Now transform the UPDATE subexpressions. */ onConflictSet = - transformUpdateTargetList(pstate, onConflictClause->targetList); + transformUpdateTargetList(pstate, onConflictClause->targetList, NULL); onConflictWhere = transformWhereClause(pstate, onConflictClause->whereClause, @@ -1268,6 +1298,194 @@ transformOnConflictClause(ParseState *pstate, return result; } +/* + * transformForPortionOfClause + * + * Transforms a ForPortionOfClause in an UPDATE/DELETE statement. + * + * - Look up the range/period requested. + * - Build a compatible range value from the FROM and TO expressions. + * - Build an "overlaps" expression for filtering. + * - For UPDATEs, build an "intersects" expression the rewriter can add + * to the targetList to change the temporal bounds. + */ +static ForPortionOfExpr * +transformForPortionOfClause(ParseState *pstate, + int rtindex, + ForPortionOfClause *forPortionOf, + bool isUpdate) +{ + Relation targetrel = pstate->p_target_relation; + RTEPermissionInfo *target_perminfo = pstate->p_target_nsitem->p_perminfo; + char *range_name = forPortionOf->range_name; + char *range_type_namespace = NULL; + char *range_type_name = NULL; + int range_attno = InvalidAttrNumber; + Form_pg_attribute attr; + Oid opclass; + Oid opfamily; + Oid opcintype; + Oid funcid = InvalidOid; + StrategyNumber strat; + Oid opid; + ForPortionOfExpr *result; + Var *rangeVar; + Node *targetExpr; + + /* We don't support FOR PORTION OF FDW queries. */ + if (targetrel->rd_rel->relkind == RELKIND_FOREIGN_TABLE) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("foreign tables don't support FOR PORTION OF"))); + + result = makeNode(ForPortionOfExpr); + + /* Look up the FOR PORTION OF name requested. */ + range_attno = attnameAttNum(targetrel, range_name, false); + if (range_attno == InvalidAttrNumber) + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_COLUMN), + errmsg("column or period \"%s\" of relation \"%s\" does not exist", + range_name, + RelationGetRelationName(targetrel)), + parser_errposition(pstate, forPortionOf->location))); + attr = TupleDescAttr(targetrel->rd_att, range_attno - 1); + + rangeVar = makeVar( + rtindex, + range_attno, + attr->atttypid, + attr->atttypmod, + attr->attcollation, + 0); + rangeVar->location = forPortionOf->location; + result->rangeVar = rangeVar; + result->rangeType = attr->atttypid; + if (!get_typname_and_namespace(attr->atttypid, &range_type_name, &range_type_namespace)) + elog(ERROR, "cache lookup failed for type %u", attr->atttypid); + + + if (forPortionOf->target) + + /* + * We were already given an expression for the target, so we don't + * have to build anything. + */ + targetExpr = forPortionOf->target; + else + { + /* Make sure it's a range column */ + if (!type_is_range(attr->atttypid)) + ereport(ERROR, + (errcode(ERRCODE_INVALID_COLUMN_REFERENCE), + errmsg("column \"%s\" of relation \"%s\" is not a range type", + range_name, + RelationGetRelationName(targetrel)), + parser_errposition(pstate, forPortionOf->location))); + + /* + * Build a range from the FROM ... TO .... bounds. This should give a + * constant result, so we accept functions like NOW() but not column + * references, subqueries, etc. + */ + targetExpr = (Node *) makeFuncCall( + list_make2(makeString(range_type_namespace), makeString(range_type_name)), + list_make2(forPortionOf->target_start, forPortionOf->target_end), + COERCE_EXPLICIT_CALL, + forPortionOf->location); + } + result->targetRange = transformExpr(pstate, targetExpr, EXPR_KIND_UPDATE_PORTION); + + /* + * Build overlapsExpr to use in the whereClause. This means we only hit + * rows matching the FROM & TO bounds. We must look up the overlaps + * operator (usually "&&"). + */ + opclass = GetDefaultOpClass(attr->atttypid, GIST_AM_OID); + strat = RTOverlapStrategyNumber; + GetOperatorFromCompareType(opclass, InvalidOid, COMPARE_OVERLAP, &opid, &strat); + result->overlapsExpr = (Node *) makeSimpleA_Expr(AEXPR_OP, get_opname(opid), + (Node *) copyObject(rangeVar), targetExpr, + forPortionOf->location); + + /* + * Look up the without_portion func. This computes the bounds of temporal + * leftovers. + * + * XXX: Find a more extensible way to look up the function, permitting + * user-defined types. An opclass support function doesn't make sense, + * since there is no index involved. Perhaps a type support function. + */ + if (get_opclass_opfamily_and_input_type(opclass, &opfamily, &opcintype)) + switch (opcintype) + { + case ANYRANGEOID: + result->withoutPortionProc = F_RANGE_MINUS_MULTI; + break; + case ANYMULTIRANGEOID: + result->withoutPortionProc = F_MULTIRANGE_MINUS_MULTI; + break; + default: + elog(ERROR, "unexpected opcintype: %u", opcintype); + } + else + elog(ERROR, "unexpected opclass: %u", opclass); + + if (isUpdate) + { + /* + * Now make sure we update the start/end time of the record. For a + * range col (r) this is `r = r * targetRange`. + */ + Oid intersectoperoid; + List *funcArgs = NIL; + FuncExpr *rangeTLEExpr; + TargetEntry *tle; + + /* + * Whatever operator is used for intersect by temporal foreign keys, + * we can use its backing procedure for intersects in FOR PORTION OF. + * XXX: Share code with FindFKPeriodOpers? + */ + switch (opcintype) + { + case ANYRANGEOID: + intersectoperoid = OID_RANGE_INTERSECT_RANGE_OP; + break; + case ANYMULTIRANGEOID: + intersectoperoid = OID_MULTIRANGE_INTERSECT_MULTIRANGE_OP; + break; + default: + elog(ERROR, "Unexpected opcintype: %u", opcintype); + } + funcid = get_opcode(intersectoperoid); + if (!OidIsValid(funcid)) + ereport(ERROR, + errcode(ERRCODE_UNDEFINED_OBJECT), + errmsg("could not identify an intersect function for type %s", format_type_be(opcintype))); + + targetExpr = transformExpr(pstate, targetExpr, EXPR_KIND_UPDATE_PORTION); + funcArgs = lappend(funcArgs, copyObject(rangeVar)); + funcArgs = lappend(funcArgs, targetExpr); + rangeTLEExpr = makeFuncExpr(funcid, attr->atttypid, funcArgs, + InvalidOid, InvalidOid, COERCE_EXPLICIT_CALL); + + /* Make a TLE to set the range column */ + result->rangeTargetList = NIL; + tle = makeTargetEntry((Expr *) rangeTLEExpr, range_attno, range_name, false); + result->rangeTargetList = lappend(result->rangeTargetList, tle); + + /* Mark the range column as requiring update permissions */ + target_perminfo->updatedCols = bms_add_member(target_perminfo->updatedCols, + range_attno - FirstLowInvalidHeapAttributeNumber); + } + else + result->rangeTargetList = NIL; + + result->range_name = range_name; + + return result; +} /* * BuildOnConflictExcludedTargetlist @@ -2491,6 +2709,7 @@ transformUpdateStmt(ParseState *pstate, UpdateStmt *stmt) { Query *qry = makeNode(Query); ParseNamespaceItem *nsitem; + Node *whereClause; Node *qual; qry->commandType = CMD_UPDATE; @@ -2508,6 +2727,10 @@ transformUpdateStmt(ParseState *pstate, UpdateStmt *stmt) stmt->relation->inh, true, ACL_UPDATE); + + if (stmt->forPortionOf) + qry->forPortionOf = transformForPortionOfClause(pstate, qry->resultRelation, stmt->forPortionOf, true); + nsitem = pstate->p_target_nsitem; /* subqueries in FROM cannot access the result relation */ @@ -2524,7 +2747,8 @@ transformUpdateStmt(ParseState *pstate, UpdateStmt *stmt) nsitem->p_lateral_only = false; nsitem->p_lateral_ok = true; - qual = transformWhereClause(pstate, stmt->whereClause, + whereClause = addForPortionOfWhereConditions(qry, stmt->forPortionOf, stmt->whereClause); + qual = transformWhereClause(pstate, whereClause, EXPR_KIND_WHERE, "WHERE"); transformReturningClause(pstate, qry, stmt->returningClause, @@ -2534,7 +2758,7 @@ transformUpdateStmt(ParseState *pstate, UpdateStmt *stmt) * Now we are done with SELECT-like processing, and can get on with * transforming the target list to match the UPDATE target columns. */ - qry->targetList = transformUpdateTargetList(pstate, stmt->targetList); + qry->targetList = transformUpdateTargetList(pstate, stmt->targetList, qry->forPortionOf); qry->rtable = pstate->p_rtable; qry->rteperminfos = pstate->p_rteperminfos; @@ -2553,7 +2777,7 @@ transformUpdateStmt(ParseState *pstate, UpdateStmt *stmt) * handle SET clause in UPDATE/MERGE/INSERT ... ON CONFLICT UPDATE */ List * -transformUpdateTargetList(ParseState *pstate, List *origTlist) +transformUpdateTargetList(ParseState *pstate, List *origTlist, ForPortionOfExpr *forPortionOf) { List *tlist = NIL; RTEPermissionInfo *target_perminfo; @@ -2606,6 +2830,20 @@ transformUpdateTargetList(ParseState *pstate, List *origTlist) errhint("SET target columns cannot be qualified with the relation name.") : 0, parser_errposition(pstate, origTarget->location))); + /* + * If this is a FOR PORTION OF update, forbid directly setting the + * range column, since that would conflict with the implicit updates. + */ + if (forPortionOf != NULL) + { + if (attrno == forPortionOf->rangeVar->varattno) + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("can't directly assign to \"%s\" in a FOR PORTION OF update", + origTarget->name), + parser_errposition(pstate, origTarget->location))); + } + updateTargetListEntry(pstate, tle, origTarget->name, attrno, origTarget->indirection, diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index 8a0470d5b841..a1561e774571 100644 --- a/src/backend/parser/gram.y +++ b/src/backend/parser/gram.y @@ -250,6 +250,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); RangeVar *range; IntoClause *into; WithClause *with; + ForPortionOfClause *forportionof; InferClause *infer; OnConflictClause *onconflict; A_Indices *aind; @@ -554,6 +555,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); %type relation_expr %type extended_relation_expr %type relation_expr_opt_alias +%type opt_alias +%type for_portion_of_clause %type tablesample_clause opt_repeatable_clause %type target_el set_target insert_column_item @@ -763,7 +766,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER PARALLEL PARAMETER PARSER PARTIAL PARTITION PASSING PASSWORD PATH - PERIOD PLACING PLAN PLANS POLICY + PERIOD PLACING PLAN PLANS POLICY PORTION POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION @@ -882,12 +885,15 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); * json_predicate_type_constraint and json_key_uniqueness_constraint_opt * productions (see comments there). * + * TO is assigned the same precedence as IDENT, to support the opt_interval + * production (see comment there). + * * Like the UNBOUNDED PRECEDING/FOLLOWING case, NESTED is assigned a lower * precedence than PATH to fix ambiguity in the json_table production. */ %nonassoc UNBOUNDED NESTED /* ideally would have same precedence as IDENT */ %nonassoc IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP - SET KEYS OBJECT_P SCALAR VALUE_P WITH WITHOUT PATH + SET KEYS OBJECT_P SCALAR TO USING VALUE_P WITH WITHOUT PATH %left Op OPERATOR /* multi-character ops and user-defined operators */ %left '+' '-' %left '*' '/' '%' @@ -12550,6 +12556,20 @@ DeleteStmt: opt_with_clause DELETE_P FROM relation_expr_opt_alias n->withClause = $1; $$ = (Node *) n; } + | opt_with_clause DELETE_P FROM relation_expr for_portion_of_clause opt_alias + using_clause where_or_current_clause returning_clause + { + DeleteStmt *n = makeNode(DeleteStmt); + + n->relation = $4; + n->forPortionOf = $5; + n->relation->alias = $6; + n->usingClause = $7; + n->whereClause = $8; + n->returningClause = $9; + n->withClause = $1; + $$ = (Node *) n; + } ; using_clause: @@ -12624,6 +12644,25 @@ UpdateStmt: opt_with_clause UPDATE relation_expr_opt_alias n->withClause = $1; $$ = (Node *) n; } + | opt_with_clause UPDATE relation_expr + for_portion_of_clause opt_alias + SET set_clause_list + from_clause + where_or_current_clause + returning_clause + { + UpdateStmt *n = makeNode(UpdateStmt); + + n->relation = $3; + n->forPortionOf = $4; + n->relation->alias = $5; + n->targetList = $7; + n->fromClause = $8; + n->whereClause = $9; + n->returningClause = $10; + n->withClause = $1; + $$ = (Node *) n; + } ; set_clause_list: @@ -14121,6 +14160,44 @@ relation_expr_opt_alias: relation_expr %prec UMINUS } ; +opt_alias: + AS ColId + { + Alias *alias = makeNode(Alias); + + alias->aliasname = $2; + $$ = alias; + } + | BareColLabel + { + Alias *alias = makeNode(Alias); + + alias->aliasname = $1; + $$ = alias; + } + | /* empty */ %prec UMINUS { $$ = NULL; } + ; + +for_portion_of_clause: + FOR PORTION OF ColId '(' a_expr ')' + { + ForPortionOfClause *n = makeNode(ForPortionOfClause); + n->range_name = $4; + n->location = @4; + n->target = $6; + $$ = n; + } + | FOR PORTION OF ColId FROM a_expr TO a_expr + { + ForPortionOfClause *n = makeNode(ForPortionOfClause); + n->range_name = $4; + n->location = @4; + n->target_start = $6; + n->target_end = $8; + $$ = n; + } + ; + /* * TABLESAMPLE decoration in a FROM item */ @@ -14961,16 +15038,25 @@ opt_timezone: | /*EMPTY*/ { $$ = false; } ; +/* + * We need to handle this shift/reduce conflict: + * FOR PORTION OF valid_at FROM t + INTERVAL '1' YEAR TO MONTH. + * We don't see far enough ahead to know if there is another TO coming. + * We prefer to interpret this as FROM (t + INTERVAL '1' YEAR TO MONTH), + * i.e. to shift. + * That gives the user the option of adding parentheses to get the other meaning. + * If we reduced, intervals could never have a TO. + */ opt_interval: - YEAR_P + YEAR_P %prec IS { $$ = list_make1(makeIntConst(INTERVAL_MASK(YEAR), @1)); } | MONTH_P { $$ = list_make1(makeIntConst(INTERVAL_MASK(MONTH), @1)); } - | DAY_P + | DAY_P %prec IS { $$ = list_make1(makeIntConst(INTERVAL_MASK(DAY), @1)); } - | HOUR_P + | HOUR_P %prec IS { $$ = list_make1(makeIntConst(INTERVAL_MASK(HOUR), @1)); } - | MINUTE_P + | MINUTE_P %prec IS { $$ = list_make1(makeIntConst(INTERVAL_MASK(MINUTE), @1)); } | interval_second { $$ = $1; } @@ -18024,6 +18110,7 @@ unreserved_keyword: | PLAN | PLANS | POLICY + | PORTION | PRECEDING | PREPARE | PREPARED @@ -18653,6 +18740,7 @@ bare_label_keyword: | PLAN | PLANS | POLICY + | PORTION | POSITION | PRECEDING | PREPARE diff --git a/src/backend/parser/parse_agg.c b/src/backend/parser/parse_agg.c index 3254c83cc6cd..8b8c2b9299c8 100644 --- a/src/backend/parser/parse_agg.c +++ b/src/backend/parser/parse_agg.c @@ -579,6 +579,13 @@ check_agglevels_and_constraints(ParseState *pstate, Node *expr) case EXPR_KIND_CYCLE_MARK: errkind = true; break; + case EXPR_KIND_UPDATE_PORTION: + if (isAgg) + err = _("aggregate functions are not allowed in FOR PORTION OF expressions"); + else + err = _("grouping operations are not allowed in FOR PORTION OF expressions"); + + break; /* * There is intentionally no default: case here, so that the @@ -996,6 +1003,9 @@ transformWindowFuncCall(ParseState *pstate, WindowFunc *wfunc, case EXPR_KIND_CYCLE_MARK: errkind = true; break; + case EXPR_KIND_UPDATE_PORTION: + err = _("window functions are not allowed in FOR PORTION OF expressions"); + break; /* * There is intentionally no default: case here, so that the diff --git a/src/backend/parser/parse_collate.c b/src/backend/parser/parse_collate.c index d2e218353f31..522345b1668e 100644 --- a/src/backend/parser/parse_collate.c +++ b/src/backend/parser/parse_collate.c @@ -484,6 +484,7 @@ assign_collations_walker(Node *node, assign_collations_context *context) case T_JoinExpr: case T_FromExpr: case T_OnConflictExpr: + case T_ForPortionOfExpr: case T_SortGroupClause: case T_MergeAction: (void) expression_tree_walker(node, diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c index 32d6ae918caa..2d469c177f02 100644 --- a/src/backend/parser/parse_expr.c +++ b/src/backend/parser/parse_expr.c @@ -585,6 +585,9 @@ transformColumnRef(ParseState *pstate, ColumnRef *cref) case EXPR_KIND_PARTITION_BOUND: err = _("cannot use column reference in partition bound expression"); break; + case EXPR_KIND_UPDATE_PORTION: + err = _("cannot use column reference in FOR PORTION OF expression"); + break; /* * There is intentionally no default: case here, so that the @@ -1861,6 +1864,9 @@ transformSubLink(ParseState *pstate, SubLink *sublink) case EXPR_KIND_GENERATED_COLUMN: err = _("cannot use subquery in column generation expression"); break; + case EXPR_KIND_UPDATE_PORTION: + err = _("cannot use subquery in FOR PORTION OF expression"); + break; /* * There is intentionally no default: case here, so that the @@ -3174,6 +3180,8 @@ ParseExprKindName(ParseExprKind exprKind) return "UPDATE"; case EXPR_KIND_MERGE_WHEN: return "MERGE WHEN"; + case EXPR_KIND_UPDATE_PORTION: + return "FOR PORTION OF"; case EXPR_KIND_GROUP_BY: return "GROUP BY"; case EXPR_KIND_ORDER_BY: diff --git a/src/backend/parser/parse_func.c b/src/backend/parser/parse_func.c index 778d69c6f3c2..4764dd21c900 100644 --- a/src/backend/parser/parse_func.c +++ b/src/backend/parser/parse_func.c @@ -2783,6 +2783,9 @@ check_srf_call_placement(ParseState *pstate, Node *last_srf, int location) case EXPR_KIND_CYCLE_MARK: errkind = true; break; + case EXPR_KIND_UPDATE_PORTION: + err = _("set-returning functions are not allowed in FOR PORTION OF expressions"); + break; /* * There is intentionally no default: case here, so that the diff --git a/src/backend/parser/parse_merge.c b/src/backend/parser/parse_merge.c index 51d7703eff7e..ed276c41460b 100644 --- a/src/backend/parser/parse_merge.c +++ b/src/backend/parser/parse_merge.c @@ -385,7 +385,7 @@ transformMergeStmt(ParseState *pstate, MergeStmt *stmt) pstate->p_is_insert = false; action->targetList = transformUpdateTargetList(pstate, - mergeWhenClause->targetList); + mergeWhenClause->targetList, NULL); } break; case CMD_DELETE: diff --git a/src/backend/rewrite/rewriteHandler.c b/src/backend/rewrite/rewriteHandler.c index adc9e7600e1e..e883b7f2a603 100644 --- a/src/backend/rewrite/rewriteHandler.c +++ b/src/backend/rewrite/rewriteHandler.c @@ -3729,6 +3729,30 @@ rewriteTargetView(Query *parsetree, Relation view) &parsetree->hasSubLinks); } + if (parsetree->forPortionOf && parsetree->commandType == CMD_UPDATE) + { + /* + * Like the INSERT/UPDATE code above, update the resnos in the + * auxiliary UPDATE targetlist to refer to columns of the base + * relation. + */ + foreach(lc, parsetree->forPortionOf->rangeTargetList) + { + TargetEntry *tle = (TargetEntry *) lfirst(lc); + TargetEntry *view_tle; + + if (tle->resjunk) + continue; + + view_tle = get_tle_by_resno(view_targetlist, tle->resno); + if (view_tle != NULL && !view_tle->resjunk && IsA(view_tle->expr, Var)) + tle->resno = ((Var *) view_tle->expr)->varattno; + else + elog(ERROR, "attribute number %d not found in view targetlist", + tle->resno); + } + } + /* * For UPDATE/DELETE/MERGE, pull up any WHERE quals from the view. We * know that any Vars in the quals must reference the one base relation, @@ -4068,6 +4092,25 @@ RewriteQuery(Query *parsetree, List *rewrite_events, int orig_rt_length) else if (event == CMD_UPDATE) { Assert(parsetree->override == OVERRIDING_NOT_SET); + + /* + * Update FOR PORTION OF column(s) automatically. Don't do this + * until we're done rewriting a view update, so that we don't add + * the same update on the recursion. + */ + if (parsetree->forPortionOf && + rt_entry_relation->rd_rel->relkind != RELKIND_VIEW) + { + ListCell *tl; + + foreach(tl, parsetree->forPortionOf->rangeTargetList) + { + TargetEntry *tle = (TargetEntry *) lfirst(tl); + + parsetree->targetList = lappend(parsetree->targetList, tle); + } + } + parsetree->targetList = rewriteTargetListIU(parsetree->targetList, parsetree->commandType, diff --git a/src/backend/utils/adt/ri_triggers.c b/src/backend/utils/adt/ri_triggers.c index 059fc5ebf601..d6b1eb57a489 100644 --- a/src/backend/utils/adt/ri_triggers.c +++ b/src/backend/utils/adt/ri_triggers.c @@ -128,7 +128,7 @@ typedef struct RI_ConstraintInfo Oid ff_eq_oprs[RI_MAX_NUMKEYS]; /* equality operators (FK = FK) */ Oid period_contained_by_oper; /* anyrange <@ anyrange */ Oid agged_period_contained_by_oper; /* fkattr <@ range_agg(pkattr) */ - Oid period_intersect_oper; /* anyrange * anyrange */ + Oid period_intersect_oper; /* anyrange * anyrange (or multirange) */ dlist_node valid_link; /* Link in list of valid entries */ } RI_ConstraintInfo; diff --git a/src/backend/utils/cache/lsyscache.c b/src/backend/utils/cache/lsyscache.c index fa7cd7e06a7a..43158afac150 100644 --- a/src/backend/utils/cache/lsyscache.c +++ b/src/backend/utils/cache/lsyscache.c @@ -2355,6 +2355,33 @@ get_typisdefined(Oid typid) return false; } +/* + * get_typname_and_namespace + * + * Returns the name and namespace of a given type + * + * Returns true if one found, or false if not. + */ +bool +get_typname_and_namespace(Oid typid, char **typname, char **typnamespace) +{ + HeapTuple tp; + + tp = SearchSysCache1(TYPEOID, ObjectIdGetDatum(typid)); + if (HeapTupleIsValid(tp)) + { + Form_pg_type typtup = (Form_pg_type) GETSTRUCT(tp); + + *typname = pstrdup(NameStr(typtup->typname)); + *typnamespace = get_namespace_name(typtup->typnamespace); + ReleaseSysCache(tp); + /* *typnamespace is NULL if it wasn't found: */ + return *typnamespace; + } + else + return false; +} + /* * get_typlen * diff --git a/src/include/nodes/execnodes.h b/src/include/nodes/execnodes.h index 18ae8f0d4bb8..acb3d5458a26 100644 --- a/src/include/nodes/execnodes.h +++ b/src/include/nodes/execnodes.h @@ -48,6 +48,7 @@ #include "utils/sortsupport.h" #include "utils/tuplesort.h" #include "utils/tuplestore.h" +#include "utils/typcache.h" /* * forward references in this file @@ -452,6 +453,24 @@ typedef struct MergeActionState ExprState *mas_whenqual; /* WHEN [NOT] MATCHED AND conditions */ } MergeActionState; +/* + * ForPortionOfState + * + * Executor state of a FOR PORTION OF operation. + */ +typedef struct ForPortionOfState +{ + NodeTag type; + + char *fp_rangeName; /* the column named in FOR PORTION OF */ + Oid fp_rangeType; /* the type of the FOR PORTION OF expression */ + int fp_rangeAttno; /* the attno of the range column */ + Datum fp_targetRange; /* the range/multirange from FOR PORTION OF */ + TypeCacheEntry *fp_leftoverstypcache; /* type cache entry of the range */ + TupleTableSlot *fp_Existing; /* slot to store old tuple */ + TupleTableSlot *fp_Leftover; /* slot to store leftover */ +} ForPortionOfState; + /* * ResultRelInfo * @@ -588,6 +607,9 @@ typedef struct ResultRelInfo /* for MERGE, expr state for checking the join condition */ ExprState *ri_MergeJoinCondition; + /* FOR PORTION OF evaluation state */ + ForPortionOfState *ri_forPortionOf; + /* partition check expression state (NULL if not set up yet) */ ExprState *ri_PartitionCheckExpr; diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h index ecbddd12e1b3..a09e9d9ba6ac 100644 --- a/src/include/nodes/parsenodes.h +++ b/src/include/nodes/parsenodes.h @@ -147,6 +147,9 @@ typedef struct Query */ int resultRelation pg_node_attr(query_jumble_ignore); + /* FOR PORTION OF clause for UPDATE/DELETE */ + ForPortionOfExpr *forPortionOf; + /* has aggregates in tlist or havingQual */ bool hasAggs pg_node_attr(query_jumble_ignore); /* has window functions in tlist */ @@ -1613,6 +1616,21 @@ typedef struct RowMarkClause bool pushedDown; /* pushed down from higher query level? */ } RowMarkClause; +/* + * ForPortionOfClause + * representation of FOR PORTION OF FROM TO + * or FOR PORTION OF () + */ +typedef struct ForPortionOfClause +{ + NodeTag type; + char *range_name; + int location; + Node *target; + Node *target_start; + Node *target_end; +} ForPortionOfClause; + /* * WithClause - * representation of WITH clause @@ -2126,6 +2144,7 @@ typedef struct DeleteStmt Node *whereClause; /* qualifications */ ReturningClause *returningClause; /* RETURNING clause */ WithClause *withClause; /* WITH clause */ + ForPortionOfClause *forPortionOf; /* FOR PORTION OF clause */ } DeleteStmt; /* ---------------------- @@ -2141,6 +2160,7 @@ typedef struct UpdateStmt List *fromClause; /* optional from clause for more tables */ ReturningClause *returningClause; /* RETURNING clause */ WithClause *withClause; /* WITH clause */ + ForPortionOfClause *forPortionOf; /* FOR PORTION OF clause */ } UpdateStmt; /* ---------------------- diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h index 30d889b54c53..eba697257f21 100644 --- a/src/include/nodes/pathnodes.h +++ b/src/include/nodes/pathnodes.h @@ -2612,6 +2612,7 @@ typedef struct ModifyTablePath List *returningLists; /* per-target-table RETURNING tlists */ List *rowMarks; /* PlanRowMarks (non-locking only) */ OnConflictExpr *onconflict; /* ON CONFLICT clause, or NULL */ + ForPortionOfExpr *forPortionOf; /* FOR PORTION OF clause for UPDATE/DELETE */ int epqParam; /* ID of Param for EvalPlanQual re-eval */ List *mergeActionLists; /* per-target-table lists of actions for * MERGE */ diff --git a/src/include/nodes/plannodes.h b/src/include/nodes/plannodes.h index c4393a943211..92b87c148599 100644 --- a/src/include/nodes/plannodes.h +++ b/src/include/nodes/plannodes.h @@ -368,6 +368,8 @@ typedef struct ModifyTable List *onConflictCols; /* WHERE for ON CONFLICT UPDATE */ Node *onConflictWhere; + /* FOR PORTION OF clause for UPDATE/DELETE */ + Node *forPortionOf; /* RTI of the EXCLUDED pseudo relation */ Index exclRelRTI; /* tlist of the EXCLUDED pseudo relation */ diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h index 1b4436f2ff6d..fbbcd77dd843 100644 --- a/src/include/nodes/primnodes.h +++ b/src/include/nodes/primnodes.h @@ -2385,4 +2385,31 @@ typedef struct OnConflictExpr List *exclRelTlist; /* tlist of the EXCLUDED pseudo relation */ } OnConflictExpr; +/*---------- + * ForPortionOfExpr - represents a FOR PORTION OF ... expression + * + * We set up an expression to make a range from the FROM/TO bounds, + * so that we can use range operators with it. + * + * Then we set up an overlaps expression between that and the range column, + * so that we can find the rows we need to update/delete. + * + * In the executor we'll also build an intersect expression between the + * targeted range and the range column, so that we can update the start/end + * bounds of the UPDATE'd record. + *---------- + */ +typedef struct ForPortionOfExpr +{ + NodeTag type; + Var *rangeVar; /* Range column */ + char *range_name; /* Range name */ + Node *targetRange; /* FOR PORTION OF bounds as a range */ + Oid rangeType; /* type of targetRange */ + Node *overlapsExpr; /* range && targetRange */ + List *rangeTargetList; /* List of TargetEntrys to set the time + * column(s) */ + Oid withoutPortionProc; /* SRF proc for old_range - target_range */ +} ForPortionOfExpr; + #endif /* PRIMNODES_H */ diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h index 955e90568583..ac0f691743f5 100644 --- a/src/include/optimizer/pathnode.h +++ b/src/include/optimizer/pathnode.h @@ -286,7 +286,7 @@ extern ModifyTablePath *create_modifytable_path(PlannerInfo *root, List *withCheckOptionLists, List *returningLists, List *rowMarks, OnConflictExpr *onconflict, List *mergeActionLists, List *mergeJoinConditions, - int epqParam); + ForPortionOfExpr *forPortionOf, int epqParam); extern LimitPath *create_limit_path(PlannerInfo *root, RelOptInfo *rel, Path *subpath, Node *limitOffset, Node *limitCount, diff --git a/src/include/parser/analyze.h b/src/include/parser/analyze.h index f29ed03b476e..4614be052dcc 100644 --- a/src/include/parser/analyze.h +++ b/src/include/parser/analyze.h @@ -43,7 +43,8 @@ extern List *transformInsertRow(ParseState *pstate, List *exprlist, List *stmtcols, List *icolumns, List *attrnos, bool strip_indirection); extern List *transformUpdateTargetList(ParseState *pstate, - List *origTlist); + List *origTlist, + ForPortionOfExpr *forPortionOf); extern void transformReturningClause(ParseState *pstate, Query *qry, ReturningClause *returningClause, ParseExprKind exprKind); diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h index 84182eaaae2a..a8def3a386c1 100644 --- a/src/include/parser/kwlist.h +++ b/src/include/parser/kwlist.h @@ -346,6 +346,7 @@ PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL) +PG_KEYWORD("portion", PORTION, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD, BARE_LABEL) PG_KEYWORD("preceding", PRECEDING, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("precision", PRECISION, COL_NAME_KEYWORD, AS_LABEL) diff --git a/src/include/parser/parse_node.h b/src/include/parser/parse_node.h index f7d07c845425..3e457d961fee 100644 --- a/src/include/parser/parse_node.h +++ b/src/include/parser/parse_node.h @@ -56,6 +56,7 @@ typedef enum ParseExprKind EXPR_KIND_UPDATE_SOURCE, /* UPDATE assignment source item */ EXPR_KIND_UPDATE_TARGET, /* UPDATE assignment target item */ EXPR_KIND_MERGE_WHEN, /* MERGE WHEN [NOT] MATCHED condition */ + EXPR_KIND_UPDATE_PORTION, /* UPDATE FOR PORTION OF item */ EXPR_KIND_GROUP_BY, /* GROUP BY */ EXPR_KIND_ORDER_BY, /* ORDER BY */ EXPR_KIND_DISTINCT_ON, /* DISTINCT ON */ diff --git a/src/include/utils/lsyscache.h b/src/include/utils/lsyscache.h index 50fb149e9ac9..5b50ef230ab1 100644 --- a/src/include/utils/lsyscache.h +++ b/src/include/utils/lsyscache.h @@ -150,6 +150,7 @@ extern Oid get_rel_relam(Oid relid); extern Oid get_transform_fromsql(Oid typid, Oid langid, List *trftypes); extern Oid get_transform_tosql(Oid typid, Oid langid, List *trftypes); extern bool get_typisdefined(Oid typid); +extern bool get_typname_and_namespace(Oid typid, char **typname, char **typnamespace); extern int16 get_typlen(Oid typid); extern bool get_typbyval(Oid typid); extern void get_typlenbyval(Oid typid, int16 *typlen, bool *typbyval); diff --git a/src/test/regress/expected/for_portion_of.out b/src/test/regress/expected/for_portion_of.out new file mode 100644 index 000000000000..9288b4224f73 --- /dev/null +++ b/src/test/regress/expected/for_portion_of.out @@ -0,0 +1,1248 @@ +-- Tests for UPDATE/DELETE FOR PORTION OF +SET datestyle TO ISO, YMD; +-- Works on non-PK columns +CREATE TABLE for_portion_of_test ( + id int4range, + valid_at daterange, + name text NOT NULL +); +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[1,2)', '[2018-01-02,2020-01-01)', 'one'); +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-01-15' TO '2019-01-01' + SET name = 'one^1'; +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2019-01-15' TO '2019-01-20'; +-- With a table alias with AS +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2019-02-01' TO '2019-02-03' AS t + SET name = 'one^2'; +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2019-02-03' TO '2019-02-04' AS t; +-- With a table alias without AS +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2019-02-04' TO '2019-02-05' t + SET name = 'one^3'; +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2019-02-05' TO '2019-02-06' t; +-- UPDATE with FROM +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2019-03-01' to '2019-03-02' + SET name = 'one^4' + FROM (SELECT '[1,2)'::int4range) AS t2(id) + WHERE for_portion_of_test.id = t2.id; +-- DELETE with USING +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2019-03-02' TO '2019-03-03' + USING (SELECT '[1,2)'::int4range) AS t2(id) + WHERE for_portion_of_test.id = t2.id; +SELECT * FROM for_portion_of_test ORDER BY id, valid_at; + id | valid_at | name +-------+-------------------------+------- + [1,2) | [2018-01-02,2018-01-15) | one + [1,2) | [2018-01-15,2019-01-01) | one^1 + [1,2) | [2019-01-01,2019-01-15) | one + [1,2) | [2019-01-20,2019-02-01) | one + [1,2) | [2019-02-01,2019-02-03) | one^2 + [1,2) | [2019-02-04,2019-02-05) | one^3 + [1,2) | [2019-02-06,2019-03-01) | one + [1,2) | [2019-03-01,2019-03-02) | one^4 + [1,2) | [2019-03-03,2020-01-01) | one +(9 rows) + +-- Works on more than one range +DROP TABLE for_portion_of_test; +CREATE TABLE for_portion_of_test ( + id int4range, + valid1_at daterange, + valid2_at daterange, + name text NOT NULL +); +INSERT INTO for_portion_of_test (id, valid1_at, valid2_at, name) VALUES + ('[1,2)', '[2018-01-02,2018-02-03)', '[2015-01-01,2025-01-01)', 'one'); +UPDATE for_portion_of_test + FOR PORTION OF valid1_at FROM '2018-01-15' TO NULL + SET name = 'foo'; + SELECT * FROM for_portion_of_test ORDER BY id, valid1_at, valid2_at; + id | valid1_at | valid2_at | name +-------+-------------------------+-------------------------+------ + [1,2) | [2018-01-02,2018-01-15) | [2015-01-01,2025-01-01) | one + [1,2) | [2018-01-15,2018-02-03) | [2015-01-01,2025-01-01) | foo +(2 rows) + +UPDATE for_portion_of_test + FOR PORTION OF valid2_at FROM '2018-01-15' TO NULL + SET name = 'bar'; + SELECT * FROM for_portion_of_test ORDER BY id, valid1_at, valid2_at; + id | valid1_at | valid2_at | name +-------+-------------------------+-------------------------+------ + [1,2) | [2018-01-02,2018-01-15) | [2015-01-01,2018-01-15) | one + [1,2) | [2018-01-02,2018-01-15) | [2018-01-15,2025-01-01) | bar + [1,2) | [2018-01-15,2018-02-03) | [2015-01-01,2018-01-15) | foo + [1,2) | [2018-01-15,2018-02-03) | [2018-01-15,2025-01-01) | bar +(4 rows) + +DELETE FROM for_portion_of_test + FOR PORTION OF valid1_at FROM '2018-01-20' TO NULL; + SELECT * FROM for_portion_of_test ORDER BY id, valid1_at, valid2_at; + id | valid1_at | valid2_at | name +-------+-------------------------+-------------------------+------ + [1,2) | [2018-01-02,2018-01-15) | [2015-01-01,2018-01-15) | one + [1,2) | [2018-01-02,2018-01-15) | [2018-01-15,2025-01-01) | bar + [1,2) | [2018-01-15,2018-01-20) | [2015-01-01,2018-01-15) | foo + [1,2) | [2018-01-15,2018-01-20) | [2018-01-15,2025-01-01) | bar +(4 rows) + +DELETE FROM for_portion_of_test + FOR PORTION OF valid2_at FROM '2018-01-20' TO NULL; + SELECT * FROM for_portion_of_test ORDER BY id, valid1_at, valid2_at; + id | valid1_at | valid2_at | name +-------+-------------------------+-------------------------+------ + [1,2) | [2018-01-02,2018-01-15) | [2015-01-01,2018-01-15) | one + [1,2) | [2018-01-02,2018-01-15) | [2018-01-15,2018-01-20) | bar + [1,2) | [2018-01-15,2018-01-20) | [2015-01-01,2018-01-15) | foo + [1,2) | [2018-01-15,2018-01-20) | [2018-01-15,2018-01-20) | bar +(4 rows) + +-- Test with NULLs in the scalar/range key columns. +-- This won't happen if there is a PRIMARY KEY or UNIQUE constraint +-- but FOR PORTION OF shouldn't require that. +DROP TABLE for_portion_of_test; +CREATE UNLOGGED TABLE for_portion_of_test ( + id int4range, + valid_at daterange, + name text +); +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[1,2)', NULL, '1 null'), + ('[1,2)', '(,)', '1 unbounded'), + ('[1,2)', 'empty', '1 empty'), + (NULL, NULL, NULL), + (NULL, daterange('2018-01-01', '2019-01-01'), 'null key'); +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO NULL + SET name = 'NULL to NULL'; +SELECT * FROM for_portion_of_test ORDER BY id, valid_at; + id | valid_at | name +-------+-------------------------+-------------- + [1,2) | empty | 1 empty + [1,2) | (,) | NULL to NULL + [1,2) | | 1 null + | [2018-01-01,2019-01-01) | NULL to NULL + | | +(5 rows) + +DROP TABLE for_portion_of_test; +-- +-- UPDATE tests +-- +CREATE TABLE for_portion_of_test ( + id int4range NOT NULL, + valid_at daterange NOT NULL, + name text NOT NULL, + CONSTRAINT for_portion_of_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[1,2)', '[2018-01-02,2018-02-03)', 'one'), + ('[1,2)', '[2018-02-03,2018-03-03)', 'one'), + ('[1,2)', '[2018-03-03,2018-04-04)', 'one'), + ('[2,3)', '[2018-01-01,2018-01-05)', 'two'), + ('[3,4)', '[2018-01-01,)', 'three'), + ('[4,5)', '(,2018-04-01)', 'four'), + ('[5,6)', '(,)', 'five') + ; +\set QUIET false +-- Updating with a missing column fails +UPDATE for_portion_of_test + FOR PORTION OF invalid_at FROM '2018-06-01' TO NULL + SET name = 'foo' + WHERE id = '[5,6)'; +ERROR: column or period "invalid_at" of relation "for_portion_of_test" does not exist +LINE 2: FOR PORTION OF invalid_at FROM '2018-06-01' TO NULL + ^ +-- Updating the range fails +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-06-01' TO NULL + SET valid_at = '[1990-01-01,1999-01-01)' + WHERE id = '[5,6)'; +ERROR: can't directly assign to "valid_at" in a FOR PORTION OF update +LINE 3: SET valid_at = '[1990-01-01,1999-01-01)' + ^ +-- The wrong type fails +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM 1 TO 4 + SET name = 'nope' + WHERE id = '[3,4)'; +ERROR: function pg_catalog.daterange(integer, integer) does not exist +LINE 2: FOR PORTION OF valid_at FROM 1 TO 4 + ^ +DETAIL: No function of that name accepts the given argument types. +HINT: You might need to add explicit type casts. +-- Updating with timestamps reversed fails +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-06-01' TO '2018-01-01' + SET name = 'three^1' + WHERE id = '[3,4)'; +ERROR: range lower bound must be less than or equal to range upper bound +-- Updating with a subquery fails +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM (SELECT '2018-01-01') TO '2018-06-01' + SET name = 'nope' + WHERE id = '[3,4)'; +ERROR: cannot use subquery in FOR PORTION OF expression +LINE 2: FOR PORTION OF valid_at FROM (SELECT '2018-01-01') TO '201... + ^ +-- Updating with a column fails +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM lower(valid_at) TO NULL + SET name = 'nope' + WHERE id = '[3,4)'; +ERROR: cannot use column reference in FOR PORTION OF expression +LINE 2: FOR PORTION OF valid_at FROM lower(valid_at) TO NULL + ^ +-- Updating with timestamps equal does nothing +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-04-01' TO '2018-04-01' + SET name = 'three^0' + WHERE id = '[3,4)'; +UPDATE 0 +-- Updating a finite/open portion with a finite/open target +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-06-01' TO NULL + SET name = 'three^1' + WHERE id = '[3,4)'; +UPDATE 2 +-- Updating a finite/open portion with an open/finite target +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO '2018-03-01' + SET name = 'three^2' + WHERE id = '[3,4)'; +UPDATE 2 +-- Updating an open/finite portion with an open/finite target +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO '2018-02-01' + SET name = 'four^1' + WHERE id = '[4,5)'; +UPDATE 2 +-- Updating an open/finite portion with a finite/open target +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2017-01-01' TO NULL + SET name = 'four^2' + WHERE id = '[4,5)'; +UPDATE 3 +-- Updating a finite/finite portion with an exact fit +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2017-01-01' TO '2018-02-01' + SET name = 'four^3' + WHERE id = '[4,5)'; +UPDATE 1 +-- Updating an enclosed span +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO NULL + SET name = 'two^2' + WHERE id = '[2,3)'; +UPDATE 1 +-- Updating an open/open portion with a finite/finite target +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-01-01' TO '2019-01-01' + SET name = 'five^1' + WHERE id = '[5,6)'; +UPDATE 3 +-- Updating an enclosed span with separate protruding spans +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2017-01-01' TO '2020-01-01' + SET name = 'five^2' + WHERE id = '[5,6)'; +UPDATE 5 +-- Updating multiple enclosed spans +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO NULL + SET name = 'one^2' + WHERE id = '[1,2)'; +UPDATE 3 +-- Updating with a direct target +UPDATE for_portion_of_test + FOR PORTION OF valid_at (daterange('2018-03-10', '2018-03-17')) + SET name = 'one^3' + WHERE id = '[1,2)'; +UPDATE 3 +-- Updating the non-range part of the PK: +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-02-15' TO NULL + SET id = '[6,7)' + WHERE id = '[1,2)'; +UPDATE 5 +-- UPDATE with no WHERE clause +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2030-01-01' TO NULL + SET name = name || '*'; +UPDATE 4 +SELECT * FROM for_portion_of_test ORDER BY id, valid_at; + id | valid_at | name +-------+-------------------------+---------- + [1,2) | [2018-01-02,2018-02-03) | one^2 + [1,2) | [2018-02-03,2018-02-15) | one^2 + [2,3) | [2018-01-01,2018-01-05) | two^2 + [3,4) | [2018-01-01,2018-03-01) | three^2 + [3,4) | [2018-03-01,2018-06-01) | three + [3,4) | [2018-06-01,2030-01-01) | three^1 + [3,4) | [2030-01-01,) | three^1* + [4,5) | (,2017-01-01) | four^1 + [4,5) | [2017-01-01,2018-02-01) | four^3 + [4,5) | [2018-02-01,2018-04-01) | four^2 + [5,6) | (,2017-01-01) | five + [5,6) | [2017-01-01,2018-01-01) | five^2 + [5,6) | [2018-01-01,2019-01-01) | five^2 + [5,6) | [2019-01-01,2020-01-01) | five^2 + [5,6) | [2020-01-01,2030-01-01) | five + [5,6) | [2030-01-01,) | five* + [6,7) | [2018-02-15,2018-03-03) | one^2 + [6,7) | [2018-03-03,2018-03-10) | one^2 + [6,7) | [2018-03-10,2018-03-17) | one^3 + [6,7) | [2018-03-17,2018-04-04) | one^2 +(20 rows) + +\set QUIET true +-- Updating with a shift/reduce conflict +-- (requires a tsrange column) +CREATE UNLOGGED TABLE for_portion_of_test2 ( + id int4range, + valid_at tsrange, + name text +); +INSERT INTO for_portion_of_test2 (id, valid_at, name) VALUES + ('[1,2)', '[2000-01-01,2020-01-01)', 'one'); +-- updates [2011-03-01 01:02:00, 2012-01-01) (note 2 minutes) +UPDATE for_portion_of_test2 + FOR PORTION OF valid_at + FROM '2011-03-01'::timestamp + INTERVAL '1:02:03' HOUR TO MINUTE + TO '2012-01-01' + SET name = 'one^1' + WHERE id = '[1,2)'; +-- TO is used for the bound but not the INTERVAL: +-- syntax error +UPDATE for_portion_of_test2 + FOR PORTION OF valid_at + FROM '2013-03-01'::timestamp + INTERVAL '1:02:03' HOUR + TO '2014-01-01' + SET name = 'one^2' + WHERE id = '[1,2)'; +ERROR: syntax error at or near "'2014-01-01'" +LINE 4: TO '2014-01-01' + ^ +-- adding parens fixes it +-- updates [2015-03-01 01:00:00, 2016-01-01) (no minutes) +UPDATE for_portion_of_test2 + FOR PORTION OF valid_at + FROM ('2015-03-01'::timestamp + INTERVAL '1:02:03' HOUR) + TO '2016-01-01' + SET name = 'one^3' + WHERE id = '[1,2)'; +SELECT * FROM for_portion_of_test2 ORDER BY id, valid_at; + id | valid_at | name +-------+-----------------------------------------------+------- + [1,2) | ["2000-01-01 00:00:00","2011-03-01 01:02:00") | one + [1,2) | ["2011-03-01 01:02:00","2012-01-01 00:00:00") | one^1 + [1,2) | ["2012-01-01 00:00:00","2015-03-01 01:00:00") | one + [1,2) | ["2015-03-01 01:00:00","2016-01-01 00:00:00") | one^3 + [1,2) | ["2016-01-01 00:00:00","2020-01-01 00:00:00") | one +(5 rows) + +DROP TABLE for_portion_of_test2; +-- UPDATE FOR PORTION OF in a CTE: +-- Visible to SELECT: +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[10,11)', '[2018-01-01,2020-01-01)', 'ten'); +WITH update_apr AS ( + UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-04-01' TO '2018-05-01' + SET name = 'Apr 2018' + WHERE id = '[10,11)' + RETURNING id, valid_at, name +) +SELECT * + FROM for_portion_of_test AS t, update_apr + WHERE t.id = update_apr.id; + id | valid_at | name | id | valid_at | name +---------+-------------------------+------+---------+-------------------------+---------- + [10,11) | [2018-01-01,2020-01-01) | ten | [10,11) | [2018-04-01,2018-05-01) | Apr 2018 +(1 row) + +SELECT * FROM for_portion_of_test WHERE id = '[10,11)'; + id | valid_at | name +---------+-------------------------+---------- + [10,11) | [2018-04-01,2018-05-01) | Apr 2018 + [10,11) | [2018-01-01,2018-04-01) | ten + [10,11) | [2018-05-01,2020-01-01) | ten +(3 rows) + +-- Not visible to UPDATE: +-- Tuples updated/inserted within the CTE are not visible to the main query yet, +-- but neither are old tuples the CTE changed: +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[11,12)', '[2018-01-01,2020-01-01)', 'eleven'); +WITH update_apr AS ( + UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-04-01' TO '2018-05-01' + SET name = 'Apr 2018' + WHERE id = '[11,12)' + RETURNING id, valid_at, name +) +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-05-01' TO '2018-06-01' + AS t + SET name = 'May 2018' + FROM update_apr AS j + WHERE t.id = j.id; +SELECT * FROM for_portion_of_test WHERE id = '[11,12)'; + id | valid_at | name +---------+-------------------------+---------- + [11,12) | [2018-04-01,2018-05-01) | Apr 2018 + [11,12) | [2018-01-01,2018-04-01) | eleven + [11,12) | [2018-05-01,2020-01-01) | eleven +(3 rows) + +DELETE FROM for_portion_of_test WHERE id IN ('[10,11)', '[11,12)'); +-- UPDATE FOR PORTION OF in a PL/pgSQL function +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[10,11)', '[2018-01-01,2020-01-01)', 'ten'); +CREATE FUNCTION fpo_update(_id int4range, _target_from date, _target_til date) +RETURNS void LANGUAGE plpgsql AS +$$ +BEGIN + UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM $2 TO $3 + SET name = concat(_target_from::text, ' to ', _target_til::text) + WHERE id = $1; +END; +$$; +SELECT fpo_update('[10,11)', '2015-01-01', '2019-01-01'); + fpo_update +------------ + +(1 row) + +SELECT * FROM for_portion_of_test WHERE id = '[10,11)'; + id | valid_at | name +---------+-------------------------+-------------------------- + [10,11) | [2018-01-01,2019-01-01) | 2015-01-01 to 2019-01-01 + [10,11) | [2019-01-01,2020-01-01) | ten +(2 rows) + +DROP TABLE for_portion_of_test; +-- +-- DELETE tests +-- +CREATE TABLE for_portion_of_test ( + id int4range NOT NULL, + valid_at daterange NOT NULL, + name text NOT NULL, + CONSTRAINT for_portion_of_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[1,2)', '[2018-01-02,2018-02-03)', 'one'), + ('[1,2)', '[2018-02-03,2018-03-03)', 'one'), + ('[1,2)', '[2018-03-03,2018-04-04)', 'one'), + ('[2,3)', '[2018-01-01,2018-01-05)', 'two'), + ('[3,4)', '[2018-01-01,)', 'three'), + ('[4,5)', '(,2018-04-01)', 'four'), + ('[5,6)', '(,)', 'five'), + ('[6,7)', '[2018-01-01,)', 'six'), + ('[7,8)', '(,2018-04-01)', 'seven'), + ('[8,9)', '[2018-01-02,2018-02-03)', 'eight'), + ('[8,9)', '[2018-02-03,2018-03-03)', 'eight'), + ('[8,9)', '[2018-03-03,2018-04-04)', 'eight') + ; +\set QUIET false +-- Deleting with a missing column fails +DELETE FROM for_portion_of_test + FOR PORTION OF invalid_at FROM '2018-06-01' TO NULL + WHERE id = '[5,6)'; +ERROR: column or period "invalid_at" of relation "for_portion_of_test" does not exist +LINE 2: FOR PORTION OF invalid_at FROM '2018-06-01' TO NULL + ^ +-- The wrong type fails +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM 1 TO 4 + WHERE id = '[3,4)'; +ERROR: function pg_catalog.daterange(integer, integer) does not exist +LINE 2: FOR PORTION OF valid_at FROM 1 TO 4 + ^ +DETAIL: No function of that name accepts the given argument types. +HINT: You might need to add explicit type casts. +-- Deleting with timestamps reversed fails +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-06-01' TO '2018-01-01' + WHERE id = '[3,4)'; +ERROR: range lower bound must be less than or equal to range upper bound +-- Deleting with a subquery fails +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM (SELECT '2018-01-01') TO '2018-06-01' + WHERE id = '[3,4)'; +ERROR: cannot use subquery in FOR PORTION OF expression +LINE 2: FOR PORTION OF valid_at FROM (SELECT '2018-01-01') TO '201... + ^ +-- Deleting with a column fails +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM lower(valid_at) TO NULL + WHERE id = '[3,4)'; +ERROR: cannot use column reference in FOR PORTION OF expression +LINE 2: FOR PORTION OF valid_at FROM lower(valid_at) TO NULL + ^ +-- Deleting with timestamps equal does nothing +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-04-01' TO '2018-04-01' + WHERE id = '[3,4)'; +DELETE 0 +-- Deleting a finite/open portion with a finite/open target +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-06-01' TO NULL + WHERE id = '[3,4)'; +DELETE 2 +-- Deleting a finite/open portion with an open/finite target +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO '2018-03-01' + WHERE id = '[6,7)'; +DELETE 2 +-- Deleting an open/finite portion with an open/finite target +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO '2018-02-01' + WHERE id = '[4,5)'; +DELETE 2 +-- Deleting an open/finite portion with a finite/open target +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2017-01-01' TO NULL + WHERE id = '[7,8)'; +DELETE 2 +-- Deleting a finite/finite portion with an exact fit +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-02-01' TO '2018-04-01' + WHERE id = '[4,5)'; +DELETE 1 +-- Deleting an enclosed span +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO NULL + WHERE id = '[2,3)'; +DELETE 1 +-- Deleting an open/open portion with a finite/finite target +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-01-01' TO '2019-01-01' + WHERE id = '[5,6)'; +DELETE 3 +-- Deleting an enclosed span with separate protruding spans +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-02-03' TO '2018-03-03' + WHERE id = '[1,2)'; +DELETE 1 +-- Deleting multiple enclosed spans +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO NULL + WHERE id = '[8,9)'; +DELETE 3 +-- Deleting with a direct target +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at (daterange('2018-03-10', '2018-03-17')) + WHERE id = '[1,2)'; +DELETE 3 +-- DELETE with no WHERE clause +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2030-01-01' TO NULL; +DELETE 4 +SELECT * FROM for_portion_of_test ORDER BY id, valid_at; + id | valid_at | name +-------+-------------------------+------- + [1,2) | [2018-01-02,2018-02-03) | one + [1,2) | [2018-03-03,2018-03-10) | one + [1,2) | [2018-03-17,2018-04-04) | one + [3,4) | [2018-01-01,2018-06-01) | three + [5,6) | (,2018-01-01) | five + [5,6) | [2019-01-01,2030-01-01) | five + [6,7) | [2018-03-01,2030-01-01) | six + [7,8) | (,2017-01-01) | seven +(8 rows) + +\set QUIET true +-- UPDATE ... RETURNING returns only the updated values (not the inserted side values) +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-02-01' TO '2018-02-15' + SET name = 'three^3' + WHERE id = '[3,4)' + RETURNING *; + id | valid_at | name +-------+-------------------------+--------- + [3,4) | [2018-02-01,2018-02-15) | three^3 +(1 row) + +-- DELETE ... RETURNING returns the deleted values (regardless of bounds) +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-02-02' TO '2018-02-03' + WHERE id = '[3,4)' + RETURNING *; + id | valid_at | name +-------+-------------------------+--------- + [3,4) | [2018-02-01,2018-02-15) | three^3 +(1 row) + +-- DELETE FOR PORTION OF in a PL/pgSQL function +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[10,11)', '[2018-01-01,2020-01-01)', 'ten'); +CREATE FUNCTION fpo_delete(_id int4range, _target_from date, _target_til date) +RETURNS void LANGUAGE plpgsql AS +$$ +BEGIN + DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM $2 TO $3 + WHERE id = $1; +END; +$$; +SELECT fpo_delete('[10,11)', '2015-01-01', '2019-01-01'); + fpo_delete +------------ + +(1 row) + +SELECT * FROM for_portion_of_test WHERE id = '[10,11)'; + id | valid_at | name +---------+-------------------------+------ + [10,11) | [2019-01-01,2020-01-01) | ten +(1 row) + +DELETE FROM for_portion_of_test WHERE id IN ('[10,11)'); +-- test that we run triggers on the UPDATE/DELETEd row and the INSERTed rows +CREATE FUNCTION dump_trigger() +RETURNS TRIGGER LANGUAGE plpgsql AS +$$ +BEGIN + RAISE NOTICE '%: % % %:', + TG_NAME, TG_WHEN, TG_OP, TG_LEVEL; + + IF TG_ARGV[0] THEN + RAISE NOTICE ' old: %', (SELECT string_agg(old_table::text, '\n ') FROM old_table); + ELSE + RAISE NOTICE ' old: %', OLD.valid_at; + END IF; + IF TG_ARGV[1] THEN + RAISE NOTICE ' new: %', (SELECT string_agg(new_table::text, '\n ') FROM new_table); + ELSE + RAISE NOTICE ' new: %', NEW.valid_at; + END IF; + + IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN + RETURN NEW; + ELSIF TG_OP = 'DELETE' THEN + RETURN OLD; + END IF; +END; +$$; +-- statement triggers: +CREATE TRIGGER fpo_before_stmt +BEFORE INSERT OR UPDATE OR DELETE ON for_portion_of_test +FOR EACH STATEMENT EXECUTE PROCEDURE dump_trigger(false, false); +CREATE TRIGGER fpo_after_insert_stmt +AFTER INSERT ON for_portion_of_test +FOR EACH STATEMENT EXECUTE PROCEDURE dump_trigger(false, false); +CREATE TRIGGER fpo_after_update_stmt +AFTER UPDATE ON for_portion_of_test +FOR EACH STATEMENT EXECUTE PROCEDURE dump_trigger(false, false); +CREATE TRIGGER fpo_after_delete_stmt +AFTER DELETE ON for_portion_of_test +FOR EACH STATEMENT EXECUTE PROCEDURE dump_trigger(false, false); +-- row triggers: +CREATE TRIGGER fpo_before_row +BEFORE INSERT OR UPDATE OR DELETE ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, false); +CREATE TRIGGER fpo_after_insert_row +AFTER INSERT ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, false); +CREATE TRIGGER fpo_after_update_row +AFTER UPDATE ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, false); +CREATE TRIGGER fpo_after_delete_row +AFTER DELETE ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, false); +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2021-01-01' TO '2022-01-01' + SET name = 'five^3' + WHERE id = '[5,6)'; +NOTICE: fpo_before_stmt: BEFORE UPDATE STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_before_row: BEFORE UPDATE ROW: +NOTICE: old: [2019-01-01,2030-01-01) +NOTICE: new: [2021-01-01,2022-01-01) +NOTICE: fpo_before_stmt: BEFORE INSERT STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_before_row: BEFORE INSERT ROW: +NOTICE: old: +NOTICE: new: [2019-01-01,2021-01-01) +NOTICE: fpo_after_insert_row: AFTER INSERT ROW: +NOTICE: old: +NOTICE: new: [2019-01-01,2021-01-01) +NOTICE: fpo_after_insert_stmt: AFTER INSERT STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_before_stmt: BEFORE INSERT STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_before_row: BEFORE INSERT ROW: +NOTICE: old: +NOTICE: new: [2022-01-01,2030-01-01) +NOTICE: fpo_after_insert_row: AFTER INSERT ROW: +NOTICE: old: +NOTICE: new: [2022-01-01,2030-01-01) +NOTICE: fpo_after_insert_stmt: AFTER INSERT STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_after_update_row: AFTER UPDATE ROW: +NOTICE: old: [2019-01-01,2030-01-01) +NOTICE: new: [2021-01-01,2022-01-01) +NOTICE: fpo_after_update_stmt: AFTER UPDATE STATEMENT: +NOTICE: old: +NOTICE: new: +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2023-01-01' TO '2024-01-01' + WHERE id = '[5,6)'; +NOTICE: fpo_before_stmt: BEFORE DELETE STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_before_row: BEFORE DELETE ROW: +NOTICE: old: [2022-01-01,2030-01-01) +NOTICE: new: +NOTICE: fpo_before_stmt: BEFORE INSERT STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_before_row: BEFORE INSERT ROW: +NOTICE: old: +NOTICE: new: [2022-01-01,2023-01-01) +NOTICE: fpo_after_insert_row: AFTER INSERT ROW: +NOTICE: old: +NOTICE: new: [2022-01-01,2023-01-01) +NOTICE: fpo_after_insert_stmt: AFTER INSERT STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_before_stmt: BEFORE INSERT STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_before_row: BEFORE INSERT ROW: +NOTICE: old: +NOTICE: new: [2024-01-01,2030-01-01) +NOTICE: fpo_after_insert_row: AFTER INSERT ROW: +NOTICE: old: +NOTICE: new: [2024-01-01,2030-01-01) +NOTICE: fpo_after_insert_stmt: AFTER INSERT STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_after_delete_row: AFTER DELETE ROW: +NOTICE: old: [2022-01-01,2030-01-01) +NOTICE: new: +NOTICE: fpo_after_delete_stmt: AFTER DELETE STATEMENT: +NOTICE: old: +NOTICE: new: +SELECT * FROM for_portion_of_test ORDER BY id, valid_at; + id | valid_at | name +-------+-------------------------+--------- + [1,2) | [2018-01-02,2018-02-03) | one + [1,2) | [2018-03-03,2018-03-10) | one + [1,2) | [2018-03-17,2018-04-04) | one + [3,4) | [2018-01-01,2018-02-01) | three + [3,4) | [2018-02-01,2018-02-02) | three^3 + [3,4) | [2018-02-03,2018-02-15) | three^3 + [3,4) | [2018-02-15,2018-06-01) | three + [5,6) | (,2018-01-01) | five + [5,6) | [2019-01-01,2021-01-01) | five + [5,6) | [2021-01-01,2022-01-01) | five^3 + [5,6) | [2022-01-01,2023-01-01) | five + [5,6) | [2024-01-01,2030-01-01) | five + [6,7) | [2018-03-01,2030-01-01) | six + [7,8) | (,2017-01-01) | seven +(14 rows) + +-- Triggers with a custom transition table name: +DROP TABLE for_portion_of_test; +CREATE TABLE for_portion_of_test ( + id int4range, + valid_at daterange, + name text +); +INSERT INTO for_portion_of_test VALUES ('[1,2)', '[2018-01-01,2020-01-01)', 'one'); +-- statement triggers: +CREATE TRIGGER fpo_before_stmt +BEFORE INSERT OR UPDATE OR DELETE ON for_portion_of_test +FOR EACH STATEMENT EXECUTE PROCEDURE dump_trigger(false, false); +CREATE TRIGGER fpo_after_insert_stmt +AFTER INSERT ON for_portion_of_test +REFERENCING NEW TABLE AS new_table +FOR EACH STATEMENT EXECUTE PROCEDURE dump_trigger(false, true); +CREATE TRIGGER fpo_after_update_stmt +AFTER UPDATE ON for_portion_of_test +REFERENCING NEW TABLE AS new_table OLD TABLE AS old_table +FOR EACH STATEMENT EXECUTE PROCEDURE dump_trigger(true, true); +CREATE TRIGGER fpo_after_delete_stmt +AFTER DELETE ON for_portion_of_test +REFERENCING OLD TABLE AS old_table +FOR EACH STATEMENT EXECUTE PROCEDURE dump_trigger(true, false); +-- row triggers: +CREATE TRIGGER fpo_before_row +BEFORE INSERT OR UPDATE OR DELETE ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, false); +CREATE TRIGGER fpo_after_insert_row +AFTER INSERT ON for_portion_of_test +REFERENCING NEW TABLE AS new_table +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, true); +CREATE TRIGGER fpo_after_update_row +AFTER UPDATE ON for_portion_of_test +REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(true, true); +CREATE TRIGGER fpo_after_delete_row +AFTER DELETE ON for_portion_of_test +REFERENCING OLD TABLE AS old_table +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(true, false); +BEGIN; +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-01-15' TO '2019-01-01' + SET name = '2018-01-15_to_2019-01-01'; +NOTICE: fpo_before_stmt: BEFORE UPDATE STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_before_row: BEFORE UPDATE ROW: +NOTICE: old: [2018-01-01,2020-01-01) +NOTICE: new: [2018-01-15,2019-01-01) +NOTICE: fpo_before_stmt: BEFORE INSERT STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_before_row: BEFORE INSERT ROW: +NOTICE: old: +NOTICE: new: [2018-01-01,2018-01-15) +NOTICE: fpo_after_insert_row: AFTER INSERT ROW: +NOTICE: old: +NOTICE: new: ("[1,2)","[2018-01-01,2018-01-15)",one) +NOTICE: fpo_after_insert_stmt: AFTER INSERT STATEMENT: +NOTICE: old: +NOTICE: new: ("[1,2)","[2018-01-01,2018-01-15)",one) +NOTICE: fpo_before_stmt: BEFORE INSERT STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_before_row: BEFORE INSERT ROW: +NOTICE: old: +NOTICE: new: [2019-01-01,2020-01-01) +NOTICE: fpo_after_insert_row: AFTER INSERT ROW: +NOTICE: old: +NOTICE: new: ("[1,2)","[2019-01-01,2020-01-01)",one) +NOTICE: fpo_after_insert_stmt: AFTER INSERT STATEMENT: +NOTICE: old: +NOTICE: new: ("[1,2)","[2019-01-01,2020-01-01)",one) +NOTICE: fpo_after_update_row: AFTER UPDATE ROW: +NOTICE: old: ("[1,2)","[2018-01-01,2020-01-01)",one) +NOTICE: new: ("[1,2)","[2018-01-15,2019-01-01)",2018-01-15_to_2019-01-01) +NOTICE: fpo_after_update_stmt: AFTER UPDATE STATEMENT: +NOTICE: old: ("[1,2)","[2018-01-01,2020-01-01)",one) +NOTICE: new: ("[1,2)","[2018-01-15,2019-01-01)",2018-01-15_to_2019-01-01) +ROLLBACK; +BEGIN; +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO '2018-01-21'; +NOTICE: fpo_before_stmt: BEFORE DELETE STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_before_row: BEFORE DELETE ROW: +NOTICE: old: [2018-01-01,2020-01-01) +NOTICE: new: +NOTICE: fpo_before_stmt: BEFORE INSERT STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_before_row: BEFORE INSERT ROW: +NOTICE: old: +NOTICE: new: [2018-01-21,2020-01-01) +NOTICE: fpo_after_insert_row: AFTER INSERT ROW: +NOTICE: old: +NOTICE: new: ("[1,2)","[2018-01-21,2020-01-01)",one) +NOTICE: fpo_after_insert_stmt: AFTER INSERT STATEMENT: +NOTICE: old: +NOTICE: new: ("[1,2)","[2018-01-21,2020-01-01)",one) +NOTICE: fpo_after_delete_row: AFTER DELETE ROW: +NOTICE: old: ("[1,2)","[2018-01-01,2020-01-01)",one) +NOTICE: new: +NOTICE: fpo_after_delete_stmt: AFTER DELETE STATEMENT: +NOTICE: old: ("[1,2)","[2018-01-01,2020-01-01)",one) +NOTICE: new: +ROLLBACK; +BEGIN; +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO '2018-01-02' + SET name = 'NULL_to_2018-01-01'; +NOTICE: fpo_before_stmt: BEFORE UPDATE STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_before_row: BEFORE UPDATE ROW: +NOTICE: old: [2018-01-01,2020-01-01) +NOTICE: new: [2018-01-01,2018-01-02) +NOTICE: fpo_before_stmt: BEFORE INSERT STATEMENT: +NOTICE: old: +NOTICE: new: +NOTICE: fpo_before_row: BEFORE INSERT ROW: +NOTICE: old: +NOTICE: new: [2018-01-02,2020-01-01) +NOTICE: fpo_after_insert_row: AFTER INSERT ROW: +NOTICE: old: +NOTICE: new: ("[1,2)","[2018-01-02,2020-01-01)",one) +NOTICE: fpo_after_insert_stmt: AFTER INSERT STATEMENT: +NOTICE: old: +NOTICE: new: ("[1,2)","[2018-01-02,2020-01-01)",one) +NOTICE: fpo_after_update_row: AFTER UPDATE ROW: +NOTICE: old: ("[1,2)","[2018-01-01,2020-01-01)",one) +NOTICE: new: ("[1,2)","[2018-01-01,2018-01-02)",NULL_to_2018-01-01) +NOTICE: fpo_after_update_stmt: AFTER UPDATE STATEMENT: +NOTICE: old: ("[1,2)","[2018-01-01,2020-01-01)",one) +NOTICE: new: ("[1,2)","[2018-01-01,2018-01-02)",NULL_to_2018-01-01) +ROLLBACK; +-- Deferred triggers +-- (must be CONSTRAINT triggers thus AFTER ROW with no transition tables) +DROP TABLE for_portion_of_test; +CREATE TABLE for_portion_of_test ( + id int4range, + valid_at daterange, + name text +); +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[1,2)', '[2018-01-01,2020-01-01)', 'one'); +CREATE CONSTRAINT TRIGGER fpo_after_insert_row +AFTER INSERT ON for_portion_of_test +DEFERRABLE INITIALLY DEFERRED +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, false); +CREATE CONSTRAINT TRIGGER fpo_after_update_row +AFTER UPDATE ON for_portion_of_test +DEFERRABLE INITIALLY DEFERRED +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, false); +CREATE CONSTRAINT TRIGGER fpo_after_delete_row +AFTER DELETE ON for_portion_of_test +DEFERRABLE INITIALLY DEFERRED +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, false); +BEGIN; +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-01-15' TO '2019-01-01' + SET name = '2018-01-15_to_2019-01-01'; +COMMIT; +NOTICE: fpo_after_insert_row: AFTER INSERT ROW: +NOTICE: old: +NOTICE: new: [2018-01-01,2018-01-15) +NOTICE: fpo_after_insert_row: AFTER INSERT ROW: +NOTICE: old: +NOTICE: new: [2019-01-01,2020-01-01) +NOTICE: fpo_after_update_row: AFTER UPDATE ROW: +NOTICE: old: [2018-01-01,2020-01-01) +NOTICE: new: [2018-01-15,2019-01-01) +BEGIN; +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO '2018-01-21'; +COMMIT; +NOTICE: fpo_after_insert_row: AFTER INSERT ROW: +NOTICE: old: +NOTICE: new: [2018-01-21,2019-01-01) +NOTICE: fpo_after_delete_row: AFTER DELETE ROW: +NOTICE: old: [2018-01-15,2019-01-01) +NOTICE: new: +NOTICE: fpo_after_delete_row: AFTER DELETE ROW: +NOTICE: old: [2018-01-01,2018-01-15) +NOTICE: new: +BEGIN; +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO '2018-01-02' + SET name = 'NULL_to_2018-01-01'; +COMMIT; +SELECT * FROM for_portion_of_test; + id | valid_at | name +-------+-------------------------+-------------------------- + [1,2) | [2019-01-01,2020-01-01) | one + [1,2) | [2018-01-21,2019-01-01) | 2018-01-15_to_2019-01-01 +(2 rows) + +-- test FOR PORTION OF from triggers during FOR PORTION OF: +DROP TABLE for_portion_of_test; +CREATE TABLE for_portion_of_test ( + id int4range, + valid_at daterange, + name text +); +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[1,2)', '[2018-01-01,2020-01-01)', 'one'), + ('[2,3)', '[2018-01-01,2020-01-01)', 'two'), + ('[3,4)', '[2018-01-01,2020-01-01)', 'three'), + ('[4,5)', '[2018-01-01,2020-01-01)', 'four'); +CREATE FUNCTION trg_fpo_update() +RETURNS TRIGGER LANGUAGE plpgsql AS +$$ +BEGIN + IF pg_trigger_depth() = 1 THEN + UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-02-01' TO '2018-03-01' + SET name = CONCAT(name, '^') + WHERE id = OLD.id; + END IF; + RETURN CASE WHEN 'TG_OP' = 'DELETE' THEN OLD ELSE NEW END; +END; +$$; +CREATE FUNCTION trg_fpo_delete() +RETURNS TRIGGER LANGUAGE plpgsql AS +$$ +BEGIN + IF pg_trigger_depth() = 1 THEN + DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-03-01' TO '2018-04-01' + WHERE id = OLD.id; + END IF; + RETURN CASE WHEN 'TG_OP' = 'DELETE' THEN OLD ELSE NEW END; +END; +$$; +-- UPDATE FOR PORTION OF from a trigger fired by UPDATE FOR PORTION OF +CREATE TRIGGER fpo_after_update_row +AFTER UPDATE ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE trg_fpo_update(); +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-05-01' TO '2018-06-01' + SET name = CONCAT(name, '*') + WHERE id = '[1,2)'; +SELECT * FROM for_portion_of_test WHERE id = '[1,2)' ORDER BY id, valid_at; + id | valid_at | name +-------+-------------------------+------ + [1,2) | [2018-01-01,2018-02-01) | one + [1,2) | [2018-02-01,2018-03-01) | one^ + [1,2) | [2018-03-01,2018-05-01) | one + [1,2) | [2018-05-01,2018-06-01) | one* + [1,2) | [2018-06-01,2020-01-01) | one +(5 rows) + +DROP TRIGGER fpo_after_update_row ON for_portion_of_test; +-- UPDATE FOR PORTION OF from a trigger fired by DELETE FOR PORTION OF +CREATE TRIGGER fpo_after_delete_row +AFTER DELETE ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE trg_fpo_update(); +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-05-01' TO '2018-06-01' + WHERE id = '[2,3)'; +SELECT * FROM for_portion_of_test WHERE id = '[2,3)' ORDER BY id, valid_at; + id | valid_at | name +-------+-------------------------+------ + [2,3) | [2018-01-01,2018-02-01) | two + [2,3) | [2018-02-01,2018-03-01) | two^ + [2,3) | [2018-03-01,2018-05-01) | two + [2,3) | [2018-06-01,2020-01-01) | two +(4 rows) + +DROP TRIGGER fpo_after_delete_row ON for_portion_of_test; +-- DELETE FOR PORTION OF from a trigger fired by UPDATE FOR PORTION OF +CREATE TRIGGER fpo_after_update_row +AFTER UPDATE ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE trg_fpo_delete(); +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-05-01' TO '2018-06-01' + SET name = CONCAT(name, '*') + WHERE id = '[3,4)'; +SELECT * FROM for_portion_of_test WHERE id = '[3,4)' ORDER BY id, valid_at; + id | valid_at | name +-------+-------------------------+-------- + [3,4) | [2018-01-01,2018-03-01) | three + [3,4) | [2018-04-01,2018-05-01) | three + [3,4) | [2018-05-01,2018-06-01) | three* + [3,4) | [2018-06-01,2020-01-01) | three +(4 rows) + +DROP TRIGGER fpo_after_update_row ON for_portion_of_test; +-- DELETE FOR PORTION OF from a trigger fired by DELETE FOR PORTION OF +CREATE TRIGGER fpo_after_delete_row +AFTER DELETE ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE trg_fpo_delete(); +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-05-01' TO '2018-06-01' + WHERE id = '[4,5)'; +SELECT * FROM for_portion_of_test WHERE id = '[4,5)' ORDER BY id, valid_at; + id | valid_at | name +-------+-------------------------+------ + [4,5) | [2018-01-01,2018-03-01) | four + [4,5) | [2018-04-01,2018-05-01) | four + [4,5) | [2018-06-01,2020-01-01) | four +(3 rows) + +DROP TRIGGER fpo_after_delete_row ON for_portion_of_test; +-- Test with multiranges +CREATE TABLE for_portion_of_test2 ( + id int4range NOT NULL, + valid_at datemultirange NOT NULL, + name text NOT NULL, + CONSTRAINT for_portion_of_test2_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +INSERT INTO for_portion_of_test2 (id, valid_at, name) VALUES + ('[1,2)', datemultirange(daterange('2018-01-02', '2018-02-03)'), daterange('2018-02-04', '2018-03-03')), 'one'), + ('[1,2)', datemultirange(daterange('2018-03-03', '2018-04-04)')), 'one'), + ('[2,3)', datemultirange(daterange('2018-01-01', '2018-05-01)')), 'two'), + ('[3,4)', datemultirange(daterange('2018-01-01', null)), 'three'); + ; +UPDATE for_portion_of_test2 + FOR PORTION OF valid_at (datemultirange(daterange('2018-01-10', '2018-02-10'), daterange('2018-03-05', '2018-05-01'))) + SET name = 'one^1' + WHERE id = '[1,2)'; +DELETE FROM for_portion_of_test2 + FOR PORTION OF valid_at (datemultirange(daterange('2018-01-15', '2018-02-15'), daterange('2018-03-01', '2018-03-15'))) + WHERE id = '[2,3)'; +SELECT * FROM for_portion_of_test2 ORDER BY id, valid_at; + id | valid_at | name +-------+---------------------------------------------------------------------------+------- + [1,2) | {[2018-01-02,2018-01-10),[2018-02-10,2018-03-03)} | one + [1,2) | {[2018-01-10,2018-02-03),[2018-02-04,2018-02-10)} | one^1 + [1,2) | {[2018-03-03,2018-03-05)} | one + [1,2) | {[2018-03-05,2018-04-04)} | one^1 + [2,3) | {[2018-01-01,2018-01-15),[2018-02-15,2018-03-01),[2018-03-15,2018-05-01)} | two + [3,4) | {[2018-01-01,)} | three +(6 rows) + +DROP TABLE for_portion_of_test2; +-- Test with a custom range type +CREATE TYPE mydaterange AS range(subtype=date); +CREATE TABLE for_portion_of_test2 ( + id int4range NOT NULL, + valid_at mydaterange NOT NULL, + name text NOT NULL, + CONSTRAINT for_portion_of_test2_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +INSERT INTO for_portion_of_test2 (id, valid_at, name) VALUES + ('[1,2)', '[2018-01-02,2018-02-03)', 'one'), + ('[1,2)', '[2018-02-03,2018-03-03)', 'one'), + ('[1,2)', '[2018-03-03,2018-04-04)', 'one'), + ('[2,3)', '[2018-01-01,2018-05-01)', 'two'), + ('[3,4)', '[2018-01-01,)', 'three'); + ; +UPDATE for_portion_of_test2 + FOR PORTION OF valid_at FROM '2018-01-10' TO '2018-02-10' + SET name = 'one^1' + WHERE id = '[1,2)'; +DELETE FROM for_portion_of_test2 + FOR PORTION OF valid_at FROM '2018-01-15' TO '2018-02-15' + WHERE id = '[2,3)'; +SELECT * FROM for_portion_of_test2 ORDER BY id, valid_at; + id | valid_at | name +-------+-------------------------+------- + [1,2) | [2018-01-02,2018-01-10) | one + [1,2) | [2018-01-10,2018-02-03) | one^1 + [1,2) | [2018-02-03,2018-02-10) | one^1 + [1,2) | [2018-02-10,2018-03-03) | one + [1,2) | [2018-03-03,2018-04-04) | one + [2,3) | [2018-01-01,2018-01-15) | two + [2,3) | [2018-02-15,2018-05-01) | two + [3,4) | [2018-01-01,) | three +(8 rows) + +DROP TABLE for_portion_of_test2; +DROP TYPE mydaterange; +-- Test FOR PORTION OF against a partitioned table. +-- temporal_partitioned_1 has the same attnums as the root +-- temporal_partitioned_3 has the different attnums from the root +-- temporal_partitioned_5 has the different attnums too, but reversed +CREATE TABLE temporal_partitioned ( + id int4range, + valid_at daterange, + name text, + CONSTRAINT temporal_paritioned_uq UNIQUE (id, valid_at WITHOUT OVERLAPS) +) PARTITION BY LIST (id); +CREATE TABLE temporal_partitioned_1 PARTITION OF temporal_partitioned FOR VALUES IN ('[1,2)', '[2,3)'); +CREATE TABLE temporal_partitioned_3 PARTITION OF temporal_partitioned FOR VALUES IN ('[3,4)', '[4,5)'); +CREATE TABLE temporal_partitioned_5 PARTITION OF temporal_partitioned FOR VALUES IN ('[5,6)', '[6,7)'); +ALTER TABLE temporal_partitioned DETACH PARTITION temporal_partitioned_3; +ALTER TABLE temporal_partitioned_3 DROP COLUMN id, DROP COLUMN valid_at; +ALTER TABLE temporal_partitioned_3 ADD COLUMN id int4range NOT NULL, ADD COLUMN valid_at daterange NOT NULL; +ALTER TABLE temporal_partitioned ATTACH PARTITION temporal_partitioned_3 FOR VALUES IN ('[3,4)', '[4,5)'); +ALTER TABLE temporal_partitioned DETACH PARTITION temporal_partitioned_5; +ALTER TABLE temporal_partitioned_5 DROP COLUMN id, DROP COLUMN valid_at; +ALTER TABLE temporal_partitioned_5 ADD COLUMN valid_at daterange NOT NULL, ADD COLUMN id int4range NOT NULL; +ALTER TABLE temporal_partitioned ATTACH PARTITION temporal_partitioned_5 FOR VALUES IN ('[5,6)', '[6,7)'); +INSERT INTO temporal_partitioned (id, valid_at, name) VALUES + ('[1,2)', daterange('2000-01-01', '2010-01-01'), 'one'), + ('[3,4)', daterange('2000-01-01', '2010-01-01'), 'three'), + ('[5,6)', daterange('2000-01-01', '2010-01-01'), 'five'); +SELECT * FROM temporal_partitioned; + id | valid_at | name +-------+-------------------------+------- + [1,2) | [2000-01-01,2010-01-01) | one + [3,4) | [2000-01-01,2010-01-01) | three + [5,6) | [2000-01-01,2010-01-01) | five +(3 rows) + +-- Update without moving within partition 1 +UPDATE temporal_partitioned FOR PORTION OF valid_at FROM '2000-03-01' TO '2000-04-01' + SET name = 'one^1' + WHERE id = '[1,2)'; +-- Update without moving within partition 3 +UPDATE temporal_partitioned FOR PORTION OF valid_at FROM '2000-03-01' TO '2000-04-01' + SET name = 'three^1' + WHERE id = '[3,4)'; +-- Update without moving within partition 5 +UPDATE temporal_partitioned FOR PORTION OF valid_at FROM '2000-03-01' TO '2000-04-01' + SET name = 'five^1' + WHERE id = '[5,6)'; +-- Move from partition 1 to partition 3 +UPDATE temporal_partitioned FOR PORTION OF valid_at FROM '2000-06-01' TO '2000-07-01' + SET name = 'one^2', + id = '[4,5)' + WHERE id = '[1,2)'; +-- Move from partition 3 to partition 1 +UPDATE temporal_partitioned FOR PORTION OF valid_at FROM '2000-06-01' TO '2000-07-01' + SET name = 'three^2', + id = '[2,3)' + WHERE id = '[3,4)'; +-- Move from partition 5 to partition 3 +UPDATE temporal_partitioned FOR PORTION OF valid_at FROM '2000-06-01' TO '2000-07-01' + SET name = 'five^2', + id = '[3,4)' + WHERE id = '[5,6)'; +-- Update all partitions at once (each with leftovers) +SELECT * FROM temporal_partitioned ORDER BY id, valid_at; + id | valid_at | name +-------+-------------------------+--------- + [1,2) | [2000-01-01,2000-03-01) | one + [1,2) | [2000-03-01,2000-04-01) | one^1 + [1,2) | [2000-04-01,2000-06-01) | one + [1,2) | [2000-07-01,2010-01-01) | one + [2,3) | [2000-06-01,2000-07-01) | three^2 + [3,4) | [2000-01-01,2000-03-01) | three + [3,4) | [2000-03-01,2000-04-01) | three^1 + [3,4) | [2000-04-01,2000-06-01) | three + [3,4) | [2000-06-01,2000-07-01) | five^2 + [3,4) | [2000-07-01,2010-01-01) | three + [4,5) | [2000-06-01,2000-07-01) | one^2 + [5,6) | [2000-01-01,2000-03-01) | five + [5,6) | [2000-03-01,2000-04-01) | five^1 + [5,6) | [2000-04-01,2000-06-01) | five + [5,6) | [2000-07-01,2010-01-01) | five +(15 rows) + +SELECT * FROM temporal_partitioned_1 ORDER BY id, valid_at; + id | valid_at | name +-------+-------------------------+--------- + [1,2) | [2000-01-01,2000-03-01) | one + [1,2) | [2000-03-01,2000-04-01) | one^1 + [1,2) | [2000-04-01,2000-06-01) | one + [1,2) | [2000-07-01,2010-01-01) | one + [2,3) | [2000-06-01,2000-07-01) | three^2 +(5 rows) + +SELECT * FROM temporal_partitioned_3 ORDER BY id, valid_at; + name | id | valid_at +---------+-------+------------------------- + three | [3,4) | [2000-01-01,2000-03-01) + three^1 | [3,4) | [2000-03-01,2000-04-01) + three | [3,4) | [2000-04-01,2000-06-01) + five^2 | [3,4) | [2000-06-01,2000-07-01) + three | [3,4) | [2000-07-01,2010-01-01) + one^2 | [4,5) | [2000-06-01,2000-07-01) +(6 rows) + +SELECT * FROM temporal_partitioned_5 ORDER BY id, valid_at; + name | valid_at | id +--------+-------------------------+------- + five | [2000-01-01,2000-03-01) | [5,6) + five^1 | [2000-03-01,2000-04-01) | [5,6) + five | [2000-04-01,2000-06-01) | [5,6) + five | [2000-07-01,2010-01-01) | [5,6) +(4 rows) + +DROP TABLE temporal_partitioned; +RESET datestyle; diff --git a/src/test/regress/expected/privileges.out b/src/test/regress/expected/privileges.out index daafaa94fdec..9ff8e7fb363d 100644 --- a/src/test/regress/expected/privileges.out +++ b/src/test/regress/expected/privileges.out @@ -1119,6 +1119,24 @@ ERROR: null value in column "b" of relation "errtst_part_2" violates not-null c DETAIL: Failing row contains (a, b, c) = (aaaa, null, ccc). SET SESSION AUTHORIZATION regress_priv_user1; DROP TABLE errtst; +-- test column-level privileges on the range used in FOR PORTION OF +SET SESSION AUTHORIZATION regress_priv_user1; +CREATE TABLE t1 ( + c1 int4range, + valid_at tsrange, + CONSTRAINT t1pk PRIMARY KEY (c1, valid_at WITHOUT OVERLAPS) +); +GRANT SELECT ON t1 TO regress_priv_user2; +GRANT SELECT ON t1 TO regress_priv_user3; +GRANT UPDATE (c1) ON t1 TO regress_priv_user2; +GRANT UPDATE (c1, valid_at) ON t1 TO regress_priv_user3; +SET SESSION AUTHORIZATION regress_priv_user2; +UPDATE t1 FOR PORTION OF valid_at FROM '2000-01-01' TO '2001-01-01' SET c1 = '[2,3)'; +ERROR: permission denied for table t1 +SET SESSION AUTHORIZATION regress_priv_user3; +UPDATE t1 FOR PORTION OF valid_at FROM '2000-01-01' TO '2001-01-01' SET c1 = '[2,3)'; +SET SESSION AUTHORIZATION regress_priv_user1; +DROP TABLE t1; -- test column-level privileges when involved with DELETE SET SESSION AUTHORIZATION regress_priv_user1; ALTER TABLE atest6 ADD COLUMN three integer; diff --git a/src/test/regress/expected/updatable_views.out b/src/test/regress/expected/updatable_views.out index 03df7e75b7b6..4fb928d561d3 100644 --- a/src/test/regress/expected/updatable_views.out +++ b/src/test/regress/expected/updatable_views.out @@ -3700,6 +3700,38 @@ select * from uv_iocu_tab; drop view uv_iocu_view; drop table uv_iocu_tab; +-- Check UPDATE FOR PORTION OF works correctly +create table uv_fpo_tab (id int4range, valid_at tsrange, b float, + constraint pk_uv_fpo_tab primary key (id, valid_at without overlaps)); +insert into uv_fpo_tab values ('[1,1]', '[2020-01-01, 2030-01-01)', 0); +create view uv_fpo_view as + select b, b+1 as c, valid_at, id, '2.0'::text as two from uv_fpo_tab; +insert into uv_fpo_view (id, valid_at, b) values ('[1,1]', '[2010-01-01, 2020-01-01)', 1); +select * from uv_fpo_view; + b | c | valid_at | id | two +---+---+---------------------------------------------------------+-------+----- + 0 | 1 | ["Wed Jan 01 00:00:00 2020","Tue Jan 01 00:00:00 2030") | [1,2) | 2.0 + 1 | 2 | ["Fri Jan 01 00:00:00 2010","Wed Jan 01 00:00:00 2020") | [1,2) | 2.0 +(2 rows) + +update uv_fpo_view for portion of valid_at from '2015-01-01' to '2020-01-01' set b = 2 where id = '[1,1]'; +select * from uv_fpo_view; + b | c | valid_at | id | two +---+---+---------------------------------------------------------+-------+----- + 0 | 1 | ["Wed Jan 01 00:00:00 2020","Tue Jan 01 00:00:00 2030") | [1,2) | 2.0 + 2 | 3 | ["Thu Jan 01 00:00:00 2015","Wed Jan 01 00:00:00 2020") | [1,2) | 2.0 + 1 | 2 | ["Fri Jan 01 00:00:00 2010","Thu Jan 01 00:00:00 2015") | [1,2) | 2.0 +(3 rows) + +delete from uv_fpo_view for portion of valid_at from '2017-01-01' to '2022-01-01' where id = '[1,1]'; +select * from uv_fpo_view; + b | c | valid_at | id | two +---+---+---------------------------------------------------------+-------+----- + 1 | 2 | ["Fri Jan 01 00:00:00 2010","Thu Jan 01 00:00:00 2015") | [1,2) | 2.0 + 0 | 1 | ["Sat Jan 01 00:00:00 2022","Tue Jan 01 00:00:00 2030") | [1,2) | 2.0 + 2 | 3 | ["Thu Jan 01 00:00:00 2015","Sun Jan 01 00:00:00 2017") | [1,2) | 2.0 +(3 rows) + -- Test whole-row references to the view create table uv_iocu_tab (a int unique, b text); create view uv_iocu_view as diff --git a/src/test/regress/expected/without_overlaps.out b/src/test/regress/expected/without_overlaps.out index f3144bdc39c2..401550b5482d 100644 --- a/src/test/regress/expected/without_overlaps.out +++ b/src/test/regress/expected/without_overlaps.out @@ -2,7 +2,7 @@ -- -- We leave behind several tables to test pg_dump etc: -- temporal_rng, temporal_rng2, --- temporal_fk_rng2rng. +-- temporal_fk_rng2rng, temporal_fk2_rng2rng. SET datestyle TO ISO, YMD; -- -- test input parser @@ -889,6 +889,36 @@ INSERT INTO temporal3 (id, valid_at, id2, name) ('[1,2)', daterange('2000-01-01', '2010-01-01'), '[7,8)', 'foo'), ('[2,3)', daterange('2000-01-01', '2010-01-01'), '[9,10)', 'bar') ; +UPDATE temporal3 FOR PORTION OF valid_at FROM '2000-05-01' TO '2000-07-01' + SET name = name || '1'; +UPDATE temporal3 FOR PORTION OF valid_at FROM '2000-04-01' TO '2000-06-01' + SET name = name || '2' + WHERE id = '[2,3)'; +SELECT * FROM temporal3 ORDER BY id, valid_at; + id | valid_at | id2 | name +-------+-------------------------+--------+------- + [1,2) | [2000-01-01,2000-05-01) | [7,8) | foo + [1,2) | [2000-05-01,2000-07-01) | [7,8) | foo1 + [1,2) | [2000-07-01,2010-01-01) | [7,8) | foo + [2,3) | [2000-01-01,2000-04-01) | [9,10) | bar + [2,3) | [2000-04-01,2000-05-01) | [9,10) | bar2 + [2,3) | [2000-05-01,2000-06-01) | [9,10) | bar12 + [2,3) | [2000-06-01,2000-07-01) | [9,10) | bar1 + [2,3) | [2000-07-01,2010-01-01) | [9,10) | bar +(8 rows) + +-- conflicting id only: +INSERT INTO temporal3 (id, valid_at, id2, name) + VALUES + ('[1,2)', daterange('2005-01-01', '2006-01-01'), '[8,9)', 'foo3'); +ERROR: conflicting key value violates exclusion constraint "temporal3_pk" +DETAIL: Key (id, valid_at)=([1,2), [2005-01-01,2006-01-01)) conflicts with existing key (id, valid_at)=([1,2), [2000-07-01,2010-01-01)). +-- conflicting id2 only: +INSERT INTO temporal3 (id, valid_at, id2, name) + VALUES + ('[3,4)', daterange('2005-01-01', '2010-01-01'), '[9,10)', 'bar3'); +ERROR: conflicting key value violates exclusion constraint "temporal3_uniq" +DETAIL: Key (id2, valid_at)=([9,10), [2005-01-01,2010-01-01)) conflicts with existing key (id2, valid_at)=([9,10), [2000-07-01,2010-01-01)). DROP TABLE temporal3; -- -- test changing the PK's dependencies @@ -920,26 +950,43 @@ INSERT INTO temporal_partitioned (id, valid_at, name) VALUES ('[1,2)', daterange('2000-01-01', '2000-02-01'), 'one'), ('[1,2)', daterange('2000-02-01', '2000-03-01'), 'one'), ('[3,4)', daterange('2000-01-01', '2010-01-01'), 'three'); -SELECT * FROM temporal_partitioned ORDER BY id, valid_at; - id | valid_at | name --------+-------------------------+------- - [1,2) | [2000-01-01,2000-02-01) | one - [1,2) | [2000-02-01,2000-03-01) | one - [3,4) | [2000-01-01,2010-01-01) | three +SELECT tableoid::regclass, * FROM temporal_partitioned ORDER BY id, valid_at; + tableoid | id | valid_at | name +----------+-------+-------------------------+------- + tp1 | [1,2) | [2000-01-01,2000-02-01) | one + tp1 | [1,2) | [2000-02-01,2000-03-01) | one + tp2 | [3,4) | [2000-01-01,2010-01-01) | three (3 rows) -SELECT * FROM tp1 ORDER BY id, valid_at; - id | valid_at | name --------+-------------------------+------ - [1,2) | [2000-01-01,2000-02-01) | one - [1,2) | [2000-02-01,2000-03-01) | one -(2 rows) - -SELECT * FROM tp2 ORDER BY id, valid_at; - id | valid_at | name --------+-------------------------+------- - [3,4) | [2000-01-01,2010-01-01) | three -(1 row) +UPDATE temporal_partitioned + FOR PORTION OF valid_at FROM '2000-01-15' TO '2000-02-15' + SET name = 'one2' + WHERE id = '[1,2)'; +UPDATE temporal_partitioned + FOR PORTION OF valid_at FROM '2000-02-20' TO '2000-02-25' + SET id = '[4,5)' + WHERE name = 'one'; +UPDATE temporal_partitioned + FOR PORTION OF valid_at FROM '2002-01-01' TO '2003-01-01' + SET id = '[2,3)' + WHERE name = 'three'; +DELETE FROM temporal_partitioned + FOR PORTION OF valid_at FROM '2000-01-15' TO '2000-02-15' + WHERE id = '[3,4)'; +SELECT tableoid::regclass, * FROM temporal_partitioned ORDER BY id, valid_at; + tableoid | id | valid_at | name +----------+-------+-------------------------+------- + tp1 | [1,2) | [2000-01-01,2000-01-15) | one + tp1 | [1,2) | [2000-01-15,2000-02-01) | one2 + tp1 | [1,2) | [2000-02-01,2000-02-15) | one2 + tp1 | [1,2) | [2000-02-15,2000-02-20) | one + tp1 | [1,2) | [2000-02-25,2000-03-01) | one + tp1 | [2,3) | [2002-01-01,2003-01-01) | three + tp2 | [3,4) | [2000-01-01,2000-01-15) | three + tp2 | [3,4) | [2000-02-15,2002-01-01) | three + tp2 | [3,4) | [2003-01-01,2010-01-01) | three + tp2 | [4,5) | [2000-02-20,2000-02-25) | one +(10 rows) DROP TABLE temporal_partitioned; -- temporal UNIQUE: @@ -955,26 +1002,43 @@ INSERT INTO temporal_partitioned (id, valid_at, name) VALUES ('[1,2)', daterange('2000-01-01', '2000-02-01'), 'one'), ('[1,2)', daterange('2000-02-01', '2000-03-01'), 'one'), ('[3,4)', daterange('2000-01-01', '2010-01-01'), 'three'); -SELECT * FROM temporal_partitioned ORDER BY id, valid_at; - id | valid_at | name --------+-------------------------+------- - [1,2) | [2000-01-01,2000-02-01) | one - [1,2) | [2000-02-01,2000-03-01) | one - [3,4) | [2000-01-01,2010-01-01) | three +SELECT tableoid::regclass, * FROM temporal_partitioned ORDER BY id, valid_at; + tableoid | id | valid_at | name +----------+-------+-------------------------+------- + tp1 | [1,2) | [2000-01-01,2000-02-01) | one + tp1 | [1,2) | [2000-02-01,2000-03-01) | one + tp2 | [3,4) | [2000-01-01,2010-01-01) | three (3 rows) -SELECT * FROM tp1 ORDER BY id, valid_at; - id | valid_at | name --------+-------------------------+------ - [1,2) | [2000-01-01,2000-02-01) | one - [1,2) | [2000-02-01,2000-03-01) | one -(2 rows) - -SELECT * FROM tp2 ORDER BY id, valid_at; - id | valid_at | name --------+-------------------------+------- - [3,4) | [2000-01-01,2010-01-01) | three -(1 row) +UPDATE temporal_partitioned + FOR PORTION OF valid_at FROM '2000-01-15' TO '2000-02-15' + SET name = 'one2' + WHERE id = '[1,2)'; +UPDATE temporal_partitioned + FOR PORTION OF valid_at FROM '2000-02-20' TO '2000-02-25' + SET id = '[4,5)' + WHERE name = 'one'; +UPDATE temporal_partitioned + FOR PORTION OF valid_at FROM '2002-01-01' TO '2003-01-01' + SET id = '[2,3)' + WHERE name = 'three'; +DELETE FROM temporal_partitioned + FOR PORTION OF valid_at FROM '2000-01-15' TO '2000-02-15' + WHERE id = '[3,4)'; +SELECT tableoid::regclass, * FROM temporal_partitioned ORDER BY id, valid_at; + tableoid | id | valid_at | name +----------+-------+-------------------------+------- + tp1 | [1,2) | [2000-01-01,2000-01-15) | one + tp1 | [1,2) | [2000-01-15,2000-02-01) | one2 + tp1 | [1,2) | [2000-02-01,2000-02-15) | one2 + tp1 | [1,2) | [2000-02-15,2000-02-20) | one + tp1 | [1,2) | [2000-02-25,2000-03-01) | one + tp1 | [2,3) | [2002-01-01,2003-01-01) | three + tp2 | [3,4) | [2000-01-01,2000-01-15) | three + tp2 | [3,4) | [2000-02-15,2002-01-01) | three + tp2 | [3,4) | [2003-01-01,2010-01-01) | three + tp2 | [4,5) | [2000-02-20,2000-02-25) | one +(10 rows) DROP TABLE temporal_partitioned; -- ALTER TABLE REPLICA IDENTITY @@ -1755,6 +1819,33 @@ UPDATE temporal_rng SET id = '[7,8)' WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); ERROR: update or delete on table "temporal_rng" violates foreign key constraint "temporal_fk_rng2rng_fk" on table "temporal_fk_rng2rng" DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_rng2rng". +-- changing an unreferenced part is okay: +UPDATE temporal_rng + FOR PORTION OF valid_at FROM '2018-01-02' TO '2018-01-03' + SET id = '[7,8)' + WHERE id = '[5,6)'; +-- changing just a part fails: +UPDATE temporal_rng + FOR PORTION OF valid_at FROM '2018-01-05' TO '2018-01-10' + SET id = '[7,8)' + WHERE id = '[5,6)'; +ERROR: update or delete on table "temporal_rng" violates foreign key constraint "temporal_fk_rng2rng_fk" on table "temporal_fk_rng2rng" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-03,2018-02-01)) is still referenced from table "temporal_fk_rng2rng". +SELECT * FROM temporal_rng WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; + id | valid_at +-------+------------------------- + [5,6) | [2016-02-01,2016-03-01) + [5,6) | [2018-01-01,2018-01-02) + [5,6) | [2018-01-03,2018-02-01) + [7,8) | [2018-01-02,2018-01-03) +(4 rows) + +SELECT * FROM temporal_fk_rng2rng WHERE id in ('[3,4)') ORDER BY id, valid_at; + id | valid_at | parent_id +-------+-------------------------+----------- + [3,4) | [2018-01-05,2018-01-10) | [5,6) +(1 row) + -- then delete the objecting FK record and the same PK update succeeds: DELETE FROM temporal_fk_rng2rng WHERE id = '[3,4)'; UPDATE temporal_rng SET valid_at = daterange('2016-01-01', '2016-02-01') @@ -1802,6 +1893,42 @@ BEGIN; COMMIT; ERROR: update or delete on table "temporal_rng" violates foreign key constraint "temporal_fk_rng2rng_fk" on table "temporal_fk_rng2rng" DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_rng2rng". +-- deleting an unreferenced part is okay: +DELETE FROM temporal_rng +FOR PORTION OF valid_at FROM '2018-01-02' TO '2018-01-03' +WHERE id = '[5,6)'; +SELECT * FROM temporal_rng WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; + id | valid_at +-------+------------------------- + [5,6) | [2018-01-01,2018-01-02) + [5,6) | [2018-01-03,2018-02-01) +(2 rows) + +SELECT * FROM temporal_fk_rng2rng WHERE id in ('[3,4)') ORDER BY id, valid_at; + id | valid_at | parent_id +-------+-------------------------+----------- + [3,4) | [2018-01-05,2018-01-10) | [5,6) +(1 row) + +-- deleting just a part fails: +DELETE FROM temporal_rng +FOR PORTION OF valid_at FROM '2018-01-05' TO '2018-01-10' +WHERE id = '[5,6)'; +ERROR: update or delete on table "temporal_rng" violates foreign key constraint "temporal_fk_rng2rng_fk" on table "temporal_fk_rng2rng" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-03,2018-02-01)) is still referenced from table "temporal_fk_rng2rng". +SELECT * FROM temporal_rng WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; + id | valid_at +-------+------------------------- + [5,6) | [2018-01-01,2018-01-02) + [5,6) | [2018-01-03,2018-02-01) +(2 rows) + +SELECT * FROM temporal_fk_rng2rng WHERE id in ('[3,4)') ORDER BY id, valid_at; + id | valid_at | parent_id +-------+-------------------------+----------- + [3,4) | [2018-01-05,2018-01-10) | [5,6) +(1 row) + -- then delete the objecting FK record and the same PK delete succeeds: DELETE FROM temporal_fk_rng2rng WHERE id = '[3,4)'; DELETE FROM temporal_rng WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); @@ -1818,11 +1945,12 @@ ALTER TABLE temporal_fk_rng2rng ON DELETE RESTRICT; ERROR: unsupported ON DELETE action for foreign key constraint using PERIOD -- --- test ON UPDATE/DELETE options +-- rng2rng test ON UPDATE/DELETE options -- -- test FK referenced updates CASCADE +TRUNCATE temporal_rng, temporal_fk_rng2rng; INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); -INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[4,5)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); ALTER TABLE temporal_fk_rng2rng ADD CONSTRAINT temporal_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) @@ -1830,8 +1958,9 @@ ALTER TABLE temporal_fk_rng2rng ON DELETE CASCADE ON UPDATE CASCADE; ERROR: unsupported ON UPDATE action for foreign key constraint using PERIOD -- test FK referenced updates SET NULL -INSERT INTO temporal_rng (id, valid_at) VALUES ('[9,10)', daterange('2018-01-01', '2021-01-01')); -INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01'), '[9,10)'); +TRUNCATE temporal_rng, temporal_fk_rng2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); ALTER TABLE temporal_fk_rng2rng ADD CONSTRAINT temporal_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) @@ -1839,9 +1968,10 @@ ALTER TABLE temporal_fk_rng2rng ON DELETE SET NULL ON UPDATE SET NULL; ERROR: unsupported ON UPDATE action for foreign key constraint using PERIOD -- test FK referenced updates SET DEFAULT +TRUNCATE temporal_rng, temporal_fk_rng2rng; INSERT INTO temporal_rng (id, valid_at) VALUES ('[-1,-1]', daterange(null, null)); -INSERT INTO temporal_rng (id, valid_at) VALUES ('[12,13)', daterange('2018-01-01', '2021-01-01')); -INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[8,9)', daterange('2018-01-01', '2021-01-01'), '[12,13)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); ALTER TABLE temporal_fk_rng2rng ALTER COLUMN parent_id SET DEFAULT '[-1,-1]', ADD CONSTRAINT temporal_fk_rng2rng_fk @@ -2211,6 +2341,22 @@ UPDATE temporal_mltrng SET id = '[7,8)' WHERE id = '[5,6)' AND valid_at = datemultirange(daterange('2018-01-01', '2018-02-01')); ERROR: update or delete on table "temporal_mltrng" violates foreign key constraint "temporal_fk_mltrng2mltrng_fk" on table "temporal_fk_mltrng2mltrng" DETAIL: Key (id, valid_at)=([5,6), {[2018-01-01,2018-02-01)}) is still referenced from table "temporal_fk_mltrng2mltrng". +-- changing an unreferenced part is okay: +UPDATE temporal_mltrng + FOR PORTION OF valid_at (datemultirange(daterange('2018-01-02', '2018-01-03'))) + SET id = '[7,8)' + WHERE id = '[5,6)'; +-- changing just a part fails: +UPDATE temporal_mltrng + FOR PORTION OF valid_at (datemultirange(daterange('2018-01-05', '2018-01-10'))) + SET id = '[7,8)' + WHERE id = '[5,6)'; +ERROR: update or delete on table "temporal_mltrng" violates foreign key constraint "temporal_fk_mltrng2mltrng_fk" on table "temporal_fk_mltrng2mltrng" +DETAIL: Key (id, valid_at)=([5,6), {[2018-01-01,2018-01-02),[2018-01-03,2018-02-01)}) is still referenced from table "temporal_fk_mltrng2mltrng". +-- then delete the objecting FK record and the same PK update succeeds: +DELETE FROM temporal_fk_mltrng2mltrng WHERE id = '[3,4)'; +UPDATE temporal_mltrng SET id = '[7,8)' + WHERE id = '[5,6)' AND valid_at = datemultirange(daterange('2018-01-01', '2018-02-01')); -- -- test FK referenced updates RESTRICT -- @@ -2253,6 +2399,19 @@ BEGIN; COMMIT; ERROR: update or delete on table "temporal_mltrng" violates foreign key constraint "temporal_fk_mltrng2mltrng_fk" on table "temporal_fk_mltrng2mltrng" DETAIL: Key (id, valid_at)=([5,6), {[2018-01-01,2018-02-01)}) is still referenced from table "temporal_fk_mltrng2mltrng". +-- deleting an unreferenced part is okay: +DELETE FROM temporal_mltrng +FOR PORTION OF valid_at (datemultirange(daterange('2018-01-02', '2018-01-03'))) +WHERE id = '[5,6)'; +-- deleting just a part fails: +DELETE FROM temporal_mltrng +FOR PORTION OF valid_at (datemultirange(daterange('2018-01-05', '2018-01-10'))) +WHERE id = '[5,6)'; +ERROR: update or delete on table "temporal_mltrng" violates foreign key constraint "temporal_fk_mltrng2mltrng_fk" on table "temporal_fk_mltrng2mltrng" +DETAIL: Key (id, valid_at)=([5,6), {[2018-01-01,2018-01-02),[2018-01-03,2018-02-01)}) is still referenced from table "temporal_fk_mltrng2mltrng". +-- then delete the objecting FK record and the same PK delete succeeds: +DELETE FROM temporal_fk_mltrng2mltrng WHERE id = '[3,4)'; +DELETE FROM temporal_mltrng WHERE id = '[5,6)' AND valid_at = datemultirange(daterange('2018-01-01', '2018-02-01')); -- -- FK between partitioned tables: ranges -- diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule index a0f5fab0f5df..844350262170 100644 --- a/src/test/regress/parallel_schedule +++ b/src/test/regress/parallel_schedule @@ -48,7 +48,7 @@ test: create_index create_index_spgist create_view index_including index_includi # ---------- # Another group of parallel tests # ---------- -test: create_aggregate create_function_sql create_cast constraints triggers select inherit typed_table vacuum drop_if_exists updatable_views roleattributes create_am hash_func errors infinite_recurse +test: create_aggregate create_function_sql create_cast constraints triggers select inherit typed_table vacuum drop_if_exists updatable_views roleattributes create_am hash_func errors infinite_recurse for_portion_of # ---------- # sanity_check does a vacuum, affecting the sort order of SELECT * diff --git a/src/test/regress/sql/for_portion_of.sql b/src/test/regress/sql/for_portion_of.sql new file mode 100644 index 000000000000..0e6c2db5a75b --- /dev/null +++ b/src/test/regress/sql/for_portion_of.sql @@ -0,0 +1,905 @@ +-- Tests for UPDATE/DELETE FOR PORTION OF + +SET datestyle TO ISO, YMD; + +-- Works on non-PK columns +CREATE TABLE for_portion_of_test ( + id int4range, + valid_at daterange, + name text NOT NULL +); +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[1,2)', '[2018-01-02,2020-01-01)', 'one'); + +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-01-15' TO '2019-01-01' + SET name = 'one^1'; + +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2019-01-15' TO '2019-01-20'; + +-- With a table alias with AS + +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2019-02-01' TO '2019-02-03' AS t + SET name = 'one^2'; + +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2019-02-03' TO '2019-02-04' AS t; + +-- With a table alias without AS + +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2019-02-04' TO '2019-02-05' t + SET name = 'one^3'; + +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2019-02-05' TO '2019-02-06' t; + +-- UPDATE with FROM + +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2019-03-01' to '2019-03-02' + SET name = 'one^4' + FROM (SELECT '[1,2)'::int4range) AS t2(id) + WHERE for_portion_of_test.id = t2.id; + +-- DELETE with USING + +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2019-03-02' TO '2019-03-03' + USING (SELECT '[1,2)'::int4range) AS t2(id) + WHERE for_portion_of_test.id = t2.id; + +SELECT * FROM for_portion_of_test ORDER BY id, valid_at; + +-- Works on more than one range +DROP TABLE for_portion_of_test; +CREATE TABLE for_portion_of_test ( + id int4range, + valid1_at daterange, + valid2_at daterange, + name text NOT NULL +); +INSERT INTO for_portion_of_test (id, valid1_at, valid2_at, name) VALUES + ('[1,2)', '[2018-01-02,2018-02-03)', '[2015-01-01,2025-01-01)', 'one'); + +UPDATE for_portion_of_test + FOR PORTION OF valid1_at FROM '2018-01-15' TO NULL + SET name = 'foo'; + SELECT * FROM for_portion_of_test ORDER BY id, valid1_at, valid2_at; + +UPDATE for_portion_of_test + FOR PORTION OF valid2_at FROM '2018-01-15' TO NULL + SET name = 'bar'; + SELECT * FROM for_portion_of_test ORDER BY id, valid1_at, valid2_at; + +DELETE FROM for_portion_of_test + FOR PORTION OF valid1_at FROM '2018-01-20' TO NULL; + SELECT * FROM for_portion_of_test ORDER BY id, valid1_at, valid2_at; + +DELETE FROM for_portion_of_test + FOR PORTION OF valid2_at FROM '2018-01-20' TO NULL; + SELECT * FROM for_portion_of_test ORDER BY id, valid1_at, valid2_at; + +-- Test with NULLs in the scalar/range key columns. +-- This won't happen if there is a PRIMARY KEY or UNIQUE constraint +-- but FOR PORTION OF shouldn't require that. +DROP TABLE for_portion_of_test; +CREATE UNLOGGED TABLE for_portion_of_test ( + id int4range, + valid_at daterange, + name text +); +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[1,2)', NULL, '1 null'), + ('[1,2)', '(,)', '1 unbounded'), + ('[1,2)', 'empty', '1 empty'), + (NULL, NULL, NULL), + (NULL, daterange('2018-01-01', '2019-01-01'), 'null key'); +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO NULL + SET name = 'NULL to NULL'; +SELECT * FROM for_portion_of_test ORDER BY id, valid_at; + +DROP TABLE for_portion_of_test; + +-- +-- UPDATE tests +-- + +CREATE TABLE for_portion_of_test ( + id int4range NOT NULL, + valid_at daterange NOT NULL, + name text NOT NULL, + CONSTRAINT for_portion_of_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[1,2)', '[2018-01-02,2018-02-03)', 'one'), + ('[1,2)', '[2018-02-03,2018-03-03)', 'one'), + ('[1,2)', '[2018-03-03,2018-04-04)', 'one'), + ('[2,3)', '[2018-01-01,2018-01-05)', 'two'), + ('[3,4)', '[2018-01-01,)', 'three'), + ('[4,5)', '(,2018-04-01)', 'four'), + ('[5,6)', '(,)', 'five') + ; +\set QUIET false + +-- Updating with a missing column fails +UPDATE for_portion_of_test + FOR PORTION OF invalid_at FROM '2018-06-01' TO NULL + SET name = 'foo' + WHERE id = '[5,6)'; + +-- Updating the range fails +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-06-01' TO NULL + SET valid_at = '[1990-01-01,1999-01-01)' + WHERE id = '[5,6)'; + +-- The wrong type fails +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM 1 TO 4 + SET name = 'nope' + WHERE id = '[3,4)'; + +-- Updating with timestamps reversed fails +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-06-01' TO '2018-01-01' + SET name = 'three^1' + WHERE id = '[3,4)'; + +-- Updating with a subquery fails +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM (SELECT '2018-01-01') TO '2018-06-01' + SET name = 'nope' + WHERE id = '[3,4)'; + +-- Updating with a column fails +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM lower(valid_at) TO NULL + SET name = 'nope' + WHERE id = '[3,4)'; + +-- Updating with timestamps equal does nothing +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-04-01' TO '2018-04-01' + SET name = 'three^0' + WHERE id = '[3,4)'; + +-- Updating a finite/open portion with a finite/open target +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-06-01' TO NULL + SET name = 'three^1' + WHERE id = '[3,4)'; + +-- Updating a finite/open portion with an open/finite target +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO '2018-03-01' + SET name = 'three^2' + WHERE id = '[3,4)'; + +-- Updating an open/finite portion with an open/finite target +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO '2018-02-01' + SET name = 'four^1' + WHERE id = '[4,5)'; + +-- Updating an open/finite portion with a finite/open target +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2017-01-01' TO NULL + SET name = 'four^2' + WHERE id = '[4,5)'; + +-- Updating a finite/finite portion with an exact fit +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2017-01-01' TO '2018-02-01' + SET name = 'four^3' + WHERE id = '[4,5)'; + +-- Updating an enclosed span +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO NULL + SET name = 'two^2' + WHERE id = '[2,3)'; + +-- Updating an open/open portion with a finite/finite target +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-01-01' TO '2019-01-01' + SET name = 'five^1' + WHERE id = '[5,6)'; + +-- Updating an enclosed span with separate protruding spans +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2017-01-01' TO '2020-01-01' + SET name = 'five^2' + WHERE id = '[5,6)'; + +-- Updating multiple enclosed spans +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO NULL + SET name = 'one^2' + WHERE id = '[1,2)'; + +-- Updating with a direct target +UPDATE for_portion_of_test + FOR PORTION OF valid_at (daterange('2018-03-10', '2018-03-17')) + SET name = 'one^3' + WHERE id = '[1,2)'; + +-- Updating the non-range part of the PK: +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-02-15' TO NULL + SET id = '[6,7)' + WHERE id = '[1,2)'; + +-- UPDATE with no WHERE clause +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2030-01-01' TO NULL + SET name = name || '*'; + +SELECT * FROM for_portion_of_test ORDER BY id, valid_at; +\set QUIET true + +-- Updating with a shift/reduce conflict +-- (requires a tsrange column) +CREATE UNLOGGED TABLE for_portion_of_test2 ( + id int4range, + valid_at tsrange, + name text +); +INSERT INTO for_portion_of_test2 (id, valid_at, name) VALUES + ('[1,2)', '[2000-01-01,2020-01-01)', 'one'); +-- updates [2011-03-01 01:02:00, 2012-01-01) (note 2 minutes) +UPDATE for_portion_of_test2 + FOR PORTION OF valid_at + FROM '2011-03-01'::timestamp + INTERVAL '1:02:03' HOUR TO MINUTE + TO '2012-01-01' + SET name = 'one^1' + WHERE id = '[1,2)'; + +-- TO is used for the bound but not the INTERVAL: +-- syntax error +UPDATE for_portion_of_test2 + FOR PORTION OF valid_at + FROM '2013-03-01'::timestamp + INTERVAL '1:02:03' HOUR + TO '2014-01-01' + SET name = 'one^2' + WHERE id = '[1,2)'; + +-- adding parens fixes it +-- updates [2015-03-01 01:00:00, 2016-01-01) (no minutes) +UPDATE for_portion_of_test2 + FOR PORTION OF valid_at + FROM ('2015-03-01'::timestamp + INTERVAL '1:02:03' HOUR) + TO '2016-01-01' + SET name = 'one^3' + WHERE id = '[1,2)'; + +SELECT * FROM for_portion_of_test2 ORDER BY id, valid_at; +DROP TABLE for_portion_of_test2; + +-- UPDATE FOR PORTION OF in a CTE: + +-- Visible to SELECT: +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[10,11)', '[2018-01-01,2020-01-01)', 'ten'); +WITH update_apr AS ( + UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-04-01' TO '2018-05-01' + SET name = 'Apr 2018' + WHERE id = '[10,11)' + RETURNING id, valid_at, name +) +SELECT * + FROM for_portion_of_test AS t, update_apr + WHERE t.id = update_apr.id; +SELECT * FROM for_portion_of_test WHERE id = '[10,11)'; + +-- Not visible to UPDATE: +-- Tuples updated/inserted within the CTE are not visible to the main query yet, +-- but neither are old tuples the CTE changed: +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[11,12)', '[2018-01-01,2020-01-01)', 'eleven'); +WITH update_apr AS ( + UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-04-01' TO '2018-05-01' + SET name = 'Apr 2018' + WHERE id = '[11,12)' + RETURNING id, valid_at, name +) +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-05-01' TO '2018-06-01' + AS t + SET name = 'May 2018' + FROM update_apr AS j + WHERE t.id = j.id; +SELECT * FROM for_portion_of_test WHERE id = '[11,12)'; +DELETE FROM for_portion_of_test WHERE id IN ('[10,11)', '[11,12)'); + +-- UPDATE FOR PORTION OF in a PL/pgSQL function +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[10,11)', '[2018-01-01,2020-01-01)', 'ten'); +CREATE FUNCTION fpo_update(_id int4range, _target_from date, _target_til date) +RETURNS void LANGUAGE plpgsql AS +$$ +BEGIN + UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM $2 TO $3 + SET name = concat(_target_from::text, ' to ', _target_til::text) + WHERE id = $1; +END; +$$; +SELECT fpo_update('[10,11)', '2015-01-01', '2019-01-01'); +SELECT * FROM for_portion_of_test WHERE id = '[10,11)'; + +DROP TABLE for_portion_of_test; + +-- +-- DELETE tests +-- + +CREATE TABLE for_portion_of_test ( + id int4range NOT NULL, + valid_at daterange NOT NULL, + name text NOT NULL, + CONSTRAINT for_portion_of_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[1,2)', '[2018-01-02,2018-02-03)', 'one'), + ('[1,2)', '[2018-02-03,2018-03-03)', 'one'), + ('[1,2)', '[2018-03-03,2018-04-04)', 'one'), + ('[2,3)', '[2018-01-01,2018-01-05)', 'two'), + ('[3,4)', '[2018-01-01,)', 'three'), + ('[4,5)', '(,2018-04-01)', 'four'), + ('[5,6)', '(,)', 'five'), + ('[6,7)', '[2018-01-01,)', 'six'), + ('[7,8)', '(,2018-04-01)', 'seven'), + ('[8,9)', '[2018-01-02,2018-02-03)', 'eight'), + ('[8,9)', '[2018-02-03,2018-03-03)', 'eight'), + ('[8,9)', '[2018-03-03,2018-04-04)', 'eight') + ; +\set QUIET false + +-- Deleting with a missing column fails +DELETE FROM for_portion_of_test + FOR PORTION OF invalid_at FROM '2018-06-01' TO NULL + WHERE id = '[5,6)'; + +-- The wrong type fails +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM 1 TO 4 + WHERE id = '[3,4)'; + +-- Deleting with timestamps reversed fails +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-06-01' TO '2018-01-01' + WHERE id = '[3,4)'; + +-- Deleting with a subquery fails +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM (SELECT '2018-01-01') TO '2018-06-01' + WHERE id = '[3,4)'; + +-- Deleting with a column fails +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM lower(valid_at) TO NULL + WHERE id = '[3,4)'; + +-- Deleting with timestamps equal does nothing +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-04-01' TO '2018-04-01' + WHERE id = '[3,4)'; + +-- Deleting a finite/open portion with a finite/open target +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-06-01' TO NULL + WHERE id = '[3,4)'; + +-- Deleting a finite/open portion with an open/finite target +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO '2018-03-01' + WHERE id = '[6,7)'; + +-- Deleting an open/finite portion with an open/finite target +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO '2018-02-01' + WHERE id = '[4,5)'; + +-- Deleting an open/finite portion with a finite/open target +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2017-01-01' TO NULL + WHERE id = '[7,8)'; + +-- Deleting a finite/finite portion with an exact fit +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-02-01' TO '2018-04-01' + WHERE id = '[4,5)'; + +-- Deleting an enclosed span +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO NULL + WHERE id = '[2,3)'; + +-- Deleting an open/open portion with a finite/finite target +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-01-01' TO '2019-01-01' + WHERE id = '[5,6)'; + +-- Deleting an enclosed span with separate protruding spans +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-02-03' TO '2018-03-03' + WHERE id = '[1,2)'; + +-- Deleting multiple enclosed spans +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO NULL + WHERE id = '[8,9)'; + +-- Deleting with a direct target +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at (daterange('2018-03-10', '2018-03-17')) + WHERE id = '[1,2)'; + +-- DELETE with no WHERE clause +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2030-01-01' TO NULL; + +SELECT * FROM for_portion_of_test ORDER BY id, valid_at; +\set QUIET true + +-- UPDATE ... RETURNING returns only the updated values (not the inserted side values) +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-02-01' TO '2018-02-15' + SET name = 'three^3' + WHERE id = '[3,4)' + RETURNING *; + +-- DELETE ... RETURNING returns the deleted values (regardless of bounds) +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-02-02' TO '2018-02-03' + WHERE id = '[3,4)' + RETURNING *; + +-- DELETE FOR PORTION OF in a PL/pgSQL function +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[10,11)', '[2018-01-01,2020-01-01)', 'ten'); +CREATE FUNCTION fpo_delete(_id int4range, _target_from date, _target_til date) +RETURNS void LANGUAGE plpgsql AS +$$ +BEGIN + DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM $2 TO $3 + WHERE id = $1; +END; +$$; +SELECT fpo_delete('[10,11)', '2015-01-01', '2019-01-01'); +SELECT * FROM for_portion_of_test WHERE id = '[10,11)'; +DELETE FROM for_portion_of_test WHERE id IN ('[10,11)'); + + +-- test that we run triggers on the UPDATE/DELETEd row and the INSERTed rows + +CREATE FUNCTION dump_trigger() +RETURNS TRIGGER LANGUAGE plpgsql AS +$$ +BEGIN + RAISE NOTICE '%: % % %:', + TG_NAME, TG_WHEN, TG_OP, TG_LEVEL; + + IF TG_ARGV[0] THEN + RAISE NOTICE ' old: %', (SELECT string_agg(old_table::text, '\n ') FROM old_table); + ELSE + RAISE NOTICE ' old: %', OLD.valid_at; + END IF; + IF TG_ARGV[1] THEN + RAISE NOTICE ' new: %', (SELECT string_agg(new_table::text, '\n ') FROM new_table); + ELSE + RAISE NOTICE ' new: %', NEW.valid_at; + END IF; + + IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN + RETURN NEW; + ELSIF TG_OP = 'DELETE' THEN + RETURN OLD; + END IF; +END; +$$; + +-- statement triggers: + +CREATE TRIGGER fpo_before_stmt +BEFORE INSERT OR UPDATE OR DELETE ON for_portion_of_test +FOR EACH STATEMENT EXECUTE PROCEDURE dump_trigger(false, false); + +CREATE TRIGGER fpo_after_insert_stmt +AFTER INSERT ON for_portion_of_test +FOR EACH STATEMENT EXECUTE PROCEDURE dump_trigger(false, false); + +CREATE TRIGGER fpo_after_update_stmt +AFTER UPDATE ON for_portion_of_test +FOR EACH STATEMENT EXECUTE PROCEDURE dump_trigger(false, false); + +CREATE TRIGGER fpo_after_delete_stmt +AFTER DELETE ON for_portion_of_test +FOR EACH STATEMENT EXECUTE PROCEDURE dump_trigger(false, false); + +-- row triggers: + +CREATE TRIGGER fpo_before_row +BEFORE INSERT OR UPDATE OR DELETE ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, false); + +CREATE TRIGGER fpo_after_insert_row +AFTER INSERT ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, false); + +CREATE TRIGGER fpo_after_update_row +AFTER UPDATE ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, false); + +CREATE TRIGGER fpo_after_delete_row +AFTER DELETE ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, false); + + +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2021-01-01' TO '2022-01-01' + SET name = 'five^3' + WHERE id = '[5,6)'; + +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2023-01-01' TO '2024-01-01' + WHERE id = '[5,6)'; + +SELECT * FROM for_portion_of_test ORDER BY id, valid_at; + +-- Triggers with a custom transition table name: + +DROP TABLE for_portion_of_test; +CREATE TABLE for_portion_of_test ( + id int4range, + valid_at daterange, + name text +); +INSERT INTO for_portion_of_test VALUES ('[1,2)', '[2018-01-01,2020-01-01)', 'one'); + +-- statement triggers: + +CREATE TRIGGER fpo_before_stmt +BEFORE INSERT OR UPDATE OR DELETE ON for_portion_of_test +FOR EACH STATEMENT EXECUTE PROCEDURE dump_trigger(false, false); + +CREATE TRIGGER fpo_after_insert_stmt +AFTER INSERT ON for_portion_of_test +REFERENCING NEW TABLE AS new_table +FOR EACH STATEMENT EXECUTE PROCEDURE dump_trigger(false, true); + +CREATE TRIGGER fpo_after_update_stmt +AFTER UPDATE ON for_portion_of_test +REFERENCING NEW TABLE AS new_table OLD TABLE AS old_table +FOR EACH STATEMENT EXECUTE PROCEDURE dump_trigger(true, true); + +CREATE TRIGGER fpo_after_delete_stmt +AFTER DELETE ON for_portion_of_test +REFERENCING OLD TABLE AS old_table +FOR EACH STATEMENT EXECUTE PROCEDURE dump_trigger(true, false); + +-- row triggers: + +CREATE TRIGGER fpo_before_row +BEFORE INSERT OR UPDATE OR DELETE ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, false); + +CREATE TRIGGER fpo_after_insert_row +AFTER INSERT ON for_portion_of_test +REFERENCING NEW TABLE AS new_table +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, true); + +CREATE TRIGGER fpo_after_update_row +AFTER UPDATE ON for_portion_of_test +REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(true, true); + +CREATE TRIGGER fpo_after_delete_row +AFTER DELETE ON for_portion_of_test +REFERENCING OLD TABLE AS old_table +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(true, false); + +BEGIN; +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-01-15' TO '2019-01-01' + SET name = '2018-01-15_to_2019-01-01'; +ROLLBACK; + +BEGIN; +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO '2018-01-21'; +ROLLBACK; + +BEGIN; +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO '2018-01-02' + SET name = 'NULL_to_2018-01-01'; +ROLLBACK; + +-- Deferred triggers +-- (must be CONSTRAINT triggers thus AFTER ROW with no transition tables) + +DROP TABLE for_portion_of_test; +CREATE TABLE for_portion_of_test ( + id int4range, + valid_at daterange, + name text +); +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[1,2)', '[2018-01-01,2020-01-01)', 'one'); + +CREATE CONSTRAINT TRIGGER fpo_after_insert_row +AFTER INSERT ON for_portion_of_test +DEFERRABLE INITIALLY DEFERRED +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, false); + +CREATE CONSTRAINT TRIGGER fpo_after_update_row +AFTER UPDATE ON for_portion_of_test +DEFERRABLE INITIALLY DEFERRED +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, false); + +CREATE CONSTRAINT TRIGGER fpo_after_delete_row +AFTER DELETE ON for_portion_of_test +DEFERRABLE INITIALLY DEFERRED +FOR EACH ROW EXECUTE PROCEDURE dump_trigger(false, false); + +BEGIN; +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-01-15' TO '2019-01-01' + SET name = '2018-01-15_to_2019-01-01'; +COMMIT; + +BEGIN; +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO '2018-01-21'; +COMMIT; + +BEGIN; +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM NULL TO '2018-01-02' + SET name = 'NULL_to_2018-01-01'; +COMMIT; + +SELECT * FROM for_portion_of_test; + +-- test FOR PORTION OF from triggers during FOR PORTION OF: + +DROP TABLE for_portion_of_test; +CREATE TABLE for_portion_of_test ( + id int4range, + valid_at daterange, + name text +); +INSERT INTO for_portion_of_test (id, valid_at, name) VALUES + ('[1,2)', '[2018-01-01,2020-01-01)', 'one'), + ('[2,3)', '[2018-01-01,2020-01-01)', 'two'), + ('[3,4)', '[2018-01-01,2020-01-01)', 'three'), + ('[4,5)', '[2018-01-01,2020-01-01)', 'four'); + +CREATE FUNCTION trg_fpo_update() +RETURNS TRIGGER LANGUAGE plpgsql AS +$$ +BEGIN + IF pg_trigger_depth() = 1 THEN + UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-02-01' TO '2018-03-01' + SET name = CONCAT(name, '^') + WHERE id = OLD.id; + END IF; + RETURN CASE WHEN 'TG_OP' = 'DELETE' THEN OLD ELSE NEW END; +END; +$$; + +CREATE FUNCTION trg_fpo_delete() +RETURNS TRIGGER LANGUAGE plpgsql AS +$$ +BEGIN + IF pg_trigger_depth() = 1 THEN + DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-03-01' TO '2018-04-01' + WHERE id = OLD.id; + END IF; + RETURN CASE WHEN 'TG_OP' = 'DELETE' THEN OLD ELSE NEW END; +END; +$$; + +-- UPDATE FOR PORTION OF from a trigger fired by UPDATE FOR PORTION OF + +CREATE TRIGGER fpo_after_update_row +AFTER UPDATE ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE trg_fpo_update(); + +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-05-01' TO '2018-06-01' + SET name = CONCAT(name, '*') + WHERE id = '[1,2)'; + +SELECT * FROM for_portion_of_test WHERE id = '[1,2)' ORDER BY id, valid_at; + +DROP TRIGGER fpo_after_update_row ON for_portion_of_test; + +-- UPDATE FOR PORTION OF from a trigger fired by DELETE FOR PORTION OF + +CREATE TRIGGER fpo_after_delete_row +AFTER DELETE ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE trg_fpo_update(); + +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-05-01' TO '2018-06-01' + WHERE id = '[2,3)'; + +SELECT * FROM for_portion_of_test WHERE id = '[2,3)' ORDER BY id, valid_at; + +DROP TRIGGER fpo_after_delete_row ON for_portion_of_test; + +-- DELETE FOR PORTION OF from a trigger fired by UPDATE FOR PORTION OF + +CREATE TRIGGER fpo_after_update_row +AFTER UPDATE ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE trg_fpo_delete(); + +UPDATE for_portion_of_test + FOR PORTION OF valid_at FROM '2018-05-01' TO '2018-06-01' + SET name = CONCAT(name, '*') + WHERE id = '[3,4)'; + +SELECT * FROM for_portion_of_test WHERE id = '[3,4)' ORDER BY id, valid_at; + +DROP TRIGGER fpo_after_update_row ON for_portion_of_test; + +-- DELETE FOR PORTION OF from a trigger fired by DELETE FOR PORTION OF + +CREATE TRIGGER fpo_after_delete_row +AFTER DELETE ON for_portion_of_test +FOR EACH ROW EXECUTE PROCEDURE trg_fpo_delete(); + +DELETE FROM for_portion_of_test + FOR PORTION OF valid_at FROM '2018-05-01' TO '2018-06-01' + WHERE id = '[4,5)'; + +SELECT * FROM for_portion_of_test WHERE id = '[4,5)' ORDER BY id, valid_at; + +DROP TRIGGER fpo_after_delete_row ON for_portion_of_test; + +-- Test with multiranges + +CREATE TABLE for_portion_of_test2 ( + id int4range NOT NULL, + valid_at datemultirange NOT NULL, + name text NOT NULL, + CONSTRAINT for_portion_of_test2_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +INSERT INTO for_portion_of_test2 (id, valid_at, name) VALUES + ('[1,2)', datemultirange(daterange('2018-01-02', '2018-02-03)'), daterange('2018-02-04', '2018-03-03')), 'one'), + ('[1,2)', datemultirange(daterange('2018-03-03', '2018-04-04)')), 'one'), + ('[2,3)', datemultirange(daterange('2018-01-01', '2018-05-01)')), 'two'), + ('[3,4)', datemultirange(daterange('2018-01-01', null)), 'three'); + ; + +UPDATE for_portion_of_test2 + FOR PORTION OF valid_at (datemultirange(daterange('2018-01-10', '2018-02-10'), daterange('2018-03-05', '2018-05-01'))) + SET name = 'one^1' + WHERE id = '[1,2)'; + +DELETE FROM for_portion_of_test2 + FOR PORTION OF valid_at (datemultirange(daterange('2018-01-15', '2018-02-15'), daterange('2018-03-01', '2018-03-15'))) + WHERE id = '[2,3)'; + +SELECT * FROM for_portion_of_test2 ORDER BY id, valid_at; + +DROP TABLE for_portion_of_test2; + +-- Test with a custom range type + +CREATE TYPE mydaterange AS range(subtype=date); + +CREATE TABLE for_portion_of_test2 ( + id int4range NOT NULL, + valid_at mydaterange NOT NULL, + name text NOT NULL, + CONSTRAINT for_portion_of_test2_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +INSERT INTO for_portion_of_test2 (id, valid_at, name) VALUES + ('[1,2)', '[2018-01-02,2018-02-03)', 'one'), + ('[1,2)', '[2018-02-03,2018-03-03)', 'one'), + ('[1,2)', '[2018-03-03,2018-04-04)', 'one'), + ('[2,3)', '[2018-01-01,2018-05-01)', 'two'), + ('[3,4)', '[2018-01-01,)', 'three'); + ; + +UPDATE for_portion_of_test2 + FOR PORTION OF valid_at FROM '2018-01-10' TO '2018-02-10' + SET name = 'one^1' + WHERE id = '[1,2)'; + +DELETE FROM for_portion_of_test2 + FOR PORTION OF valid_at FROM '2018-01-15' TO '2018-02-15' + WHERE id = '[2,3)'; + +SELECT * FROM for_portion_of_test2 ORDER BY id, valid_at; + +DROP TABLE for_portion_of_test2; +DROP TYPE mydaterange; + +-- Test FOR PORTION OF against a partitioned table. +-- temporal_partitioned_1 has the same attnums as the root +-- temporal_partitioned_3 has the different attnums from the root +-- temporal_partitioned_5 has the different attnums too, but reversed + +CREATE TABLE temporal_partitioned ( + id int4range, + valid_at daterange, + name text, + CONSTRAINT temporal_paritioned_uq UNIQUE (id, valid_at WITHOUT OVERLAPS) +) PARTITION BY LIST (id); +CREATE TABLE temporal_partitioned_1 PARTITION OF temporal_partitioned FOR VALUES IN ('[1,2)', '[2,3)'); +CREATE TABLE temporal_partitioned_3 PARTITION OF temporal_partitioned FOR VALUES IN ('[3,4)', '[4,5)'); +CREATE TABLE temporal_partitioned_5 PARTITION OF temporal_partitioned FOR VALUES IN ('[5,6)', '[6,7)'); + +ALTER TABLE temporal_partitioned DETACH PARTITION temporal_partitioned_3; +ALTER TABLE temporal_partitioned_3 DROP COLUMN id, DROP COLUMN valid_at; +ALTER TABLE temporal_partitioned_3 ADD COLUMN id int4range NOT NULL, ADD COLUMN valid_at daterange NOT NULL; +ALTER TABLE temporal_partitioned ATTACH PARTITION temporal_partitioned_3 FOR VALUES IN ('[3,4)', '[4,5)'); + +ALTER TABLE temporal_partitioned DETACH PARTITION temporal_partitioned_5; +ALTER TABLE temporal_partitioned_5 DROP COLUMN id, DROP COLUMN valid_at; +ALTER TABLE temporal_partitioned_5 ADD COLUMN valid_at daterange NOT NULL, ADD COLUMN id int4range NOT NULL; +ALTER TABLE temporal_partitioned ATTACH PARTITION temporal_partitioned_5 FOR VALUES IN ('[5,6)', '[6,7)'); + +INSERT INTO temporal_partitioned (id, valid_at, name) VALUES + ('[1,2)', daterange('2000-01-01', '2010-01-01'), 'one'), + ('[3,4)', daterange('2000-01-01', '2010-01-01'), 'three'), + ('[5,6)', daterange('2000-01-01', '2010-01-01'), 'five'); + +SELECT * FROM temporal_partitioned; + +-- Update without moving within partition 1 +UPDATE temporal_partitioned FOR PORTION OF valid_at FROM '2000-03-01' TO '2000-04-01' + SET name = 'one^1' + WHERE id = '[1,2)'; + +-- Update without moving within partition 3 +UPDATE temporal_partitioned FOR PORTION OF valid_at FROM '2000-03-01' TO '2000-04-01' + SET name = 'three^1' + WHERE id = '[3,4)'; + +-- Update without moving within partition 5 +UPDATE temporal_partitioned FOR PORTION OF valid_at FROM '2000-03-01' TO '2000-04-01' + SET name = 'five^1' + WHERE id = '[5,6)'; + +-- Move from partition 1 to partition 3 +UPDATE temporal_partitioned FOR PORTION OF valid_at FROM '2000-06-01' TO '2000-07-01' + SET name = 'one^2', + id = '[4,5)' + WHERE id = '[1,2)'; + +-- Move from partition 3 to partition 1 +UPDATE temporal_partitioned FOR PORTION OF valid_at FROM '2000-06-01' TO '2000-07-01' + SET name = 'three^2', + id = '[2,3)' + WHERE id = '[3,4)'; + +-- Move from partition 5 to partition 3 +UPDATE temporal_partitioned FOR PORTION OF valid_at FROM '2000-06-01' TO '2000-07-01' + SET name = 'five^2', + id = '[3,4)' + WHERE id = '[5,6)'; + +-- Update all partitions at once (each with leftovers) + +SELECT * FROM temporal_partitioned ORDER BY id, valid_at; +SELECT * FROM temporal_partitioned_1 ORDER BY id, valid_at; +SELECT * FROM temporal_partitioned_3 ORDER BY id, valid_at; +SELECT * FROM temporal_partitioned_5 ORDER BY id, valid_at; + +DROP TABLE temporal_partitioned; + +RESET datestyle; diff --git a/src/test/regress/sql/privileges.sql b/src/test/regress/sql/privileges.sql index 96eff1104d25..ae57f233314c 100644 --- a/src/test/regress/sql/privileges.sql +++ b/src/test/regress/sql/privileges.sql @@ -765,6 +765,24 @@ UPDATE errtst SET a = 'aaaa', b = NULL WHERE a = 'aaa'; SET SESSION AUTHORIZATION regress_priv_user1; DROP TABLE errtst; +-- test column-level privileges on the range used in FOR PORTION OF +SET SESSION AUTHORIZATION regress_priv_user1; +CREATE TABLE t1 ( + c1 int4range, + valid_at tsrange, + CONSTRAINT t1pk PRIMARY KEY (c1, valid_at WITHOUT OVERLAPS) +); +GRANT SELECT ON t1 TO regress_priv_user2; +GRANT SELECT ON t1 TO regress_priv_user3; +GRANT UPDATE (c1) ON t1 TO regress_priv_user2; +GRANT UPDATE (c1, valid_at) ON t1 TO regress_priv_user3; +SET SESSION AUTHORIZATION regress_priv_user2; +UPDATE t1 FOR PORTION OF valid_at FROM '2000-01-01' TO '2001-01-01' SET c1 = '[2,3)'; +SET SESSION AUTHORIZATION regress_priv_user3; +UPDATE t1 FOR PORTION OF valid_at FROM '2000-01-01' TO '2001-01-01' SET c1 = '[2,3)'; +SET SESSION AUTHORIZATION regress_priv_user1; +DROP TABLE t1; + -- test column-level privileges when involved with DELETE SET SESSION AUTHORIZATION regress_priv_user1; ALTER TABLE atest6 ADD COLUMN three integer; diff --git a/src/test/regress/sql/updatable_views.sql b/src/test/regress/sql/updatable_views.sql index c071fffc1163..e8c04e3ad91a 100644 --- a/src/test/regress/sql/updatable_views.sql +++ b/src/test/regress/sql/updatable_views.sql @@ -1881,6 +1881,20 @@ select * from uv_iocu_tab; drop view uv_iocu_view; drop table uv_iocu_tab; +-- Check UPDATE FOR PORTION OF works correctly +create table uv_fpo_tab (id int4range, valid_at tsrange, b float, + constraint pk_uv_fpo_tab primary key (id, valid_at without overlaps)); +insert into uv_fpo_tab values ('[1,1]', '[2020-01-01, 2030-01-01)', 0); +create view uv_fpo_view as + select b, b+1 as c, valid_at, id, '2.0'::text as two from uv_fpo_tab; + +insert into uv_fpo_view (id, valid_at, b) values ('[1,1]', '[2010-01-01, 2020-01-01)', 1); +select * from uv_fpo_view; +update uv_fpo_view for portion of valid_at from '2015-01-01' to '2020-01-01' set b = 2 where id = '[1,1]'; +select * from uv_fpo_view; +delete from uv_fpo_view for portion of valid_at from '2017-01-01' to '2022-01-01' where id = '[1,1]'; +select * from uv_fpo_view; + -- Test whole-row references to the view create table uv_iocu_tab (a int unique, b text); create view uv_iocu_view as diff --git a/src/test/regress/sql/without_overlaps.sql b/src/test/regress/sql/without_overlaps.sql index 4aaca242bbec..c5c89fe40ab5 100644 --- a/src/test/regress/sql/without_overlaps.sql +++ b/src/test/regress/sql/without_overlaps.sql @@ -2,7 +2,7 @@ -- -- We leave behind several tables to test pg_dump etc: -- temporal_rng, temporal_rng2, --- temporal_fk_rng2rng. +-- temporal_fk_rng2rng, temporal_fk2_rng2rng. SET datestyle TO ISO, YMD; @@ -632,6 +632,20 @@ INSERT INTO temporal3 (id, valid_at, id2, name) ('[1,2)', daterange('2000-01-01', '2010-01-01'), '[7,8)', 'foo'), ('[2,3)', daterange('2000-01-01', '2010-01-01'), '[9,10)', 'bar') ; +UPDATE temporal3 FOR PORTION OF valid_at FROM '2000-05-01' TO '2000-07-01' + SET name = name || '1'; +UPDATE temporal3 FOR PORTION OF valid_at FROM '2000-04-01' TO '2000-06-01' + SET name = name || '2' + WHERE id = '[2,3)'; +SELECT * FROM temporal3 ORDER BY id, valid_at; +-- conflicting id only: +INSERT INTO temporal3 (id, valid_at, id2, name) + VALUES + ('[1,2)', daterange('2005-01-01', '2006-01-01'), '[8,9)', 'foo3'); +-- conflicting id2 only: +INSERT INTO temporal3 (id, valid_at, id2, name) + VALUES + ('[3,4)', daterange('2005-01-01', '2010-01-01'), '[9,10)', 'bar3'); DROP TABLE temporal3; -- @@ -667,9 +681,23 @@ INSERT INTO temporal_partitioned (id, valid_at, name) VALUES ('[1,2)', daterange('2000-01-01', '2000-02-01'), 'one'), ('[1,2)', daterange('2000-02-01', '2000-03-01'), 'one'), ('[3,4)', daterange('2000-01-01', '2010-01-01'), 'three'); -SELECT * FROM temporal_partitioned ORDER BY id, valid_at; -SELECT * FROM tp1 ORDER BY id, valid_at; -SELECT * FROM tp2 ORDER BY id, valid_at; +SELECT tableoid::regclass, * FROM temporal_partitioned ORDER BY id, valid_at; +UPDATE temporal_partitioned + FOR PORTION OF valid_at FROM '2000-01-15' TO '2000-02-15' + SET name = 'one2' + WHERE id = '[1,2)'; +UPDATE temporal_partitioned + FOR PORTION OF valid_at FROM '2000-02-20' TO '2000-02-25' + SET id = '[4,5)' + WHERE name = 'one'; +UPDATE temporal_partitioned + FOR PORTION OF valid_at FROM '2002-01-01' TO '2003-01-01' + SET id = '[2,3)' + WHERE name = 'three'; +DELETE FROM temporal_partitioned + FOR PORTION OF valid_at FROM '2000-01-15' TO '2000-02-15' + WHERE id = '[3,4)'; +SELECT tableoid::regclass, * FROM temporal_partitioned ORDER BY id, valid_at; DROP TABLE temporal_partitioned; -- temporal UNIQUE: @@ -685,9 +713,23 @@ INSERT INTO temporal_partitioned (id, valid_at, name) VALUES ('[1,2)', daterange('2000-01-01', '2000-02-01'), 'one'), ('[1,2)', daterange('2000-02-01', '2000-03-01'), 'one'), ('[3,4)', daterange('2000-01-01', '2010-01-01'), 'three'); -SELECT * FROM temporal_partitioned ORDER BY id, valid_at; -SELECT * FROM tp1 ORDER BY id, valid_at; -SELECT * FROM tp2 ORDER BY id, valid_at; +SELECT tableoid::regclass, * FROM temporal_partitioned ORDER BY id, valid_at; +UPDATE temporal_partitioned + FOR PORTION OF valid_at FROM '2000-01-15' TO '2000-02-15' + SET name = 'one2' + WHERE id = '[1,2)'; +UPDATE temporal_partitioned + FOR PORTION OF valid_at FROM '2000-02-20' TO '2000-02-25' + SET id = '[4,5)' + WHERE name = 'one'; +UPDATE temporal_partitioned + FOR PORTION OF valid_at FROM '2002-01-01' TO '2003-01-01' + SET id = '[2,3)' + WHERE name = 'three'; +DELETE FROM temporal_partitioned + FOR PORTION OF valid_at FROM '2000-01-15' TO '2000-02-15' + WHERE id = '[3,4)'; +SELECT tableoid::regclass, * FROM temporal_partitioned ORDER BY id, valid_at; DROP TABLE temporal_partitioned; -- ALTER TABLE REPLICA IDENTITY @@ -1291,6 +1333,18 @@ COMMIT; -- changing the scalar part fails: UPDATE temporal_rng SET id = '[7,8)' WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); +-- changing an unreferenced part is okay: +UPDATE temporal_rng + FOR PORTION OF valid_at FROM '2018-01-02' TO '2018-01-03' + SET id = '[7,8)' + WHERE id = '[5,6)'; +-- changing just a part fails: +UPDATE temporal_rng + FOR PORTION OF valid_at FROM '2018-01-05' TO '2018-01-10' + SET id = '[7,8)' + WHERE id = '[5,6)'; +SELECT * FROM temporal_rng WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; +SELECT * FROM temporal_fk_rng2rng WHERE id in ('[3,4)') ORDER BY id, valid_at; -- then delete the objecting FK record and the same PK update succeeds: DELETE FROM temporal_fk_rng2rng WHERE id = '[3,4)'; UPDATE temporal_rng SET valid_at = daterange('2016-01-01', '2016-02-01') @@ -1338,6 +1392,18 @@ BEGIN; DELETE FROM temporal_rng WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); COMMIT; +-- deleting an unreferenced part is okay: +DELETE FROM temporal_rng +FOR PORTION OF valid_at FROM '2018-01-02' TO '2018-01-03' +WHERE id = '[5,6)'; +SELECT * FROM temporal_rng WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; +SELECT * FROM temporal_fk_rng2rng WHERE id in ('[3,4)') ORDER BY id, valid_at; +-- deleting just a part fails: +DELETE FROM temporal_rng +FOR PORTION OF valid_at FROM '2018-01-05' TO '2018-01-10' +WHERE id = '[5,6)'; +SELECT * FROM temporal_rng WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; +SELECT * FROM temporal_fk_rng2rng WHERE id in ('[3,4)') ORDER BY id, valid_at; -- then delete the objecting FK record and the same PK delete succeeds: DELETE FROM temporal_fk_rng2rng WHERE id = '[3,4)'; DELETE FROM temporal_rng WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); @@ -1356,12 +1422,13 @@ ALTER TABLE temporal_fk_rng2rng ON DELETE RESTRICT; -- --- test ON UPDATE/DELETE options +-- rng2rng test ON UPDATE/DELETE options -- -- test FK referenced updates CASCADE +TRUNCATE temporal_rng, temporal_fk_rng2rng; INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); -INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[4,5)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); ALTER TABLE temporal_fk_rng2rng ADD CONSTRAINT temporal_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) @@ -1369,8 +1436,9 @@ ALTER TABLE temporal_fk_rng2rng ON DELETE CASCADE ON UPDATE CASCADE; -- test FK referenced updates SET NULL -INSERT INTO temporal_rng (id, valid_at) VALUES ('[9,10)', daterange('2018-01-01', '2021-01-01')); -INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01'), '[9,10)'); +TRUNCATE temporal_rng, temporal_fk_rng2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); ALTER TABLE temporal_fk_rng2rng ADD CONSTRAINT temporal_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) @@ -1378,9 +1446,10 @@ ALTER TABLE temporal_fk_rng2rng ON DELETE SET NULL ON UPDATE SET NULL; -- test FK referenced updates SET DEFAULT +TRUNCATE temporal_rng, temporal_fk_rng2rng; INSERT INTO temporal_rng (id, valid_at) VALUES ('[-1,-1]', daterange(null, null)); -INSERT INTO temporal_rng (id, valid_at) VALUES ('[12,13)', daterange('2018-01-01', '2021-01-01')); -INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[8,9)', daterange('2018-01-01', '2021-01-01'), '[12,13)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); ALTER TABLE temporal_fk_rng2rng ALTER COLUMN parent_id SET DEFAULT '[-1,-1]', ADD CONSTRAINT temporal_fk_rng2rng_fk @@ -1716,6 +1785,20 @@ BEGIN; WHERE id = '[5,6)' AND valid_at = datemultirange(daterange('2018-01-01', '2018-02-01')); COMMIT; -- changing the scalar part fails: +UPDATE temporal_mltrng SET id = '[7,8)' + WHERE id = '[5,6)' AND valid_at = datemultirange(daterange('2018-01-01', '2018-02-01')); +-- changing an unreferenced part is okay: +UPDATE temporal_mltrng + FOR PORTION OF valid_at (datemultirange(daterange('2018-01-02', '2018-01-03'))) + SET id = '[7,8)' + WHERE id = '[5,6)'; +-- changing just a part fails: +UPDATE temporal_mltrng + FOR PORTION OF valid_at (datemultirange(daterange('2018-01-05', '2018-01-10'))) + SET id = '[7,8)' + WHERE id = '[5,6)'; +-- then delete the objecting FK record and the same PK update succeeds: +DELETE FROM temporal_fk_mltrng2mltrng WHERE id = '[3,4)'; UPDATE temporal_mltrng SET id = '[7,8)' WHERE id = '[5,6)' AND valid_at = datemultirange(daterange('2018-01-01', '2018-02-01')); @@ -1760,6 +1843,17 @@ BEGIN; DELETE FROM temporal_mltrng WHERE id = '[5,6)' AND valid_at = datemultirange(daterange('2018-01-01', '2018-02-01')); COMMIT; +-- deleting an unreferenced part is okay: +DELETE FROM temporal_mltrng +FOR PORTION OF valid_at (datemultirange(daterange('2018-01-02', '2018-01-03'))) +WHERE id = '[5,6)'; +-- deleting just a part fails: +DELETE FROM temporal_mltrng +FOR PORTION OF valid_at (datemultirange(daterange('2018-01-05', '2018-01-10'))) +WHERE id = '[5,6)'; +-- then delete the objecting FK record and the same PK delete succeeds: +DELETE FROM temporal_fk_mltrng2mltrng WHERE id = '[3,4)'; +DELETE FROM temporal_mltrng WHERE id = '[5,6)' AND valid_at = datemultirange(daterange('2018-01-01', '2018-02-01')); -- -- FK between partitioned tables: ranges diff --git a/src/test/subscription/t/034_temporal.pl b/src/test/subscription/t/034_temporal.pl index 6bbf65672790..b74693cb89cd 100644 --- a/src/test/subscription/t/034_temporal.pl +++ b/src/test/subscription/t/034_temporal.pl @@ -137,6 +137,12 @@ () qq(psql::1: ERROR: cannot update table "temporal_no_key" because it does not have a replica identity and publishes updates HINT: To enable updating the table, set REPLICA IDENTITY using ALTER TABLE.), "can't UPDATE temporal_no_key DEFAULT"); +($result, $stdout, $stderr) = $node_publisher->psql('postgres', + "UPDATE temporal_no_key FOR PORTION OF valid_at FROM '2001-01-01' TO '2002-01-01' SET a = 'c' WHERE id = '[2,3)'"); +is( $stderr, + qq(psql::1: ERROR: cannot update table "temporal_no_key" because it does not have a replica identity and publishes updates +HINT: To enable updating the table, set REPLICA IDENTITY using ALTER TABLE.), + "can't UPDATE FOR PORTION OF temporal_no_key DEFAULT"); ($result, $stdout, $stderr) = $node_publisher->psql('postgres', "DELETE FROM temporal_no_key WHERE id = '[3,4)'"); @@ -144,6 +150,12 @@ () qq(psql::1: ERROR: cannot delete from table "temporal_no_key" because it does not have a replica identity and publishes deletes HINT: To enable deleting from the table, set REPLICA IDENTITY using ALTER TABLE.), "can't DELETE temporal_no_key DEFAULT"); +($result, $stdout, $stderr) = $node_publisher->psql('postgres', + "DELETE FROM temporal_no_key FOR PORTION OF valid_at FROM '2002-01-01' TO '2003-01-01' WHERE id = '[2,3)'"); +is( $stderr, + qq(psql::1: ERROR: cannot delete from table "temporal_no_key" because it does not have a replica identity and publishes deletes +HINT: To enable deleting from the table, set REPLICA IDENTITY using ALTER TABLE.), + "can't DELETE FOR PORTION OF temporal_no_key DEFAULT"); $node_publisher->wait_for_catchup('sub1'); @@ -165,16 +177,22 @@ () $node_publisher->safe_psql('postgres', "UPDATE temporal_pk SET a = 'b' WHERE id = '[2,3)'"); +$node_publisher->safe_psql('postgres', + "UPDATE temporal_pk FOR PORTION OF valid_at FROM '2001-01-01' TO '2002-01-01' SET a = 'c' WHERE id = '[2,3)'"); $node_publisher->safe_psql('postgres', "DELETE FROM temporal_pk WHERE id = '[3,4)'"); +$node_publisher->safe_psql('postgres', + "DELETE FROM temporal_pk FOR PORTION OF valid_at FROM '2002-01-01' TO '2003-01-01' WHERE id = '[2,3)'"); $node_publisher->wait_for_catchup('sub1'); $result = $node_subscriber->safe_psql('postgres', "SELECT * FROM temporal_pk ORDER BY id, valid_at"); is( $result, qq{[1,2)|[2000-01-01,2010-01-01)|a -[2,3)|[2000-01-01,2010-01-01)|b +[2,3)|[2000-01-01,2001-01-01)|b +[2,3)|[2001-01-01,2002-01-01)|c +[2,3)|[2003-01-01,2010-01-01)|b [4,5)|[2000-01-01,2010-01-01)|a}, 'replicated temporal_pk DEFAULT'); # replicate with a unique key: @@ -192,6 +210,12 @@ () qq(psql::1: ERROR: cannot update table "temporal_unique" because it does not have a replica identity and publishes updates HINT: To enable updating the table, set REPLICA IDENTITY using ALTER TABLE.), "can't UPDATE temporal_unique DEFAULT"); +($result, $stdout, $stderr) = $node_publisher->psql('postgres', + "UPDATE temporal_unique FOR PORTION OF valid_at FROM '2001-01-01' TO '2002-01-01' SET a = 'c' WHERE id = '[2,3)'"); +is( $stderr, + qq(psql::1: ERROR: cannot update table "temporal_unique" because it does not have a replica identity and publishes updates +HINT: To enable updating the table, set REPLICA IDENTITY using ALTER TABLE.), + "can't UPDATE FOR PORTION OF temporal_unique DEFAULT"); ($result, $stdout, $stderr) = $node_publisher->psql('postgres', "DELETE FROM temporal_unique WHERE id = '[3,4)'"); @@ -199,6 +223,12 @@ () qq(psql::1: ERROR: cannot delete from table "temporal_unique" because it does not have a replica identity and publishes deletes HINT: To enable deleting from the table, set REPLICA IDENTITY using ALTER TABLE.), "can't DELETE temporal_unique DEFAULT"); +($result, $stdout, $stderr) = $node_publisher->psql('postgres', + "DELETE FROM temporal_unique FOR PORTION OF valid_at FROM '2002-01-01' TO '2003-01-01' WHERE id = '[2,3)'"); +is( $stderr, + qq(psql::1: ERROR: cannot delete from table "temporal_unique" because it does not have a replica identity and publishes deletes +HINT: To enable deleting from the table, set REPLICA IDENTITY using ALTER TABLE.), + "can't DELETE FOR PORTION OF temporal_unique DEFAULT"); $node_publisher->wait_for_catchup('sub1'); @@ -287,16 +317,22 @@ () $node_publisher->safe_psql('postgres', "UPDATE temporal_no_key SET a = 'b' WHERE id = '[2,3)'"); +$node_publisher->safe_psql('postgres', + "UPDATE temporal_no_key FOR PORTION OF valid_at FROM '2001-01-01' TO '2002-01-01' SET a = 'c' WHERE id = '[2,3)'"); $node_publisher->safe_psql('postgres', "DELETE FROM temporal_no_key WHERE id = '[3,4)'"); +$node_publisher->safe_psql('postgres', + "DELETE FROM temporal_no_key FOR PORTION OF valid_at FROM '2002-01-01' TO '2003-01-01' WHERE id = '[2,3)'"); $node_publisher->wait_for_catchup('sub1'); $result = $node_subscriber->safe_psql('postgres', "SELECT * FROM temporal_no_key ORDER BY id, valid_at"); is( $result, qq{[1,2)|[2000-01-01,2010-01-01)|a -[2,3)|[2000-01-01,2010-01-01)|b +[2,3)|[2000-01-01,2001-01-01)|b +[2,3)|[2001-01-01,2002-01-01)|c +[2,3)|[2003-01-01,2010-01-01)|b [4,5)|[2000-01-01,2010-01-01)|a}, 'replicated temporal_no_key FULL'); # replicate with a primary key: @@ -310,16 +346,22 @@ () $node_publisher->safe_psql('postgres', "UPDATE temporal_pk SET a = 'b' WHERE id = '[2,3)'"); +$node_publisher->safe_psql('postgres', + "UPDATE temporal_pk FOR PORTION OF valid_at FROM '2001-01-01' TO '2002-01-01' SET a = 'c' WHERE id = '[2,3)'"); $node_publisher->safe_psql('postgres', "DELETE FROM temporal_pk WHERE id = '[3,4)'"); +$node_publisher->safe_psql('postgres', + "DELETE FROM temporal_pk FOR PORTION OF valid_at FROM '2002-01-01' TO '2003-01-01' WHERE id = '[2,3)'"); $node_publisher->wait_for_catchup('sub1'); $result = $node_subscriber->safe_psql('postgres', "SELECT * FROM temporal_pk ORDER BY id, valid_at"); is( $result, qq{[1,2)|[2000-01-01,2010-01-01)|a -[2,3)|[2000-01-01,2010-01-01)|b +[2,3)|[2000-01-01,2001-01-01)|b +[2,3)|[2001-01-01,2002-01-01)|c +[2,3)|[2003-01-01,2010-01-01)|b [4,5)|[2000-01-01,2010-01-01)|a}, 'replicated temporal_pk FULL'); # replicate with a unique key: @@ -333,17 +375,23 @@ () $node_publisher->safe_psql('postgres', "UPDATE temporal_unique SET a = 'b' WHERE id = '[2,3)'"); +$node_publisher->safe_psql('postgres', + "UPDATE temporal_unique FOR PORTION OF valid_at FROM '2001-01-01' TO '2002-01-01' SET a = 'c' WHERE id = '[2,3)'"); $node_publisher->safe_psql('postgres', "DELETE FROM temporal_unique WHERE id = '[3,4)'"); +$node_publisher->safe_psql('postgres', + "DELETE FROM temporal_unique FOR PORTION OF valid_at FROM '2002-01-01' TO '2003-01-01' WHERE id = '[2,3)'"); $node_publisher->wait_for_catchup('sub1'); $result = $node_subscriber->safe_psql('postgres', "SELECT * FROM temporal_unique ORDER BY id, valid_at"); is( $result, qq{[1,2)|[2000-01-01,2010-01-01)|a -[2,3)|[2000-01-01,2010-01-01)|b -[4,5)|[2000-01-01,2010-01-01)|a}, 'replicated temporal_unique FULL'); +[2,3)|[2000-01-01,2001-01-01)|b +[2,3)|[2001-01-01,2002-01-01)|c +[2,3)|[2003-01-01,2010-01-01)|b +[4,5)|[2000-01-01,2010-01-01)|a}, 'replicated temporal_unique DEFAULT'); # cleanup @@ -425,16 +473,22 @@ () $node_publisher->safe_psql('postgres', "UPDATE temporal_pk SET a = 'b' WHERE id = '[2,3)'"); +$node_publisher->safe_psql('postgres', + "UPDATE temporal_pk FOR PORTION OF valid_at FROM '2001-01-01' TO '2002-01-01' SET a = 'c' WHERE id = '[2,3)'"); $node_publisher->safe_psql('postgres', "DELETE FROM temporal_pk WHERE id = '[3,4)'"); +$node_publisher->safe_psql('postgres', + "DELETE FROM temporal_pk FOR PORTION OF valid_at FROM '2002-01-01' TO '2003-01-01' WHERE id = '[2,3)'"); $node_publisher->wait_for_catchup('sub1'); $result = $node_subscriber->safe_psql('postgres', "SELECT * FROM temporal_pk ORDER BY id, valid_at"); is( $result, qq{[1,2)|[2000-01-01,2010-01-01)|a -[2,3)|[2000-01-01,2010-01-01)|b +[2,3)|[2000-01-01,2001-01-01)|b +[2,3)|[2001-01-01,2002-01-01)|c +[2,3)|[2003-01-01,2010-01-01)|b [4,5)|[2000-01-01,2010-01-01)|a}, 'replicated temporal_pk USING INDEX'); # replicate with a unique key: @@ -448,16 +502,22 @@ () $node_publisher->safe_psql('postgres', "UPDATE temporal_unique SET a = 'b' WHERE id = '[2,3)'"); +$node_publisher->safe_psql('postgres', + "UPDATE temporal_unique FOR PORTION OF valid_at FROM '2001-01-01' TO '2002-01-01' SET a = 'c' WHERE id = '[2,3)'"); $node_publisher->safe_psql('postgres', "DELETE FROM temporal_unique WHERE id = '[3,4)'"); +$node_publisher->safe_psql('postgres', + "DELETE FROM temporal_unique FOR PORTION OF valid_at FROM '2002-01-01' TO '2003-01-01' WHERE id = '[2,3)'"); $node_publisher->wait_for_catchup('sub1'); $result = $node_subscriber->safe_psql('postgres', "SELECT * FROM temporal_unique ORDER BY id, valid_at"); is( $result, qq{[1,2)|[2000-01-01,2010-01-01)|a -[2,3)|[2000-01-01,2010-01-01)|b +[2,3)|[2000-01-01,2001-01-01)|b +[2,3)|[2001-01-01,2002-01-01)|c +[2,3)|[2003-01-01,2010-01-01)|b [4,5)|[2000-01-01,2010-01-01)|a}, 'replicated temporal_unique USING INDEX'); # cleanup @@ -543,6 +603,12 @@ () qq(psql::1: ERROR: cannot update table "temporal_no_key" because it does not have a replica identity and publishes updates HINT: To enable updating the table, set REPLICA IDENTITY using ALTER TABLE.), "can't UPDATE temporal_no_key NOTHING"); +($result, $stdout, $stderr) = $node_publisher->psql('postgres', + "UPDATE temporal_no_key FOR PORTION OF valid_at FROM '2001-01-01' TO '2002-01-01' SET a = 'c' WHERE id = '[2,3)'"); +is( $stderr, + qq(psql::1: ERROR: cannot update table "temporal_no_key" because it does not have a replica identity and publishes updates +HINT: To enable updating the table, set REPLICA IDENTITY using ALTER TABLE.), + "can't UPDATE temporal_no_key NOTHING"); ($result, $stdout, $stderr) = $node_publisher->psql('postgres', "DELETE FROM temporal_no_key WHERE id = '[3,4)'"); @@ -550,6 +616,12 @@ () qq(psql::1: ERROR: cannot delete from table "temporal_no_key" because it does not have a replica identity and publishes deletes HINT: To enable deleting from the table, set REPLICA IDENTITY using ALTER TABLE.), "can't DELETE temporal_no_key NOTHING"); +($result, $stdout, $stderr) = $node_publisher->psql('postgres', + "DELETE FROM temporal_no_key FOR PORTION OF valid_at FROM '2002-01-01' TO '2003-01-01' WHERE id = '[2,3)'"); +is( $stderr, + qq(psql::1: ERROR: cannot delete from table "temporal_no_key" because it does not have a replica identity and publishes deletes +HINT: To enable deleting from the table, set REPLICA IDENTITY using ALTER TABLE.), + "can't DELETE temporal_no_key NOTHING"); $node_publisher->wait_for_catchup('sub1'); @@ -575,6 +647,12 @@ () qq(psql::1: ERROR: cannot update table "temporal_pk" because it does not have a replica identity and publishes updates HINT: To enable updating the table, set REPLICA IDENTITY using ALTER TABLE.), "can't UPDATE temporal_pk NOTHING"); +($result, $stdout, $stderr) = $node_publisher->psql('postgres', + "UPDATE temporal_pk FOR PORTION OF valid_at FROM '2001-01-01' TO '2002-01-01' SET a = 'c' WHERE id = '[2,3)'"); +is( $stderr, + qq(psql::1: ERROR: cannot update table "temporal_pk" because it does not have a replica identity and publishes updates +HINT: To enable updating the table, set REPLICA IDENTITY using ALTER TABLE.), + "can't UPDATE temporal_pk NOTHING"); ($result, $stdout, $stderr) = $node_publisher->psql('postgres', "DELETE FROM temporal_pk WHERE id = '[3,4)'"); @@ -582,6 +660,12 @@ () qq(psql::1: ERROR: cannot delete from table "temporal_pk" because it does not have a replica identity and publishes deletes HINT: To enable deleting from the table, set REPLICA IDENTITY using ALTER TABLE.), "can't DELETE temporal_pk NOTHING"); +($result, $stdout, $stderr) = $node_publisher->psql('postgres', + "DELETE FROM temporal_pk FOR PORTION OF valid_at FROM '2002-01-01' TO '2003-01-01' WHERE id = '[2,3)'"); +is( $stderr, + qq(psql::1: ERROR: cannot delete from table "temporal_pk" because it does not have a replica identity and publishes deletes +HINT: To enable deleting from the table, set REPLICA IDENTITY using ALTER TABLE.), + "can't DELETE temporal_pk NOTHING"); $node_publisher->wait_for_catchup('sub1'); @@ -607,6 +691,12 @@ () qq(psql::1: ERROR: cannot update table "temporal_unique" because it does not have a replica identity and publishes updates HINT: To enable updating the table, set REPLICA IDENTITY using ALTER TABLE.), "can't UPDATE temporal_unique NOTHING"); +($result, $stdout, $stderr) = $node_publisher->psql('postgres', + "UPDATE temporal_unique FOR PORTION OF valid_at FROM '2001-01-01' TO '2002-01-01' SET a = 'c' WHERE id = '[2,3)'"); +is( $stderr, + qq(psql::1: ERROR: cannot update table "temporal_unique" because it does not have a replica identity and publishes updates +HINT: To enable updating the table, set REPLICA IDENTITY using ALTER TABLE.), + "can't UPDATE FOR PORTION OF temporal_unique NOTHING"); ($result, $stdout, $stderr) = $node_publisher->psql('postgres', "DELETE FROM temporal_unique WHERE id = '[3,4)'"); @@ -614,6 +704,12 @@ () qq(psql::1: ERROR: cannot delete from table "temporal_unique" because it does not have a replica identity and publishes deletes HINT: To enable deleting from the table, set REPLICA IDENTITY using ALTER TABLE.), "can't DELETE temporal_unique NOTHING"); +($result, $stdout, $stderr) = $node_publisher->psql('postgres', + "DELETE FROM temporal_unique FOR PORTION OF valid_at FROM '2002-01-01' TO '2003-01-01' WHERE id = '[2,3)'"); +is( $stderr, + qq(psql::1: ERROR: cannot delete from table "temporal_unique" because it does not have a replica identity and publishes deletes +HINT: To enable deleting from the table, set REPLICA IDENTITY using ALTER TABLE.), + "can't DELETE FOR PORTION OF temporal_unique NOTHING"); $node_publisher->wait_for_catchup('sub1'); diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list index 2ca7b75af579..8c4a5840f1c0 100644 --- a/src/tools/pgindent/typedefs.list +++ b/src/tools/pgindent/typedefs.list @@ -838,6 +838,9 @@ ForBothState ForEachState ForFiveState ForFourState +ForPortionOfClause +ForPortionOfExpr +ForPortionOfState ForThreeState ForeignAsyncConfigureWait_function ForeignAsyncNotify_function @@ -971,6 +974,7 @@ Form_pg_ts_template Form_pg_type Form_pg_user_mapping FormatNode +FPO_QueryHashEntry FreeBlockNumberArray FreeListData FreePageBtree From 7b549b2519e39e616ae17b2c81e79eaffef1c283 Mon Sep 17 00:00:00 2001 From: "Paul A. Jungwirth" Date: Fri, 31 Oct 2025 19:59:52 -0700 Subject: [PATCH 06/11] Add isolation tests for UPDATE/DELETE FOR PORTION OF Concurrent updates/deletes in READ COMMITTED mode don't give you what you want: the second update/delete fails to leftovers from the first, so you essentially have lost updates/deletes. But we are following the rules, and other RDBMSes give you screwy results in READ COMMITTED too (albeit different). One approach is to lock the history you want with SELECT FOR UPDATE before issuing the actual UPDATE/DELETE. That way you see the leftovers of anyone else who also touched that history. The isolation tests here use that approach and show that it's viable. --- doc/src/sgml/dml.sgml | 16 + src/backend/executor/nodeModifyTable.c | 4 + .../isolation/expected/for-portion-of.out | 5803 +++++++++++++++++ src/test/isolation/isolation_schedule | 1 + src/test/isolation/specs/for-portion-of.spec | 751 +++ 5 files changed, 6575 insertions(+) create mode 100644 src/test/isolation/expected/for-portion-of.out create mode 100644 src/test/isolation/specs/for-portion-of.spec diff --git a/doc/src/sgml/dml.sgml b/doc/src/sgml/dml.sgml index a899c9ab447a..e4afedf4d7a4 100644 --- a/doc/src/sgml/dml.sgml +++ b/doc/src/sgml/dml.sgml @@ -394,6 +394,22 @@ WHERE id = 5; column references are not. + + In READ COMMITTED mode, temporal updates and deletes can + cause unexpected results when they concurrently touch the same row. It is + possible to lose all or part of the second update or delete. That's because + after the first update changes the start/end times of the original + record, it may no longer fit within the second query's FOR PORTION + OF bounds, so it becomes disqualified from the query. On the other + hand the just-inserted temporal leftovers may be overlooked by the second query, + which has already scanned the table to find rows to modify. To solve these + problems, precede every temporal update/delete with a SELECT FOR + UPDATE matching the same criteria (including the targeted portion of + application time). That way the actual update/delete doesn't begin until the + lock is held, and all concurrent leftovers will be visible. In other + transaction isolation levels, this lock is not required. + + When temporal leftovers are inserted, all INSERT triggers are fired, but permission checks for inserting rows are diff --git a/src/backend/executor/nodeModifyTable.c b/src/backend/executor/nodeModifyTable.c index 665dbc182391..857139ec58b8 100644 --- a/src/backend/executor/nodeModifyTable.c +++ b/src/backend/executor/nodeModifyTable.c @@ -1403,6 +1403,10 @@ ExecForPortionOfLeftovers(ModifyTableContext *context, * We have already locked the tuple in ExecUpdate/ExecDelete, and it has * passed EvalPlanQual. This ensures that concurrent updates in READ * COMMITTED can't insert conflicting temporal leftovers. + * + * It does *not* protect against concurrent update/deletes overlooking each + * others' leftovers though. See our isolation tests for details about that + * and a viable workaround. */ if (!table_tuple_fetch_row_version(resultRelInfo->ri_RelationDesc, tupleid, SnapshotAny, oldtupleSlot)) elog(ERROR, "failed to fetch tuple for FOR PORTION OF"); diff --git a/src/test/isolation/expected/for-portion-of.out b/src/test/isolation/expected/for-portion-of.out new file mode 100644 index 000000000000..89f646dd8992 --- /dev/null +++ b/src/test/isolation/expected/for-portion-of.out @@ -0,0 +1,5803 @@ +Parsed test spec with 2 sessions + +starting permutation: s1rc s2rc s2lock2027 s2upd2027 s2c s1lock2025 s1upd2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock2027: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2027-01-01,2028-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rc s2rc s2lock202503 s2upd202503 s2c s1lock2025 s1upd2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock202503: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-03-01,2025-04-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(3 rows) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-03-01,2025-04-01)| 8.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rc s2rc s2lock20252026 s2upd20252026 s2c s1lock2025 s1upd2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock20252026: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-06-01,2026-06-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2025-06-01,2026-06-01)|10.00 +(2 rows) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2025-06-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rc s2rc s1lock2025 s1upd2025 s1c s2lock2027 s2upd2027 s2c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2lock2027: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2027-01-01,2028-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rc s2rc s1lock2025 s1upd2025 s1c s2lock202503 s2upd202503 s2c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2lock202503: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-03-01,2025-04-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2025-01-01,2026-01-01)| 8.00 +(1 row) + +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rc s2rc s1lock2025 s1upd2025 s1c s2lock20252026 s2upd20252026 s2c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2lock20252026: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-06-01,2026-06-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2025-06-01,2026-01-01)|10.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rc s2rc s2lock2027 s2upd2027 s1lock2025 s2c s1upd2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock2027: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2027-01-01,2028-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +step s2c: COMMIT; +step s1lock2025: <... completed> +id|valid_at|price +--+--------+----- +(0 rows) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rc s2rc s2lock202503 s2upd202503 s1lock2025 s2c s1upd2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock202503: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-03-01,2025-04-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +step s2c: COMMIT; +step s1lock2025: <... completed> +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2025-03-01,2025-04-01)|10.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-03-01,2025-04-01)| 8.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rc s2rc s2lock20252026 s2upd20252026 s1lock2025 s2c s1upd2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock20252026: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-06-01,2026-06-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +step s2c: COMMIT; +step s1lock2025: <... completed> +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2025-06-01,2026-06-01)|10.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2025-06-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rc s2rc s2lock2027 s2del2027 s2c s1lock2025 s1upd2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock2027: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2027-01-01,2028-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rc s2rc s2lock202503 s2del202503 s2c s1lock2025 s1upd2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock202503: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-03-01,2025-04-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(2 rows) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rc s2rc s2lock20252026 s2del20252026 s2c s1lock2025 s1upd2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock20252026: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-06-01,2026-06-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rc s2rc s1lock2025 s1upd2025 s1c s2lock2027 s2del2027 s2c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2lock2027: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2027-01-01,2028-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rc s2rc s1lock2025 s1upd2025 s1c s2lock202503 s2del202503 s2c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2lock202503: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-03-01,2025-04-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2025-01-01,2026-01-01)| 8.00 +(1 row) + +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rc s2rc s1lock2025 s1upd2025 s1c s2lock20252026 s2del20252026 s2c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2lock20252026: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-06-01,2026-06-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rc s2rc s2lock2027 s2del2027 s1lock2025 s2c s1upd2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock2027: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2027-01-01,2028-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +step s2c: COMMIT; +step s1lock2025: <... completed> +id|valid_at|price +--+--------+----- +(0 rows) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rc s2rc s2lock202503 s2del202503 s1lock2025 s2c s1upd2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock202503: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-03-01,2025-04-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +step s2c: COMMIT; +step s1lock2025: <... completed> +id|valid_at|price +--+--------+----- +(0 rows) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rc s2rc s2lock20252026 s2del20252026 s1lock2025 s2c s1upd2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock20252026: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-06-01,2026-06-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +step s2c: COMMIT; +step s1lock2025: <... completed> +id|valid_at|price +--+--------+----- +(0 rows) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rc s2rc s2lock2027 s2upd2027 s2c s1lock2025 s1del2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock2027: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2027-01-01,2028-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rc s2rc s2lock202503 s2upd202503 s2c s1lock2025 s1del2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock202503: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-03-01,2025-04-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(3 rows) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rc s2rc s2lock20252026 s2upd20252026 s2c s1lock2025 s1del2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock20252026: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-06-01,2026-06-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2025-06-01,2026-06-01)|10.00 +(2 rows) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rc s2rc s1lock2025 s1del2025 s1c s2lock2027 s2upd2027 s2c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2lock2027: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2027-01-01,2028-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rc s2rc s1lock2025 s1del2025 s1c s2lock202503 s2upd202503 s2c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2lock202503: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-03-01,2025-04-01)' + ORDER BY valid_at FOR UPDATE; + +id|valid_at|price +--+--------+----- +(0 rows) + +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rc s2rc s1lock2025 s1del2025 s1c s2lock20252026 s2upd20252026 s2c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2lock20252026: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-06-01,2026-06-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rc s2rc s2lock2027 s2upd2027 s1lock2025 s2c s1del2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock2027: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2027-01-01,2028-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +step s2c: COMMIT; +step s1lock2025: <... completed> +id|valid_at|price +--+--------+----- +(0 rows) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rc s2rc s2lock202503 s2upd202503 s1lock2025 s2c s1del2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock202503: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-03-01,2025-04-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +step s2c: COMMIT; +step s1lock2025: <... completed> +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2025-03-01,2025-04-01)|10.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rc s2rc s2lock20252026 s2upd20252026 s1lock2025 s2c s1del2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock20252026: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-06-01,2026-06-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +step s2c: COMMIT; +step s1lock2025: <... completed> +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2025-06-01,2026-06-01)|10.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rc s2rc s2lock2027 s2del2027 s2c s1lock2025 s1del2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock2027: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2027-01-01,2028-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rc s2rc s2lock202503 s2del202503 s2c s1lock2025 s1del2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock202503: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-03-01,2025-04-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(2 rows) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rc s2rc s2lock20252026 s2del20252026 s2c s1lock2025 s1del2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock20252026: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-06-01,2026-06-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rc s2rc s1lock2025 s1del2025 s1c s2lock2027 s2del2027 s2c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2lock2027: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2027-01-01,2028-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rc s2rc s1lock2025 s1del2025 s1c s2lock202503 s2del202503 s2c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2lock202503: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-03-01,2025-04-01)' + ORDER BY valid_at FOR UPDATE; + +id|valid_at|price +--+--------+----- +(0 rows) + +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rc s2rc s1lock2025 s1del2025 s1c s2lock20252026 s2del20252026 s2c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2lock20252026: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-06-01,2026-06-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rc s2rc s2lock2027 s2del2027 s1lock2025 s2c s1del2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock2027: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2027-01-01,2028-01-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +step s2c: COMMIT; +step s1lock2025: <... completed> +id|valid_at|price +--+--------+----- +(0 rows) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rc s2rc s2lock202503 s2del202503 s1lock2025 s2c s1del2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock202503: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-03-01,2025-04-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +step s2c: COMMIT; +step s1lock2025: <... completed> +id|valid_at|price +--+--------+----- +(0 rows) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rc s2rc s2lock20252026 s2del20252026 s1lock2025 s2c s1del2025 s1c s1q +step s1rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2rc: BEGIN ISOLATION LEVEL READ COMMITTED; +step s2lock20252026: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-06-01,2026-06-01)' + ORDER BY valid_at FOR UPDATE; + +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s1lock2025: + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; + +step s2c: COMMIT; +step s1lock2025: <... completed> +id|valid_at|price +--+--------+----- +(0 rows) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s2upd2027 s2c s1upd2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rr s2rr s2upd202503 s2c s1upd2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-03-01,2025-04-01)| 8.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rr s2rr s2upd20252026 s2c s1upd2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2025-06-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rr s2rr s1upd2025 s1c s2upd2027 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rr s2rr s1upd2025 s1c s2upd202503 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rr s2rr s1upd2025 s1c s2upd20252026 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2025-06-01,2026-01-01)|10.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rr s2rr s2upd2027 s1upd2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s2upd202503 s1upd2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s2upd20252026 s1upd2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2025-06-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1q s2upd2027 s2c s1upd2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1q s2upd202503 s2c s1upd2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1q s2upd20252026 s2c s1upd2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2025-06-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1q s1upd2025 s1c s2upd2027 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rr s2rr s1q s1upd2025 s1c s2upd202503 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rr s2rr s1q s1upd2025 s1c s2upd20252026 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2025-06-01,2026-01-01)|10.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1rr s2rr s1q s2upd2027 s1upd2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1q s2upd202503 s1upd2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1q s2upd20252026 s1upd2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2025-06-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s2del2027 s2c s1upd2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rr s2rr s2del202503 s2c s1upd2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rr s2rr s2del20252026 s2c s1upd2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1upd2025 s1c s2del2027 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rr s2rr s1upd2025 s1c s2del202503 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rr s2rr s1upd2025 s1c s2del20252026 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s2del2027 s1upd2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s2del202503 s1upd2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s2del20252026 s1upd2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1q s2del2027 s2c s1upd2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1q s2del202503 s2c s1upd2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1q s2del20252026 s2c s1upd2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1q s1upd2025 s1c s2del2027 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rr s2rr s1q s1upd2025 s1c s2del202503 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rr s2rr s1q s1upd2025 s1c s2del20252026 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1q s2del2027 s1upd2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1q s2del202503 s1upd2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1q s2del20252026 s1upd2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s2upd2027 s2c s1del2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rr s2rr s2upd202503 s2c s1del2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s2upd20252026 s2c s1del2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1del2025 s1c s2upd2027 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rr s2rr s1del2025 s1c s2upd202503 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1del2025 s1c s2upd20252026 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s2upd2027 s1del2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s2upd202503 s1del2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s2upd20252026 s1del2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2025-06-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1q s2upd2027 s2c s1del2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1q s2upd202503 s2c s1del2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1q s2upd20252026 s2c s1del2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2025-06-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1q s1del2025 s1c s2upd2027 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1rr s2rr s1q s1del2025 s1c s2upd202503 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1q s1del2025 s1c s2upd20252026 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1q s2upd2027 s1del2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1q s2upd202503 s1del2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1q s2upd20252026 s1del2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2025-06-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s2del2027 s2c s1del2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s2del202503 s2c s1del2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s2del20252026 s2c s1del2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1del2025 s1c s2del2027 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1del2025 s1c s2del202503 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1del2025 s1c s2del20252026 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s2del2027 s1del2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s2del202503 s1del2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s2del20252026 s1del2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1q s2del2027 s2c s1del2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1q s2del202503 s2c s1del2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1q s2del20252026 s2c s1del2025 s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1q s1del2025 s1c s2del2027 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1rr s2rr s1q s1del2025 s1c s2del202503 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1q s1del2025 s1c s2del20252026 s2c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1q s2del2027 s1del2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1q s2del202503 s1del2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1rr s2rr s1q s2del20252026 s1del2025 s2c s1c s1q +step s1rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2rr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s2upd2027 s2c s1upd2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1ser s2ser s2upd202503 s2c s1upd2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-03-01,2025-04-01)| 8.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1ser s2ser s2upd20252026 s2c s1upd2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2025-06-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1ser s2ser s1upd2025 s1c s2upd2027 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1ser s2ser s1upd2025 s1c s2upd202503 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1ser s2ser s1upd2025 s1c s2upd20252026 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2025-06-01,2026-01-01)|10.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1ser s2ser s2upd2027 s1upd2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s2upd202503 s1upd2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s2upd20252026 s1upd2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2025-06-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1q s2upd2027 s2c s1upd2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1q s2upd202503 s2c s1upd2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1q s2upd20252026 s2c s1upd2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2025-06-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1q s1upd2025 s1c s2upd2027 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1ser s2ser s1q s1upd2025 s1c s2upd202503 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1ser s2ser s1q s1upd2025 s1c s2upd20252026 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2025-06-01,2026-01-01)|10.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(5 rows) + + +starting permutation: s1ser s2ser s1q s2upd2027 s1upd2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1q s2upd202503 s1upd2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1q s2upd20252026 s1upd2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2025-06-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s2del2027 s2c s1upd2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1ser s2ser s2del202503 s2c s1upd2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1ser s2ser s2del20252026 s2c s1upd2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1upd2025 s1c s2del2027 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1ser s2ser s1upd2025 s1c s2del202503 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1ser s2ser s1upd2025 s1c s2del20252026 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s2del2027 s1upd2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s2del202503 s1upd2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s2del20252026 s1upd2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1q s2del2027 s2c s1upd2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1q s2del202503 s2c s1upd2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1q s2del20252026 s2c s1upd2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1q s1upd2025 s1c s2del2027 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1ser s2ser s1q s1upd2025 s1c s2del202503 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-03-01)| 8.00 +[1,2)|[2025-04-01,2026-01-01)| 8.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1ser s2ser s1q s1upd2025 s1c s2del20252026 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2025-01-01,2025-06-01)| 8.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1q s2del2027 s1upd2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1q s2del202503 s1upd2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1q s2del20252026 s1upd2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s1upd2025: + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1upd2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s2upd2027 s2c s1del2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1ser s2ser s2upd202503 s2c s1del2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s2upd20252026 s2c s1del2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1del2025 s1c s2upd2027 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1ser s2ser s1del2025 s1c s2upd202503 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1del2025 s1c s2upd20252026 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s2upd2027 s1del2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s2upd202503 s1del2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s2upd20252026 s1del2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2025-06-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1q s2upd2027 s2c s1del2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1q s2upd202503 s2c s1del2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1q s2upd20252026 s2c s1del2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2025-06-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1q s1del2025 s1c s2upd2027 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(4 rows) + + +starting permutation: s1ser s2ser s1q s1del2025 s1c s2upd202503 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1q s1del2025 s1c s2upd20252026 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1q s2upd2027 s1del2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd2027: + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2027-01-01,2028-01-01)|10.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1q s2upd202503 s1del2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd202503: + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-03-01,2025-04-01)|10.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1q s2upd20252026 s1del2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2upd20252026: + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent update +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2025-06-01,2026-06-01)|10.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s2del2027 s2c s1del2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s2del202503 s2c s1del2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s2del20252026 s2c s1del2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1del2025 s1c s2del2027 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1del2025 s1c s2del202503 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1del2025 s1c s2del20252026 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s2del2027 s1del2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s2del202503 s1del2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s2del20252026 s1del2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1q s2del2027 s2c s1del2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1q s2del202503 s2c s1del2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1q s2del20252026 s2c s1del2025 s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1q s1del2025 s1c s2del2027 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(3 rows) + + +starting permutation: s1ser s2ser s1q s1del2025 s1c s2del202503 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1q s1del2025 s1c s2del20252026 s2c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s1c: COMMIT; +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-01-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1q s2del2027 s1del2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del2027: + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2027-01-01)| 5.00 +[1,2)|[2028-01-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1q s2del202503 s1del2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del202503: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-03-01)| 5.00 +[1,2)|[2025-04-01,2030-01-01)| 5.00 +(2 rows) + + +starting permutation: s1ser s2ser s1q s2del20252026 s1del2025 s2c s1c s1q +step s1ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2ser: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2030-01-01)| 5.00 +(1 row) + +step s2del20252026: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; + +step s1del2025: + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; + +step s2c: COMMIT; +step s1del2025: <... completed> +ERROR: could not serialize access due to concurrent delete +step s1c: COMMIT; +step s1q: SELECT * FROM products ORDER BY id, valid_at; +id |valid_at |price +-----+-----------------------+----- +[1,2)|[2020-01-01,2025-06-01)| 5.00 +[1,2)|[2026-06-01,2030-01-01)| 5.00 +(2 rows) + diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule index 5afae33d3703..87bbbcabad1f 100644 --- a/src/test/isolation/isolation_schedule +++ b/src/test/isolation/isolation_schedule @@ -120,3 +120,4 @@ test: serializable-parallel-2 test: serializable-parallel-3 test: matview-write-skew test: lock-nowait +test: for-portion-of diff --git a/src/test/isolation/specs/for-portion-of.spec b/src/test/isolation/specs/for-portion-of.spec new file mode 100644 index 000000000000..77656d38ac64 --- /dev/null +++ b/src/test/isolation/specs/for-portion-of.spec @@ -0,0 +1,751 @@ +# UPDATE/DELETE FOR PORTION OF test +# +# Test inserting temporal leftovers from a FOR PORTION OF update/delete. +# +# In READ COMMITTED mode, concurrent updates/deletes to the same records cause +# weird results. Portions of history that should have been updated/deleted don't +# get changed. That's because the leftovers from one operation are added too +# late to be seen by the other. EvalPlanQual will reload the changed-in-common +# row, but it won't re-scan to find new leftovers. +# +# MariaDB similarly gives undesirable results in READ COMMITTED mode (although +# not the same results). DB2 doesn't have READ COMMITTED, but it gives correct +# results at all levels, in particular READ STABILITY (which seems closest). +# +# A workaround is to lock the part of history you want before changing it (using +# SELECT FOR UPDATE). That way the search for rows is late enough to see +# leftovers from the other session(s). This shouldn't impose any new deadlock +# risks, since the locks are the same as before. Adding a third/fourth/etc. +# connection also doesn't change the semantics. The READ COMMITTED tests here +# use that approach to prove that it's viable and isn't vitiated by any bugs. +# Incidentally, this approach also works in MariaDB. +# +# We run the same tests under REPEATABLE READ and SERIALIZABLE. +# In general they do what you'd want with no explicit locking required, but some +# orderings raise a concurrent update/delete failure (as expected). If there is +# a prior read by s1, concurrent update/delete failures are more common. +# +# We test updates where s2 updates history that is: +# +# - non-overlapping with s1, +# - contained entirely in s1, +# - partly contained in s1. +# +# We don't need to test where s2 entirely contains s1 because of symmetry: +# we test both when s1 precedes s2 and when s2 precedes s1, so that scenario is +# covered. +# +# We test various orderings of the update/delete/commit from s1 and s2. +# Note that `s1lock s2lock s1change` is boring because it's the same as +# `s1lock s1change s2lock`. In other words it doesn't matter if something +# interposes between the lock and its change (as long as everyone is following +# the same policy). + +setup +{ + CREATE TABLE products ( + id int4range NOT NULL, + valid_at daterange NOT NULL, + price decimal NOT NULL, + PRIMARY KEY (id, valid_at WITHOUT OVERLAPS)); + INSERT INTO products VALUES + ('[1,2)', '[2020-01-01,2030-01-01)', 5.00); +} + +teardown { DROP TABLE products; } + +session s1 +setup { SET datestyle TO ISO, YMD; } +step s1rc { BEGIN ISOLATION LEVEL READ COMMITTED; } +step s1rr { BEGIN ISOLATION LEVEL REPEATABLE READ; } +step s1ser { BEGIN ISOLATION LEVEL SERIALIZABLE; } +step s1lock2025 { + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-01-01,2026-01-01)' + ORDER BY valid_at FOR UPDATE; +} +step s1upd2025 { + UPDATE products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + SET price = 8.00 + WHERE id = '[1,2)'; +} +step s1del2025 { + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-01-01' TO '2026-01-01' + WHERE id = '[1,2)'; +} +step s1q { SELECT * FROM products ORDER BY id, valid_at; } +step s1c { COMMIT; } + +session s2 +setup { SET datestyle TO ISO, YMD; } +step s2rc { BEGIN ISOLATION LEVEL READ COMMITTED; } +step s2rr { BEGIN ISOLATION LEVEL REPEATABLE READ; } +step s2ser { BEGIN ISOLATION LEVEL SERIALIZABLE; } +step s2lock202503 { + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-03-01,2025-04-01)' + ORDER BY valid_at FOR UPDATE; +} +step s2lock20252026 { + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2025-06-01,2026-06-01)' + ORDER BY valid_at FOR UPDATE; +} +step s2lock2027 { + SELECT * FROM products + WHERE id = '[1,2)' AND valid_at && '[2027-01-01,2028-01-01)' + ORDER BY valid_at FOR UPDATE; +} +step s2upd202503 { + UPDATE products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + SET price = 10.00 + WHERE id = '[1,2)'; +} +step s2upd20252026 { + UPDATE products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + SET price = 10.00 + WHERE id = '[1,2)'; +} +step s2upd2027 { + UPDATE products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + SET price = 10.00 + WHERE id = '[1,2)'; +} +step s2del202503 { + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-03-01' TO '2025-04-01' + WHERE id = '[1,2)'; +} +step s2del20252026 { + DELETE FROM products + FOR PORTION OF valid_at FROM '2025-06-01' TO '2026-06-01' + WHERE id = '[1,2)'; +} +step s2del2027 { + DELETE FROM products + FOR PORTION OF valid_at FROM '2027-01-01' TO '2028-01-01' + WHERE id = '[1,2)'; +} +step s2c { COMMIT; } + +# ######################################## +# READ COMMITTED tests, UPDATE+UPDATE: +# ######################################## + +# s1 sees the leftovers +permutation s1rc s2rc s2lock2027 s2upd2027 s2c s1lock2025 s1upd2025 s1c s1q + +# s1 reloads the updated row and sees its leftovers +permutation s1rc s2rc s2lock202503 s2upd202503 s2c s1lock2025 s1upd2025 s1c s1q + +# s1 reloads the updated row and sees its leftovers +permutation s1rc s2rc s2lock20252026 s2upd20252026 s2c s1lock2025 s1upd2025 s1c s1q + +# s2 sees the leftovers +permutation s1rc s2rc s1lock2025 s1upd2025 s1c s2lock2027 s2upd2027 s2c s1q + +# s2 loads the updated row +permutation s1rc s2rc s1lock2025 s1upd2025 s1c s2lock202503 s2upd202503 s2c s1q + +# s2 loads the updated row and sees its leftovers +permutation s1rc s2rc s1lock2025 s1upd2025 s1c s2lock20252026 s2upd20252026 s2c s1q + +# s1 updates the leftovers from s2 +# Locking is required or s1 won't see the leftovers. +permutation s1rc s2rc s2lock2027 s2upd2027 s1lock2025 s2c s1upd2025 s1c s1q + +# s1 overwrites the row from s2 and sees its leftovers +# Locking is required or s1 won't see the leftovers. +permutation s1rc s2rc s2lock202503 s2upd202503 s1lock2025 s2c s1upd2025 s1c s1q + +# s1 overwrites the row from s2 and sees its leftovers +# Locking is required or s1 won't see the leftovers. +permutation s1rc s2rc s2lock20252026 s2upd20252026 s1lock2025 s2c s1upd2025 s1c s1q + +# ######################################## +# READ COMMITTED tests, UPDATE+DELETE: +# ######################################## + +# s1 sees the leftovers +permutation s1rc s2rc s2lock2027 s2del2027 s2c s1lock2025 s1upd2025 s1c s1q + +# s1 ignores the deleted row and sees its leftovers +permutation s1rc s2rc s2lock202503 s2del202503 s2c s1lock2025 s1upd2025 s1c s1q + +# s1 ignores the deleted row and sees its leftovers +permutation s1rc s2rc s2lock20252026 s2del20252026 s2c s1lock2025 s1upd2025 s1c s1q + +# s2 sees the leftovers +permutation s1rc s2rc s1lock2025 s1upd2025 s1c s2lock2027 s2del2027 s2c s1q + +# s2 loads the updated row +permutation s1rc s2rc s1lock2025 s1upd2025 s1c s2lock202503 s2del202503 s2c s1q + +# s2 loads the updated row and sees its leftovers +permutation s1rc s2rc s1lock2025 s1upd2025 s1c s2lock20252026 s2del20252026 s2c s1q + +# s1 updates the leftovers from s2 +# Locking is required or s1 won't see the leftovers. +permutation s1rc s2rc s2lock2027 s2del2027 s1lock2025 s2c s1upd2025 s1c s1q + +# s1 sees the leftovers from s2 +# Locking is required or s1 won't see the leftovers. +permutation s1rc s2rc s2lock202503 s2del202503 s1lock2025 s2c s1upd2025 s1c s1q + +# s1 sees the leftovers from s2 +# Locking is required or s1 won't see the leftovers. +permutation s1rc s2rc s2lock20252026 s2del20252026 s1lock2025 s2c s1upd2025 s1c s1q + +# ######################################## +# READ COMMITTED tests, DELETE+UPDATE: +# ######################################## + +# s1 sees the leftovers +permutation s1rc s2rc s2lock2027 s2upd2027 s2c s1lock2025 s1del2025 s1c s1q + +# s1 reloads the updated row and sees its leftovers +permutation s1rc s2rc s2lock202503 s2upd202503 s2c s1lock2025 s1del2025 s1c s1q + +# s1 reloads the updated row and sees its leftovers +permutation s1rc s2rc s2lock20252026 s2upd20252026 s2c s1lock2025 s1del2025 s1c s1q + +# s2 sees the leftovers +permutation s1rc s2rc s1lock2025 s1del2025 s1c s2lock2027 s2upd2027 s2c s1q + +# s2 ignores the deleted row +permutation s1rc s2rc s1lock2025 s1del2025 s1c s2lock202503 s2upd202503 s2c s1q + +# s2 ignores the deleted row and sees its leftovers +permutation s1rc s2rc s1lock2025 s1del2025 s1c s2lock20252026 s2upd20252026 s2c s1q + +# s1 deletes the leftovers from s2 +# Locking is required or s1 won't see the leftovers. +permutation s1rc s2rc s2lock2027 s2upd2027 s1lock2025 s2c s1del2025 s1c s1q + +# s1 deletes the new row from s2 and its leftovers +# Locking is required or s1 won't see the leftovers. +permutation s1rc s2rc s2lock202503 s2upd202503 s1lock2025 s2c s1del2025 s1c s1q + +# s1 deletes the new row from s2 and its leftovers +# Locking is required or s1 won't see the leftovers. +permutation s1rc s2rc s2lock20252026 s2upd20252026 s1lock2025 s2c s1del2025 s1c s1q + +# ######################################## +# READ COMMITTED tests, DELETE+DELETE: +# ######################################## + +# s1 sees the leftovers +permutation s1rc s2rc s2lock2027 s2del2027 s2c s1lock2025 s1del2025 s1c s1q + +# s1 ignores the deleted row and sees its leftovers +permutation s1rc s2rc s2lock202503 s2del202503 s2c s1lock2025 s1del2025 s1c s1q + +# s1 ignores the deleted row and sees its leftovers +permutation s1rc s2rc s2lock20252026 s2del20252026 s2c s1lock2025 s1del2025 s1c s1q + +# s2 sees the leftovers +permutation s1rc s2rc s1lock2025 s1del2025 s1c s2lock2027 s2del2027 s2c s1q + +# s2 ignores the deleted row +permutation s1rc s2rc s1lock2025 s1del2025 s1c s2lock202503 s2del202503 s2c s1q + +# s2 ignores the deleted row and sees its leftovers +permutation s1rc s2rc s1lock2025 s1del2025 s1c s2lock20252026 s2del20252026 s2c s1q + +# s1 deletes the leftovers from s2 +# Locking is required or s1 won't see the leftovers. +permutation s1rc s2rc s2lock2027 s2del2027 s1lock2025 s2c s1del2025 s1c s1q + +# s1 deletes the leftovers from s2 +# Locking is required or s1 won't see the leftovers. +permutation s1rc s2rc s2lock202503 s2del202503 s1lock2025 s2c s1del2025 s1c s1q + +# s1 deletes the leftovers from s2 +# Locking is required or s1 won't see the leftovers. +permutation s1rc s2rc s2lock20252026 s2del20252026 s1lock2025 s2c s1del2025 s1c s1q + +# ######################################## +# REPEATABLE READ tests, UPDATE+UPDATE: +# ######################################## + +# s1 sees the leftovers +permutation s1rr s2rr s2upd2027 s2c s1upd2025 s1c s1q + +# s1 reloads the updated row and sees its leftovers +permutation s1rr s2rr s2upd202503 s2c s1upd2025 s1c s1q + +# s1 reloads the updated row and sees its leftovers +permutation s1rr s2rr s2upd20252026 s2c s1upd2025 s1c s1q + +# s2 sees the leftovers +permutation s1rr s2rr s1upd2025 s1c s2upd2027 s2c s1q + +# s2 loads the updated row and sees its leftovers +permutation s1rr s2rr s1upd2025 s1c s2upd202503 s2c s1q + +# s2 loads the updated row and sees its leftovers +permutation s1rr s2rr s1upd2025 s1c s2upd20252026 s2c s1q + +# s1 fails from concurrent update +permutation s1rr s2rr s2upd2027 s1upd2025 s2c s1c s1q + +# s1 fails from concurrent update +permutation s1rr s2rr s2upd202503 s1upd2025 s2c s1c s1q + +# s1 fails from concurrent update +permutation s1rr s2rr s2upd20252026 s1upd2025 s2c s1c s1q + +## with prior read by s1: + +# s1 fails from concurrent update +permutation s1rr s2rr s1q s2upd2027 s2c s1upd2025 s1c s1q + +# s1 fails from concurrent update +permutation s1rr s2rr s1q s2upd202503 s2c s1upd2025 s1c s1q + +# s1 fails from concurrent update +permutation s1rr s2rr s1q s2upd20252026 s2c s1upd2025 s1c s1q + +# s2 sees the leftovers +permutation s1rr s2rr s1q s1upd2025 s1c s2upd2027 s2c s1q + +# s2 loads the updated row +permutation s1rr s2rr s1q s1upd2025 s1c s2upd202503 s2c s1q + +# s2 loads the updated row and sees its leftovers +permutation s1rr s2rr s1q s1upd2025 s1c s2upd20252026 s2c s1q + +# s1 fails from concurrent update +permutation s1rr s2rr s1q s2upd2027 s1upd2025 s2c s1c s1q + +# s1 fails from concurrent update +permutation s1rr s2rr s1q s2upd202503 s1upd2025 s2c s1c s1q + +# s1 fails from concurrent update +permutation s1rr s2rr s1q s2upd20252026 s1upd2025 s2c s1c s1q + +# ######################################## +# REPEATABLE READ tests, UPDATE+DELETE: +# ######################################## + +# s1 sees the leftovers +permutation s1rr s2rr s2del2027 s2c s1upd2025 s1c s1q + +# s1 ignores the deleted row and sees its leftovers +permutation s1rr s2rr s2del202503 s2c s1upd2025 s1c s1q + +# s1 ignores the deleted row and sees its leftovers +permutation s1rr s2rr s2del20252026 s2c s1upd2025 s1c s1q + +# s2 sees the leftovers +permutation s1rr s2rr s1upd2025 s1c s2del2027 s2c s1q + +# s2 loads the updated row +permutation s1rr s2rr s1upd2025 s1c s2del202503 s2c s1q + +# s2 loads the updated row and sees its leftovers +permutation s1rr s2rr s1upd2025 s1c s2del20252026 s2c s1q + +# s1 fails from concurrent delete +permutation s1rr s2rr s2del2027 s1upd2025 s2c s1c s1q + +# s1 fails from concurrent delete +permutation s1rr s2rr s2del202503 s1upd2025 s2c s1c s1q + +# s1 fails from concurrent delete +permutation s1rr s2rr s2del20252026 s1upd2025 s2c s1c s1q + +## with prior read by s1: + +# s1 fails from concurrent delete +permutation s1rr s2rr s1q s2del2027 s2c s1upd2025 s1c s1q + +# s1 fails from concurrent delete +permutation s1rr s2rr s1q s2del202503 s2c s1upd2025 s1c s1q + +# s1 fails from concurrent delete +permutation s1rr s2rr s1q s2del20252026 s2c s1upd2025 s1c s1q + +# s2 sees the leftovers +permutation s1rr s2rr s1q s1upd2025 s1c s2del2027 s2c s1q + +# s2 loads the updated row +permutation s1rr s2rr s1q s1upd2025 s1c s2del202503 s2c s1q + +# s2 loads the updated row and sees its leftovers +permutation s1rr s2rr s1q s1upd2025 s1c s2del20252026 s2c s1q + +# s1 fails from concurrent delete +permutation s1rr s2rr s1q s2del2027 s1upd2025 s2c s1c s1q + +# s1 fails from concurrent delete +permutation s1rr s2rr s1q s2del202503 s1upd2025 s2c s1c s1q + +# s1 fails from concurrent delete +permutation s1rr s2rr s1q s2del20252026 s1upd2025 s2c s1c s1q + +# ######################################## +# REPEATABLE READ tests, DELETE+UPDATE: +# ######################################## + +# s1 sees the leftovers +permutation s1rr s2rr s2upd2027 s2c s1del2025 s1c s1q + +# s1 reloads the updated row and sees its leftovers +permutation s1rr s2rr s2upd202503 s2c s1del2025 s1c s1q + +# s1 reloads the updated row and sees its leftovers +permutation s1rr s2rr s2upd20252026 s2c s1del2025 s1c s1q + +# s2 sees the leftovers +permutation s1rr s2rr s1del2025 s1c s2upd2027 s2c s1q + +# s2 ignores the deleted row +permutation s1rr s2rr s1del2025 s1c s2upd202503 s2c s1q + +# s2 ignores the deleted row and sees its leftovers +permutation s1rr s2rr s1del2025 s1c s2upd20252026 s2c s1q + +# s1 fails from concurrent update +permutation s1rr s2rr s2upd2027 s1del2025 s2c s1c s1q + +# s1 fails from concurrent update +permutation s1rr s2rr s2upd202503 s1del2025 s2c s1c s1q + +# s1 fails from concurrent update +permutation s1rr s2rr s2upd20252026 s1del2025 s2c s1c s1q + +## with prior read by s1: + +# s1 fails from concurrent update +permutation s1rr s2rr s1q s2upd2027 s2c s1del2025 s1c s1q + +# s1 fails from concurrent update +permutation s1rr s2rr s1q s2upd202503 s2c s1del2025 s1c s1q + +# s1 fails from concurrent update +permutation s1rr s2rr s1q s2upd20252026 s2c s1del2025 s1c s1q + +# s2 sees the leftovers +permutation s1rr s2rr s1q s1del2025 s1c s2upd2027 s2c s1q + +# s2 ignores the deleted row +permutation s1rr s2rr s1q s1del2025 s1c s2upd202503 s2c s1q + +# s2 ignores the deleted row and sees its leftovers +permutation s1rr s2rr s1q s1del2025 s1c s2upd20252026 s2c s1q + +# s1 fails from concurrent update +permutation s1rr s2rr s1q s2upd2027 s1del2025 s2c s1c s1q + +# s1 fails from concurrent update +permutation s1rr s2rr s1q s2upd202503 s1del2025 s2c s1c s1q + +# s1 fails from concurrent update +permutation s1rr s2rr s1q s2upd20252026 s1del2025 s2c s1c s1q + +# ######################################## +# REPEATABLE READ tests, DELETE+DELETE: +# ######################################## + +# s1 sees the leftovers +permutation s1rr s2rr s2del2027 s2c s1del2025 s1c s1q + +# s1 reloads the updated row and sees its leftovers +permutation s1rr s2rr s2del202503 s2c s1del2025 s1c s1q + +# s1 reloads the updated row and sees its leftovers +permutation s1rr s2rr s2del20252026 s2c s1del2025 s1c s1q + +# s2 sees the leftovers +permutation s1rr s2rr s1del2025 s1c s2del2027 s2c s1q + +# s2 ignores the deleted row +permutation s1rr s2rr s1del2025 s1c s2del202503 s2c s1q + +# s2 ignores the deleted row and sees its leftovers +permutation s1rr s2rr s1del2025 s1c s2del20252026 s2c s1q + +# s1 fails from concurrent delete +permutation s1rr s2rr s2del2027 s1del2025 s2c s1c s1q + +# s1 fails from concurrent delete +permutation s1rr s2rr s2del202503 s1del2025 s2c s1c s1q + +# s1 fails from concurrent delete +permutation s1rr s2rr s2del20252026 s1del2025 s2c s1c s1q + +## with prior read by s1: + +# s1 fails from concurrent delete +permutation s1rr s2rr s1q s2del2027 s2c s1del2025 s1c s1q + +# s1 fails from concurrent delete +permutation s1rr s2rr s1q s2del202503 s2c s1del2025 s1c s1q + +# s1 fails from concurrent delete +permutation s1rr s2rr s1q s2del20252026 s2c s1del2025 s1c s1q + +# s2 sees the leftovers +permutation s1rr s2rr s1q s1del2025 s1c s2del2027 s2c s1q + +# s2 ignores the deleted row +permutation s1rr s2rr s1q s1del2025 s1c s2del202503 s2c s1q + +# s2 ignores the deleted row and sees its leftovers +permutation s1rr s2rr s1q s1del2025 s1c s2del20252026 s2c s1q + +# s1 fails from concurrent delete +permutation s1rr s2rr s1q s2del2027 s1del2025 s2c s1c s1q + +# s1 fails from concurrent delete +permutation s1rr s2rr s1q s2del202503 s1del2025 s2c s1c s1q + +# s1 fails from concurrent delete +permutation s1rr s2rr s1q s2del20252026 s1del2025 s2c s1c s1q + +# ######################################## +# SERIALIZABLE tests, UPDATE+UPDATE: +# ######################################## + +# s1 sees the leftovers +permutation s1ser s2ser s2upd2027 s2c s1upd2025 s1c s1q + +# s1 reloads the updated row and sees its leftovers +permutation s1ser s2ser s2upd202503 s2c s1upd2025 s1c s1q + +# s1 reloads the updated row and sees its leftovers +permutation s1ser s2ser s2upd20252026 s2c s1upd2025 s1c s1q + +# s2 sees the leftovers +permutation s1ser s2ser s1upd2025 s1c s2upd2027 s2c s1q + +# s2 loads the updated row +permutation s1ser s2ser s1upd2025 s1c s2upd202503 s2c s1q + +# s2 loads the updated row and sees its leftovers +permutation s1ser s2ser s1upd2025 s1c s2upd20252026 s2c s1q + +# s1 fails from concurrent update +permutation s1ser s2ser s2upd2027 s1upd2025 s2c s1c s1q + +# s1 fails from concurrent update +permutation s1ser s2ser s2upd202503 s1upd2025 s2c s1c s1q + +# s1 fails from concurrent update +permutation s1ser s2ser s2upd20252026 s1upd2025 s2c s1c s1q + +## with prior read by s1: + +# s1 fails from concurrent update +permutation s1ser s2ser s1q s2upd2027 s2c s1upd2025 s1c s1q + +# s1 fails from concurrent update +permutation s1ser s2ser s1q s2upd202503 s2c s1upd2025 s1c s1q + +# s1 fails from concurrent update +permutation s1ser s2ser s1q s2upd20252026 s2c s1upd2025 s1c s1q + +# s2 sees the leftovers +permutation s1ser s2ser s1q s1upd2025 s1c s2upd2027 s2c s1q + +# s2 loads the updated row +permutation s1ser s2ser s1q s1upd2025 s1c s2upd202503 s2c s1q + +# s2 loads the updated row and sees its leftovers +permutation s1ser s2ser s1q s1upd2025 s1c s2upd20252026 s2c s1q + +# s1 fails from concurrent update +permutation s1ser s2ser s1q s2upd2027 s1upd2025 s2c s1c s1q + +# s1 fails from concurrent update +permutation s1ser s2ser s1q s2upd202503 s1upd2025 s2c s1c s1q + +# s1 fails from concurrent update +permutation s1ser s2ser s1q s2upd20252026 s1upd2025 s2c s1c s1q + +# ######################################## +# SERIALIZABLE tests, UPDATE+DELETE: +# ######################################## + +# s1 sees the leftovers +permutation s1ser s2ser s2del2027 s2c s1upd2025 s1c s1q + +# s1 ignores the deleted row and sees its leftovers +permutation s1ser s2ser s2del202503 s2c s1upd2025 s1c s1q + +# s1 ignores the deleted row and sees its leftovers +permutation s1ser s2ser s2del20252026 s2c s1upd2025 s1c s1q + +# s2 sees the leftovers +permutation s1ser s2ser s1upd2025 s1c s2del2027 s2c s1q + +# s2 loads the updated row +permutation s1ser s2ser s1upd2025 s1c s2del202503 s2c s1q + +# s2 loads the updated row and sees its leftovers +permutation s1ser s2ser s1upd2025 s1c s2del20252026 s2c s1q + +# s1 fails from concurrent delete +permutation s1ser s2ser s2del2027 s1upd2025 s2c s1c s1q + +# s1 fails from concurrent delete +permutation s1ser s2ser s2del202503 s1upd2025 s2c s1c s1q + +# s1 fails from concurrent delete +permutation s1ser s2ser s2del20252026 s1upd2025 s2c s1c s1q + +## with prior read by s1: + +# s1 fails from concurrent delete +permutation s1ser s2ser s1q s2del2027 s2c s1upd2025 s1c s1q + +# s1 fails from concurrent delete +permutation s1ser s2ser s1q s2del202503 s2c s1upd2025 s1c s1q + +# s1 fails from concurrent delete +permutation s1ser s2ser s1q s2del20252026 s2c s1upd2025 s1c s1q + +# s2 sees the leftovers +permutation s1ser s2ser s1q s1upd2025 s1c s2del2027 s2c s1q + +# s2 loads the updated row +permutation s1ser s2ser s1q s1upd2025 s1c s2del202503 s2c s1q + +# s2 loads the updated row and sees its leftovers +permutation s1ser s2ser s1q s1upd2025 s1c s2del20252026 s2c s1q + +# s1 fails from concurrent delete +permutation s1ser s2ser s1q s2del2027 s1upd2025 s2c s1c s1q + +# s1 fails from concurrent delete +permutation s1ser s2ser s1q s2del202503 s1upd2025 s2c s1c s1q + +# s1 fails from concurrent delete +permutation s1ser s2ser s1q s2del20252026 s1upd2025 s2c s1c s1q + +# ######################################## +# SERIALIZABLE tests, DELETE+UPDATE: +# ######################################## + +# s1 sees the leftovers +permutation s1ser s2ser s2upd2027 s2c s1del2025 s1c s1q + +# s1 reloads the updated row and sees its leftovers +permutation s1ser s2ser s2upd202503 s2c s1del2025 s1c s1q + +# s1 reloads the updated row and sees its leftovers +permutation s1ser s2ser s2upd20252026 s2c s1del2025 s1c s1q + +# s2 sees the leftovers +permutation s1ser s2ser s1del2025 s1c s2upd2027 s2c s1q + +# s2 ignores the deleted row +permutation s1ser s2ser s1del2025 s1c s2upd202503 s2c s1q + +# s2 ignores the deleted row and sees its leftovers +permutation s1ser s2ser s1del2025 s1c s2upd20252026 s2c s1q + +# s1 fails from concurrent update +permutation s1ser s2ser s2upd2027 s1del2025 s2c s1c s1q + +# s1 fails from concurrent update +permutation s1ser s2ser s2upd202503 s1del2025 s2c s1c s1q + +# s1 fails from concurrent update +permutation s1ser s2ser s2upd20252026 s1del2025 s2c s1c s1q + +## with prior read by s1: + +# s1 fails from concurrent update +permutation s1ser s2ser s1q s2upd2027 s2c s1del2025 s1c s1q + +# s1 fails from concurrent update +permutation s1ser s2ser s1q s2upd202503 s2c s1del2025 s1c s1q + +# s1 fails from concurrent update +permutation s1ser s2ser s1q s2upd20252026 s2c s1del2025 s1c s1q + +# s2 sees the leftovers +permutation s1ser s2ser s1q s1del2025 s1c s2upd2027 s2c s1q + +# s2 ignores the deleted row +permutation s1ser s2ser s1q s1del2025 s1c s2upd202503 s2c s1q + +# s2 ignores the deleted row and sees its leftovers +permutation s1ser s2ser s1q s1del2025 s1c s2upd20252026 s2c s1q + +# s1 fails from concurrent update +permutation s1ser s2ser s1q s2upd2027 s1del2025 s2c s1c s1q + +# s1 fails from concurrent update +permutation s1ser s2ser s1q s2upd202503 s1del2025 s2c s1c s1q + +# s1 fails from concurrent update +permutation s1ser s2ser s1q s2upd20252026 s1del2025 s2c s1c s1q + +# ######################################## +# SERIALIZABLE tests, DELETE+DELETE: +# ######################################## + +# s1 sees the leftovers +permutation s1ser s2ser s2del2027 s2c s1del2025 s1c s1q + +# s1 ignores the deleted row and sees its leftovers +permutation s1ser s2ser s2del202503 s2c s1del2025 s1c s1q + +# s1 ignores the deleted row and sees its leftovers +permutation s1ser s2ser s2del20252026 s2c s1del2025 s1c s1q + +# s2 sees the leftovers +permutation s1ser s2ser s1del2025 s1c s2del2027 s2c s1q + +# s2 ignores the deleted row +permutation s1ser s2ser s1del2025 s1c s2del202503 s2c s1q + +# s2 ignores the deleted row and sees its leftovers +permutation s1ser s2ser s1del2025 s1c s2del20252026 s2c s1q + +# s1 fails from concurrent delete +permutation s1ser s2ser s2del2027 s1del2025 s2c s1c s1q + +# s1 fails from concurrent delete +permutation s1ser s2ser s2del202503 s1del2025 s2c s1c s1q + +# s1 fails from concurrent delete +permutation s1ser s2ser s2del20252026 s1del2025 s2c s1c s1q + +# with prior read by s1: + +# s1 fails from concurrent delete +permutation s1ser s2ser s1q s2del2027 s2c s1del2025 s1c s1q + +# s1 fails from concurrent delete +permutation s1ser s2ser s1q s2del202503 s2c s1del2025 s1c s1q + +# s1 fails from concurrent delete +permutation s1ser s2ser s1q s2del20252026 s2c s1del2025 s1c s1q + +# s2 sees the leftovers +permutation s1ser s2ser s1q s1del2025 s1c s2del2027 s2c s1q + +# s2 ignores the deleted row +permutation s1ser s2ser s1q s1del2025 s1c s2del202503 s2c s1q + +# s2 ignores the deleted row and sees its leftovers +permutation s1ser s2ser s1q s1del2025 s1c s2del20252026 s2c s1q + +# s1 fails from concurrent delete +permutation s1ser s2ser s1q s2del2027 s1del2025 s2c s1c s1q + +# s1 fails from concurrent delete +permutation s1ser s2ser s1q s2del202503 s1del2025 s2c s1c s1q + +# s1 fails from concurrent delete +permutation s1ser s2ser s1q s2del20252026 s1del2025 s2c s1c s1q + From 20aa341cf738863a602f1c68339ed9aa7a03ccf6 Mon Sep 17 00:00:00 2001 From: "Paul A. Jungwirth" Date: Fri, 13 Jun 2025 15:40:06 -0700 Subject: [PATCH 07/11] Add tg_temporal to TriggerData This needs to be passed to our RI triggers to implement temporal CASCADE/SET NULL/SET DEFAULT when the user command is an UPDATE/DELETE FOR PORTION OF. The triggers will use the FOR PORTION OF bounds to avoid over-applying the change to referencing records. Probably it is useful for user-defined triggers as well, for example auditing or trigger-based replication. Author: Paul A. Jungwirth --- doc/src/sgml/trigger.sgml | 56 +++++++++++++++++++++++++------- src/backend/commands/tablecmds.c | 1 + src/backend/commands/trigger.c | 51 +++++++++++++++++++++++++++++ src/include/commands/trigger.h | 1 + 4 files changed, 98 insertions(+), 11 deletions(-) diff --git a/doc/src/sgml/trigger.sgml b/doc/src/sgml/trigger.sgml index e3ad98065282..0044a97a3fd9 100644 --- a/doc/src/sgml/trigger.sgml +++ b/doc/src/sgml/trigger.sgml @@ -563,17 +563,18 @@ CALLED_AS_TRIGGER(fcinfo) typedef struct TriggerData { - NodeTag type; - TriggerEvent tg_event; - Relation tg_relation; - HeapTuple tg_trigtuple; - HeapTuple tg_newtuple; - Trigger *tg_trigger; - TupleTableSlot *tg_trigslot; - TupleTableSlot *tg_newslot; - Tuplestorestate *tg_oldtable; - Tuplestorestate *tg_newtable; - const Bitmapset *tg_updatedcols; + NodeTag type; + TriggerEvent tg_event; + Relation tg_relation; + HeapTuple tg_trigtuple; + HeapTuple tg_newtuple; + Trigger *tg_trigger; + TupleTableSlot *tg_trigslot; + TupleTableSlot *tg_newslot; + Tuplestorestate *tg_oldtable; + Tuplestorestate *tg_newtable; + const Bitmapset *tg_updatedcols; + ForPortionOfState *tg_temporal; } TriggerData; @@ -841,6 +842,39 @@ typedef struct Trigger + + + tg_temporal + + + Set for UPDATE and DELETE queries + that use FOR PORTION OF, otherwise NULL. + Contains a pointer to a structure of type + ForPortionOfState, defined in + nodes/execnodes.h: + + +typedef struct ForPortionOfState +{ + NodeTag type; + + char *fp_rangeName; /* the column named in FOR PORTION OF */ + Oid fp_rangeType; /* the type of the FOR PORTION OF expression */ + int fp_rangeAttno; /* the attno of the range column */ + Datum fp_targetRange; /* the range/multirange from FOR PORTION OF */ + TypeCacheEntry *fp_leftoverstypcache; /* type cache entry of the range */ +} ForPortionOfState; + + + where fp_rangeName is the range + column named in the FOR PORTION OF clause, + fp_rangeType is its range type, + fp_rangeAttno is its attribute number, + and fp_targetRange is a rangetype value created + by evaluating the FOR PORTION OF bounds. + + + diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c index 3aac459e483d..1b614bd6ce2a 100644 --- a/src/backend/commands/tablecmds.c +++ b/src/backend/commands/tablecmds.c @@ -13760,6 +13760,7 @@ validateForeignKeyConstraint(char *conname, trigdata.tg_trigtuple = ExecFetchSlotHeapTuple(slot, false, NULL); trigdata.tg_trigslot = slot; trigdata.tg_trigger = &trig; + trigdata.tg_temporal = NULL; fcinfo->context = (Node *) &trigdata; diff --git a/src/backend/commands/trigger.c b/src/backend/commands/trigger.c index 579ac8d76ae7..43b9d82e63a6 100644 --- a/src/backend/commands/trigger.c +++ b/src/backend/commands/trigger.c @@ -47,12 +47,14 @@ #include "storage/lmgr.h" #include "utils/acl.h" #include "utils/builtins.h" +#include "utils/datum.h" #include "utils/fmgroids.h" #include "utils/guc_hooks.h" #include "utils/inval.h" #include "utils/lsyscache.h" #include "utils/memutils.h" #include "utils/plancache.h" +#include "utils/rangetypes.h" #include "utils/rel.h" #include "utils/snapmgr.h" #include "utils/syscache.h" @@ -2649,6 +2651,7 @@ ExecBSDeleteTriggers(EState *estate, ResultRelInfo *relinfo) LocTriggerData.tg_event = TRIGGER_EVENT_DELETE | TRIGGER_EVENT_BEFORE; LocTriggerData.tg_relation = relinfo->ri_RelationDesc; + LocTriggerData.tg_temporal = relinfo->ri_forPortionOf; for (i = 0; i < trigdesc->numtriggers; i++) { Trigger *trigger = &trigdesc->triggers[i]; @@ -2757,6 +2760,7 @@ ExecBRDeleteTriggers(EState *estate, EPQState *epqstate, TRIGGER_EVENT_ROW | TRIGGER_EVENT_BEFORE; LocTriggerData.tg_relation = relinfo->ri_RelationDesc; + LocTriggerData.tg_temporal = relinfo->ri_forPortionOf; for (i = 0; i < trigdesc->numtriggers; i++) { HeapTuple newtuple; @@ -2858,6 +2862,7 @@ ExecIRDeleteTriggers(EState *estate, ResultRelInfo *relinfo, TRIGGER_EVENT_ROW | TRIGGER_EVENT_INSTEAD; LocTriggerData.tg_relation = relinfo->ri_RelationDesc; + LocTriggerData.tg_temporal = relinfo->ri_forPortionOf; ExecForceStoreHeapTuple(trigtuple, slot, false); @@ -2921,6 +2926,7 @@ ExecBSUpdateTriggers(EState *estate, ResultRelInfo *relinfo) TRIGGER_EVENT_BEFORE; LocTriggerData.tg_relation = relinfo->ri_RelationDesc; LocTriggerData.tg_updatedcols = updatedCols; + LocTriggerData.tg_temporal = relinfo->ri_forPortionOf; for (i = 0; i < trigdesc->numtriggers; i++) { Trigger *trigger = &trigdesc->triggers[i]; @@ -3064,6 +3070,7 @@ ExecBRUpdateTriggers(EState *estate, EPQState *epqstate, TRIGGER_EVENT_ROW | TRIGGER_EVENT_BEFORE; LocTriggerData.tg_relation = relinfo->ri_RelationDesc; + LocTriggerData.tg_temporal = relinfo->ri_forPortionOf; updatedCols = ExecGetAllUpdatedCols(relinfo, estate); LocTriggerData.tg_updatedcols = updatedCols; for (i = 0; i < trigdesc->numtriggers; i++) @@ -3226,6 +3233,7 @@ ExecIRUpdateTriggers(EState *estate, ResultRelInfo *relinfo, TRIGGER_EVENT_ROW | TRIGGER_EVENT_INSTEAD; LocTriggerData.tg_relation = relinfo->ri_RelationDesc; + LocTriggerData.tg_temporal = relinfo->ri_forPortionOf; ExecForceStoreHeapTuple(trigtuple, oldslot, false); @@ -3697,6 +3705,7 @@ typedef struct AfterTriggerSharedData Oid ats_relid; /* the relation it's on */ Oid ats_rolid; /* role to execute the trigger */ CommandId ats_firing_id; /* ID for firing cycle */ + ForPortionOfState *for_portion_of; /* the FOR PORTION OF clause */ struct AfterTriggersTableData *ats_table; /* transition table access */ Bitmapset *ats_modifiedcols; /* modified columns */ } AfterTriggerSharedData; @@ -3970,6 +3979,7 @@ static SetConstraintState SetConstraintStateCreate(int numalloc); static SetConstraintState SetConstraintStateCopy(SetConstraintState origstate); static SetConstraintState SetConstraintStateAddItem(SetConstraintState state, Oid tgoid, bool tgisdeferred); +static ForPortionOfState *CopyForPortionOfState(ForPortionOfState *src); static void cancel_prior_stmt_triggers(Oid relid, CmdType cmdType, int tgevent); @@ -4177,6 +4187,7 @@ afterTriggerAddEvent(AfterTriggerEventList *events, newshared->ats_event == evtshared->ats_event && newshared->ats_firing_id == 0 && newshared->ats_table == evtshared->ats_table && + newshared->for_portion_of == evtshared->for_portion_of && newshared->ats_relid == evtshared->ats_relid && newshared->ats_rolid == evtshared->ats_rolid && bms_equal(newshared->ats_modifiedcols, @@ -4553,6 +4564,9 @@ AfterTriggerExecute(EState *estate, LocTriggerData.tg_relation = rel; if (TRIGGER_FOR_UPDATE(LocTriggerData.tg_trigger->tgtype)) LocTriggerData.tg_updatedcols = evtshared->ats_modifiedcols; + if (TRIGGER_FOR_UPDATE(LocTriggerData.tg_trigger->tgtype) || + TRIGGER_FOR_DELETE(LocTriggerData.tg_trigger->tgtype)) + LocTriggerData.tg_temporal = evtshared->for_portion_of; MemoryContextReset(per_tuple_context); @@ -6102,6 +6116,42 @@ AfterTriggerPendingOnRel(Oid relid) return false; } +/* ---------- + * ForPortionOfState() + * + * Copys a ForPortionOfState into the current memory context. + */ +static ForPortionOfState * +CopyForPortionOfState(ForPortionOfState *src) +{ + ForPortionOfState *dst = NULL; + + if (src) + { + MemoryContext oldctx; + RangeType *r; + TypeCacheEntry *typcache; + + /* + * Need to lift the FOR PORTION OF details into a higher memory + * context because cascading foreign key update/deletes can cause + * triggers to fire triggers, and the AfterTriggerEvents will outlive + * the FPO details of the original query. + */ + oldctx = MemoryContextSwitchTo(TopTransactionContext); + dst = makeNode(ForPortionOfState); + dst->fp_rangeName = pstrdup(src->fp_rangeName); + dst->fp_rangeType = src->fp_rangeType; + dst->fp_rangeAttno = src->fp_rangeAttno; + + r = DatumGetRangeTypeP(src->fp_targetRange); + typcache = lookup_type_cache(RangeTypeGetOid(r), TYPECACHE_RANGE_INFO); + dst->fp_targetRange = datumCopy(src->fp_targetRange, typcache->typbyval, typcache->typlen); + MemoryContextSwitchTo(oldctx); + } + return dst; +} + /* ---------- * AfterTriggerSaveEvent() * @@ -6518,6 +6568,7 @@ AfterTriggerSaveEvent(EState *estate, ResultRelInfo *relinfo, else new_shared.ats_table = NULL; new_shared.ats_modifiedcols = modifiedCols; + new_shared.for_portion_of = CopyForPortionOfState(relinfo->ri_forPortionOf); afterTriggerAddEvent(&afterTriggers.query_stack[afterTriggers.query_depth].events, &new_event, &new_shared); diff --git a/src/include/commands/trigger.h b/src/include/commands/trigger.h index cfd7daa20eda..c67e1324391e 100644 --- a/src/include/commands/trigger.h +++ b/src/include/commands/trigger.h @@ -41,6 +41,7 @@ typedef struct TriggerData Tuplestorestate *tg_oldtable; Tuplestorestate *tg_newtable; const Bitmapset *tg_updatedcols; + ForPortionOfState *tg_temporal; } TriggerData; /* From 44cdb883bfe980566028d1aef3c15d5727fd81fc Mon Sep 17 00:00:00 2001 From: "Paul A. Jungwirth" Date: Fri, 13 Jun 2025 16:11:47 -0700 Subject: [PATCH 08/11] Look up more temporal foreign key helper procs To implement CASCADE/SET NULL/SET DEFAULT on temporal foreign keys, we need an intersect function and a minus set-returning function. We can look them up when we look up the operators already needed for temporal foreign keys (including NO ACTION constraints). Author: Paul A. Jungwirth --- src/backend/catalog/pg_constraint.c | 36 +++++++++++++++++++++++++---- src/backend/commands/tablecmds.c | 6 +++-- src/backend/parser/analyze.c | 2 +- src/backend/utils/adt/ri_triggers.c | 12 ++++++---- src/include/catalog/pg_constraint.h | 10 ++++---- 5 files changed, 50 insertions(+), 16 deletions(-) diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c index 9944e4bd2d10..77152252ea1c 100644 --- a/src/backend/catalog/pg_constraint.c +++ b/src/backend/catalog/pg_constraint.c @@ -1635,7 +1635,7 @@ DeconstructFkConstraintRow(HeapTuple tuple, int *numfks, } /* - * FindFKPeriodOpers - + * FindFKPeriodOpersAndProcs - * * Looks up the operator oids used for the PERIOD part of a temporal foreign key. * The opclass should be the opclass of that PERIOD element. @@ -1646,12 +1646,19 @@ DeconstructFkConstraintRow(HeapTuple tuple, int *numfks, * That way foreign keys can compare fkattr <@ range_agg(pkattr). * intersectoperoid is used by NO ACTION constraints to trim the range being considered * to just what was updated/deleted. + * intersectprocoid is used to limit the effect of CASCADE/SET NULL/SET DEFAULT + * when the PK record is changed with FOR PORTION OF. + * withoutportionoid is a set-returning function computing + * the difference between one range and another, + * returning each result range in a separate row. */ void -FindFKPeriodOpers(Oid opclass, - Oid *containedbyoperoid, - Oid *aggedcontainedbyoperoid, - Oid *intersectoperoid) +FindFKPeriodOpersAndProcs(Oid opclass, + Oid *containedbyoperoid, + Oid *aggedcontainedbyoperoid, + Oid *intersectoperoid, + Oid *intersectprocoid, + Oid *withoutportionoid) { Oid opfamily = InvalidOid; Oid opcintype = InvalidOid; @@ -1693,6 +1700,17 @@ FindFKPeriodOpers(Oid opclass, aggedcontainedbyoperoid, &strat); + /* + * Hardcode intersect operators for ranges and multiranges, because we + * don't have a better way to look up operators that aren't used in + * indexes. + * + * If you change this code, you must change the code in + * transformForPortionOfClause. + * + * XXX: Find a more extensible way to look up the operator, permitting + * user-defined types. + */ switch (opcintype) { case ANYRANGEOID: @@ -1704,6 +1722,14 @@ FindFKPeriodOpers(Oid opclass, default: elog(ERROR, "unexpected opcintype: %u", opcintype); } + + /* + * Look up the intersect proc. We use this for FOR PORTION OF (both the + * operation itself and when checking foreign keys). If this is missing we + * don't need to complain here, because FOR PORTION OF will not be + * allowed. + */ + *intersectprocoid = get_opcode(*intersectoperoid); } /* diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c index 1b614bd6ce2a..8399d8786a27 100644 --- a/src/backend/commands/tablecmds.c +++ b/src/backend/commands/tablecmds.c @@ -10564,9 +10564,11 @@ ATAddForeignKeyConstraint(List **wqueue, AlteredTableInfo *tab, Relation rel, Oid periodoperoid; Oid aggedperiodoperoid; Oid intersectoperoid; + Oid intersectprocoid; + Oid withoutoverlapsoid; - FindFKPeriodOpers(opclasses[numpks - 1], &periodoperoid, &aggedperiodoperoid, - &intersectoperoid); + FindFKPeriodOpersAndProcs(opclasses[numpks - 1], &periodoperoid, &aggedperiodoperoid, + &intersectoperoid, &intersectprocoid, &withoutoverlapsoid); } /* First, create the constraint catalog entry itself. */ diff --git a/src/backend/parser/analyze.c b/src/backend/parser/analyze.c index 5cf73278e16f..a542c81b45fa 100644 --- a/src/backend/parser/analyze.c +++ b/src/backend/parser/analyze.c @@ -1445,7 +1445,7 @@ transformForPortionOfClause(ParseState *pstate, /* * Whatever operator is used for intersect by temporal foreign keys, * we can use its backing procedure for intersects in FOR PORTION OF. - * XXX: Share code with FindFKPeriodOpers? + * XXX: Share code with FindFKPeriodOpersAndProcs? */ switch (opcintype) { diff --git a/src/backend/utils/adt/ri_triggers.c b/src/backend/utils/adt/ri_triggers.c index d6b1eb57a489..fc8d59e0f476 100644 --- a/src/backend/utils/adt/ri_triggers.c +++ b/src/backend/utils/adt/ri_triggers.c @@ -129,6 +129,8 @@ typedef struct RI_ConstraintInfo Oid period_contained_by_oper; /* anyrange <@ anyrange */ Oid agged_period_contained_by_oper; /* fkattr <@ range_agg(pkattr) */ Oid period_intersect_oper; /* anyrange * anyrange (or multirange) */ + Oid period_intersect_proc; /* anyrange * anyrange (or multirange) */ + Oid without_portion_proc; /* anyrange - anyrange SRF */ dlist_node valid_link; /* Link in list of valid entries */ } RI_ConstraintInfo; @@ -2337,10 +2339,12 @@ ri_LoadConstraintInfo(Oid constraintOid) { Oid opclass = get_index_column_opclass(conForm->conindid, riinfo->nkeys); - FindFKPeriodOpers(opclass, - &riinfo->period_contained_by_oper, - &riinfo->agged_period_contained_by_oper, - &riinfo->period_intersect_oper); + FindFKPeriodOpersAndProcs(opclass, + &riinfo->period_contained_by_oper, + &riinfo->agged_period_contained_by_oper, + &riinfo->period_intersect_oper, + &riinfo->period_intersect_proc, + &riinfo->without_portion_proc); } ReleaseSysCache(tup); diff --git a/src/include/catalog/pg_constraint.h b/src/include/catalog/pg_constraint.h index 4afceb5c692d..f8a01d896179 100644 --- a/src/include/catalog/pg_constraint.h +++ b/src/include/catalog/pg_constraint.h @@ -288,10 +288,12 @@ extern void DeconstructFkConstraintRow(HeapTuple tuple, int *numfks, AttrNumber *conkey, AttrNumber *confkey, Oid *pf_eq_oprs, Oid *pp_eq_oprs, Oid *ff_eq_oprs, int *num_fk_del_set_cols, AttrNumber *fk_del_set_cols); -extern void FindFKPeriodOpers(Oid opclass, - Oid *containedbyoperoid, - Oid *aggedcontainedbyoperoid, - Oid *intersectoperoid); +extern void FindFKPeriodOpersAndProcs(Oid opclass, + Oid *containedbyoperoid, + Oid *aggedcontainedbyoperoid, + Oid *intersectoperoid, + Oid *intersectprocoid, + Oid *withoutportionoid); extern bool check_functional_grouping(Oid relid, Index varno, Index varlevelsup, From e723de19ea51bb1a749ca6d7ba6b56ace2adc95b Mon Sep 17 00:00:00 2001 From: "Paul A. Jungwirth" Date: Sat, 3 Jun 2023 21:41:11 -0400 Subject: [PATCH 09/11] Add CASCADE/SET NULL/SET DEFAULT for temporal foreign keys Previously we raised an error for these options, because their implementations require FOR PORTION OF. Now that we have temporal UPDATE/DELETE, we can implement foreign keys that use it. Author: Paul A. Jungwirth --- doc/src/sgml/ddl.sgml | 6 +- doc/src/sgml/ref/create_table.sgml | 14 +- src/backend/commands/tablecmds.c | 65 +- src/backend/utils/adt/ri_triggers.c | 617 ++++++- src/include/catalog/pg_proc.dat | 22 + src/test/regress/expected/btree_index.out | 18 +- .../regress/expected/without_overlaps.out | 1594 ++++++++++++++++- src/test/regress/sql/without_overlaps.sql | 900 +++++++++- 8 files changed, 3184 insertions(+), 52 deletions(-) diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index 53d849bf34ca..13c174b47a97 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -1850,9 +1850,9 @@ ALTER TABLE variants PostgreSQL supports NO ACTION - temporal foreign keys, but not RESTRICT, - CASCADE, SET NULL, or - SET DEFAULT. + CASCADE, SET NULL, and + SET DEFAULT temporal foreign keys, + but not RESTRICT. diff --git a/doc/src/sgml/ref/create_table.sgml b/doc/src/sgml/ref/create_table.sgml index a157a244e4ef..975d5daa0c16 100644 --- a/doc/src/sgml/ref/create_table.sgml +++ b/doc/src/sgml/ref/create_table.sgml @@ -1315,7 +1315,9 @@ WITH ( MODULUS numeric_literal, REM - In a temporal foreign key, this option is not supported. + In a temporal foreign key, the delete/update will use + FOR PORTION OF semantics to constrain the + effect to the bounds being deleted/updated in the referenced row. @@ -1330,7 +1332,10 @@ WITH ( MODULUS numeric_literal, REM - In a temporal foreign key, this option is not supported. + In a temporal foreign key, the change will use FOR PORTION + OF semantics to constrain the effect to the bounds being + deleted/updated in the referenced row. The column maked with + PERIOD will not be set to null. @@ -1347,7 +1352,10 @@ WITH ( MODULUS numeric_literal, REM - In a temporal foreign key, this option is not supported. + In a temporal foreign key, the change will use FOR PORTION + OF semantics to constrain the effect to the bounds being + deleted/updated in the referenced row. The column marked with + PERIOD with not be set to a default value. diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c index 8399d8786a27..7a917b31ed9c 100644 --- a/src/backend/commands/tablecmds.c +++ b/src/backend/commands/tablecmds.c @@ -562,7 +562,7 @@ static ObjectAddress ATAddForeignKeyConstraint(List **wqueue, AlteredTableInfo * Relation rel, Constraint *fkconstraint, bool recurse, bool recursing, LOCKMODE lockmode); -static int validateFkOnDeleteSetColumns(int numfks, const int16 *fkattnums, +static int validateFkOnDeleteSetColumns(int numfks, const int16 *fkattnums, const int16 fkperiodattnum, int numfksetcols, int16 *fksetcolsattnums, List *fksetcols); static ObjectAddress addFkConstraint(addFkConstraintSides fkside, @@ -10074,6 +10074,7 @@ ATAddForeignKeyConstraint(List **wqueue, AlteredTableInfo *tab, Relation rel, int16 fkdelsetcols[INDEX_MAX_KEYS] = {0}; bool with_period; bool pk_has_without_overlaps; + int16 fkperiodattnum = InvalidAttrNumber; int i; int numfks, numpks, @@ -10159,15 +10160,20 @@ ATAddForeignKeyConstraint(List **wqueue, AlteredTableInfo *tab, Relation rel, fkconstraint->fk_attrs, fkattnum, fktypoid, fkcolloid); with_period = fkconstraint->fk_with_period || fkconstraint->pk_with_period; - if (with_period && !fkconstraint->fk_with_period) - ereport(ERROR, - errcode(ERRCODE_INVALID_FOREIGN_KEY), - errmsg("foreign key uses PERIOD on the referenced table but not the referencing table")); + if (with_period) + { + if (!fkconstraint->fk_with_period) + ereport(ERROR, + (errcode(ERRCODE_INVALID_FOREIGN_KEY), + errmsg("foreign key uses PERIOD on the referenced table but not the referencing table"))); + fkperiodattnum = fkattnum[numfks - 1]; + } numfkdelsetcols = transformColumnNameList(RelationGetRelid(rel), fkconstraint->fk_del_set_cols, fkdelsetcols, NULL, NULL); numfkdelsetcols = validateFkOnDeleteSetColumns(numfks, fkattnum, + fkperiodattnum, numfkdelsetcols, fkdelsetcols, fkconstraint->fk_del_set_cols); @@ -10269,19 +10275,13 @@ ATAddForeignKeyConstraint(List **wqueue, AlteredTableInfo *tab, Relation rel, */ if (fkconstraint->fk_with_period) { - if (fkconstraint->fk_upd_action == FKCONSTR_ACTION_RESTRICT || - fkconstraint->fk_upd_action == FKCONSTR_ACTION_CASCADE || - fkconstraint->fk_upd_action == FKCONSTR_ACTION_SETNULL || - fkconstraint->fk_upd_action == FKCONSTR_ACTION_SETDEFAULT) + if (fkconstraint->fk_upd_action == FKCONSTR_ACTION_RESTRICT) ereport(ERROR, errcode(ERRCODE_FEATURE_NOT_SUPPORTED), errmsg("unsupported %s action for foreign key constraint using PERIOD", "ON UPDATE")); - if (fkconstraint->fk_del_action == FKCONSTR_ACTION_RESTRICT || - fkconstraint->fk_del_action == FKCONSTR_ACTION_CASCADE || - fkconstraint->fk_del_action == FKCONSTR_ACTION_SETNULL || - fkconstraint->fk_del_action == FKCONSTR_ACTION_SETDEFAULT) + if (fkconstraint->fk_del_action == FKCONSTR_ACTION_RESTRICT) ereport(ERROR, errcode(ERRCODE_FEATURE_NOT_SUPPORTED), errmsg("unsupported %s action for foreign key constraint using PERIOD", @@ -10638,6 +10638,7 @@ ATAddForeignKeyConstraint(List **wqueue, AlteredTableInfo *tab, Relation rel, */ static int validateFkOnDeleteSetColumns(int numfks, const int16 *fkattnums, + const int16 fkperiodattnum, int numfksetcols, int16 *fksetcolsattnums, List *fksetcols) { @@ -10651,6 +10652,14 @@ validateFkOnDeleteSetColumns(int numfks, const int16 *fkattnums, /* Make sure it's in fkattnums[] */ for (int j = 0; j < numfks; j++) { + if (fkperiodattnum == setcol_attnum) + { + char *col = strVal(list_nth(fksetcols, i)); + + ereport(ERROR, + (errcode(ERRCODE_INVALID_COLUMN_REFERENCE), + errmsg("column \"%s\" referenced in ON DELETE SET action cannot be PERIOD", col))); + } if (fkattnums[j] == setcol_attnum) { seen = true; @@ -13890,17 +13899,26 @@ createForeignKeyActionTriggers(Oid myRelOid, Oid refRelOid, Constraint *fkconstr case FKCONSTR_ACTION_CASCADE: fk_trigger->deferrable = false; fk_trigger->initdeferred = false; - fk_trigger->funcname = SystemFuncName("RI_FKey_cascade_del"); + if (fkconstraint->fk_with_period) + fk_trigger->funcname = SystemFuncName("RI_FKey_period_cascade_del"); + else + fk_trigger->funcname = SystemFuncName("RI_FKey_cascade_del"); break; case FKCONSTR_ACTION_SETNULL: fk_trigger->deferrable = false; fk_trigger->initdeferred = false; - fk_trigger->funcname = SystemFuncName("RI_FKey_setnull_del"); + if (fkconstraint->fk_with_period) + fk_trigger->funcname = SystemFuncName("RI_FKey_period_setnull_del"); + else + fk_trigger->funcname = SystemFuncName("RI_FKey_setnull_del"); break; case FKCONSTR_ACTION_SETDEFAULT: fk_trigger->deferrable = false; fk_trigger->initdeferred = false; - fk_trigger->funcname = SystemFuncName("RI_FKey_setdefault_del"); + if (fkconstraint->fk_with_period) + fk_trigger->funcname = SystemFuncName("RI_FKey_period_setdefault_del"); + else + fk_trigger->funcname = SystemFuncName("RI_FKey_setdefault_del"); break; default: elog(ERROR, "unrecognized FK action type: %d", @@ -13950,17 +13968,26 @@ createForeignKeyActionTriggers(Oid myRelOid, Oid refRelOid, Constraint *fkconstr case FKCONSTR_ACTION_CASCADE: fk_trigger->deferrable = false; fk_trigger->initdeferred = false; - fk_trigger->funcname = SystemFuncName("RI_FKey_cascade_upd"); + if (fkconstraint->fk_with_period) + fk_trigger->funcname = SystemFuncName("RI_FKey_period_cascade_upd"); + else + fk_trigger->funcname = SystemFuncName("RI_FKey_cascade_upd"); break; case FKCONSTR_ACTION_SETNULL: fk_trigger->deferrable = false; fk_trigger->initdeferred = false; - fk_trigger->funcname = SystemFuncName("RI_FKey_setnull_upd"); + if (fkconstraint->fk_with_period) + fk_trigger->funcname = SystemFuncName("RI_FKey_period_setnull_upd"); + else + fk_trigger->funcname = SystemFuncName("RI_FKey_setnull_upd"); break; case FKCONSTR_ACTION_SETDEFAULT: fk_trigger->deferrable = false; fk_trigger->initdeferred = false; - fk_trigger->funcname = SystemFuncName("RI_FKey_setdefault_upd"); + if (fkconstraint->fk_with_period) + fk_trigger->funcname = SystemFuncName("RI_FKey_period_setdefault_upd"); + else + fk_trigger->funcname = SystemFuncName("RI_FKey_setdefault_upd"); break; default: elog(ERROR, "unrecognized FK action type: %d", diff --git a/src/backend/utils/adt/ri_triggers.c b/src/backend/utils/adt/ri_triggers.c index fc8d59e0f476..4f2d62011a71 100644 --- a/src/backend/utils/adt/ri_triggers.c +++ b/src/backend/utils/adt/ri_triggers.c @@ -79,6 +79,12 @@ #define RI_PLAN_SETNULL_ONUPDATE 8 #define RI_PLAN_SETDEFAULT_ONDELETE 9 #define RI_PLAN_SETDEFAULT_ONUPDATE 10 +#define RI_PLAN_PERIOD_CASCADE_ONDELETE 11 +#define RI_PLAN_PERIOD_CASCADE_ONUPDATE 12 +#define RI_PLAN_PERIOD_SETNULL_ONUPDATE 13 +#define RI_PLAN_PERIOD_SETNULL_ONDELETE 14 +#define RI_PLAN_PERIOD_SETDEFAULT_ONUPDATE 15 +#define RI_PLAN_PERIOD_SETDEFAULT_ONDELETE 16 #define MAX_QUOTED_NAME_LEN (NAMEDATALEN*2+3) #define MAX_QUOTED_REL_NAME_LEN (MAX_QUOTED_NAME_LEN*2) @@ -194,6 +200,7 @@ static bool ri_Check_Pk_Match(Relation pk_rel, Relation fk_rel, const RI_ConstraintInfo *riinfo); static Datum ri_restrict(TriggerData *trigdata, bool is_no_action); static Datum ri_set(TriggerData *trigdata, bool is_set_null, int tgkind); +static Datum tri_set(TriggerData *trigdata, bool is_set_null, int tgkind); static void quoteOneName(char *buffer, const char *name); static void quoteRelationName(char *buffer, Relation rel); static void ri_GenerateQual(StringInfo buf, @@ -230,6 +237,7 @@ static bool ri_PerformCheck(const RI_ConstraintInfo *riinfo, RI_QueryKey *qkey, SPIPlanPtr qplan, Relation fk_rel, Relation pk_rel, TupleTableSlot *oldslot, TupleTableSlot *newslot, + int periodParam, Datum period, bool is_restrict, bool detectNewRows, int expect_OK); static void ri_ExtractValues(Relation rel, TupleTableSlot *slot, @@ -239,6 +247,11 @@ pg_noreturn static void ri_ReportViolation(const RI_ConstraintInfo *riinfo, Relation pk_rel, Relation fk_rel, TupleTableSlot *violatorslot, TupleDesc tupdesc, int queryno, bool is_restrict, bool partgone); +static bool fpo_targets_pk_range(const ForPortionOfState *tg_temporal, + const RI_ConstraintInfo *riinfo); +static Datum restrict_enforced_range(const ForPortionOfState *tg_temporal, + const RI_ConstraintInfo *riinfo, + TupleTableSlot *oldslot); /* @@ -452,6 +465,7 @@ RI_FKey_check(TriggerData *trigdata) ri_PerformCheck(riinfo, &qkey, qplan, fk_rel, pk_rel, NULL, newslot, + -1, (Datum) 0, false, pk_rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE, SPI_OK_SELECT); @@ -617,6 +631,7 @@ ri_Check_Pk_Match(Relation pk_rel, Relation fk_rel, result = ri_PerformCheck(riinfo, &qkey, qplan, fk_rel, pk_rel, oldslot, NULL, + -1, (Datum) 0, false, true, /* treat like update */ SPI_OK_SELECT); @@ -893,6 +908,7 @@ ri_restrict(TriggerData *trigdata, bool is_no_action) ri_PerformCheck(riinfo, &qkey, qplan, fk_rel, pk_rel, oldslot, NULL, + -1, (Datum) 0, !is_no_action, true, /* must detect new rows */ SPI_OK_SELECT); @@ -995,6 +1011,7 @@ RI_FKey_cascade_del(PG_FUNCTION_ARGS) ri_PerformCheck(riinfo, &qkey, qplan, fk_rel, pk_rel, oldslot, NULL, + -1, (Datum) 0, false, true, /* must detect new rows */ SPI_OK_DELETE); @@ -1112,6 +1129,7 @@ RI_FKey_cascade_upd(PG_FUNCTION_ARGS) ri_PerformCheck(riinfo, &qkey, qplan, fk_rel, pk_rel, oldslot, newslot, + -1, (Datum) 0, false, true, /* must detect new rows */ SPI_OK_UPDATE); @@ -1340,6 +1358,7 @@ ri_set(TriggerData *trigdata, bool is_set_null, int tgkind) ri_PerformCheck(riinfo, &qkey, qplan, fk_rel, pk_rel, oldslot, NULL, + -1, (Datum) 0, false, true, /* must detect new rows */ SPI_OK_UPDATE); @@ -1371,6 +1390,540 @@ ri_set(TriggerData *trigdata, bool is_set_null, int tgkind) } +/* + * RI_FKey_period_cascade_del - + * + * Cascaded delete foreign key references at delete event on temporal PK table. + */ +Datum +RI_FKey_period_cascade_del(PG_FUNCTION_ARGS) +{ + TriggerData *trigdata = (TriggerData *) fcinfo->context; + const RI_ConstraintInfo *riinfo; + Relation fk_rel; + Relation pk_rel; + TupleTableSlot *oldslot; + RI_QueryKey qkey; + SPIPlanPtr qplan; + Datum targetRange; + + /* Check that this is a valid trigger call on the right time and event. */ + ri_CheckTrigger(fcinfo, "RI_FKey_period_cascade_del", RI_TRIGTYPE_DELETE); + + riinfo = ri_FetchConstraintInfo(trigdata->tg_trigger, + trigdata->tg_relation, true); + + /* + * Get the relation descriptors of the FK and PK tables and the old tuple. + * + * fk_rel is opened in RowExclusiveLock mode since that's what our + * eventual DELETE will get on it. + */ + fk_rel = table_open(riinfo->fk_relid, RowExclusiveLock); + pk_rel = trigdata->tg_relation; + oldslot = trigdata->tg_trigslot; + + /* + * Don't delete than more than the PK's duration, trimmed by an original + * FOR PORTION OF if necessary. + */ + targetRange = restrict_enforced_range(trigdata->tg_temporal, riinfo, oldslot); + + if (SPI_connect() != SPI_OK_CONNECT) + elog(ERROR, "SPI_connect failed"); + + /* Fetch or prepare a saved plan for the cascaded delete */ + ri_BuildQueryKey(&qkey, riinfo, RI_PLAN_PERIOD_CASCADE_ONDELETE); + + if ((qplan = ri_FetchPreparedPlan(&qkey)) == NULL) + { + StringInfoData querybuf; + char fkrelname[MAX_QUOTED_REL_NAME_LEN]; + char attname[MAX_QUOTED_NAME_LEN]; + char paramname[16]; + const char *querysep; + Oid queryoids[RI_MAX_NUMKEYS + 1]; + const char *fk_only; + + /* ---------- + * The query string built is + * DELETE FROM [ONLY] + * FOR PORTION OF $fkatt (${n+1}) + * WHERE $1 = fkatt1 [AND ...] + * The type id's for the $ parameters are those of the + * corresponding PK attributes. + * ---------- + */ + initStringInfo(&querybuf); + fk_only = fk_rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE ? + "" : "ONLY "; + quoteRelationName(fkrelname, fk_rel); + quoteOneName(attname, RIAttName(fk_rel, riinfo->fk_attnums[riinfo->nkeys - 1])); + + appendStringInfo(&querybuf, "DELETE FROM %s%s FOR PORTION OF %s ($%d)", + fk_only, fkrelname, attname, riinfo->nkeys + 1); + querysep = "WHERE"; + for (int i = 0; i < riinfo->nkeys; i++) + { + Oid pk_type = RIAttType(pk_rel, riinfo->pk_attnums[i]); + Oid pk_coll = RIAttCollation(pk_rel, riinfo->pk_attnums[i]); + Oid fk_type = RIAttType(fk_rel, riinfo->fk_attnums[i]); + Oid fk_coll = RIAttCollation(fk_rel, riinfo->fk_attnums[i]); + + quoteOneName(attname, + RIAttName(fk_rel, riinfo->fk_attnums[i])); + sprintf(paramname, "$%d", i + 1); + ri_GenerateQual(&querybuf, querysep, + paramname, pk_type, + riinfo->pf_eq_oprs[i], + attname, fk_type); + if (pk_coll != fk_coll && !get_collation_isdeterministic(pk_coll)) + ri_GenerateQualCollation(&querybuf, pk_coll); + querysep = "AND"; + queryoids[i] = pk_type; + } + + /* Set a param for FOR PORTION OF TO/FROM */ + queryoids[riinfo->nkeys] = RIAttType(pk_rel, riinfo->pk_attnums[riinfo->nkeys - 1]); + + /* Prepare and save the plan */ + qplan = ri_PlanCheck(querybuf.data, riinfo->nkeys + 1, queryoids, + &qkey, fk_rel, pk_rel); + } + + /* + * We have a plan now. Build up the arguments from the key values in the + * deleted PK tuple and delete the referencing rows + */ + ri_PerformCheck(riinfo, &qkey, qplan, + fk_rel, pk_rel, + oldslot, NULL, + riinfo->nkeys + 1, targetRange, + false, + true, /* must detect new rows */ + SPI_OK_DELETE); + + if (SPI_finish() != SPI_OK_FINISH) + elog(ERROR, "SPI_finish failed"); + + table_close(fk_rel, RowExclusiveLock); + + return PointerGetDatum(NULL); +} + +/* + * RI_FKey_period_cascade_upd - + * + * Cascaded update foreign key references at update event on temporal PK table. + */ +Datum +RI_FKey_period_cascade_upd(PG_FUNCTION_ARGS) +{ + TriggerData *trigdata = (TriggerData *) fcinfo->context; + const RI_ConstraintInfo *riinfo; + Relation fk_rel; + Relation pk_rel; + TupleTableSlot *oldslot; + TupleTableSlot *newslot; + RI_QueryKey qkey; + SPIPlanPtr qplan; + Datum targetRange; + + /* Check that this is a valid trigger call on the right time and event. */ + ri_CheckTrigger(fcinfo, "RI_FKey_period_cascade_upd", RI_TRIGTYPE_UPDATE); + + riinfo = ri_FetchConstraintInfo(trigdata->tg_trigger, + trigdata->tg_relation, true); + + /* + * Get the relation descriptors of the FK and PK tables and the new and + * old tuple. + * + * fk_rel is opened in RowExclusiveLock mode since that's what our + * eventual UPDATE will get on it. + */ + fk_rel = table_open(riinfo->fk_relid, RowExclusiveLock); + pk_rel = trigdata->tg_relation; + newslot = trigdata->tg_newslot; + oldslot = trigdata->tg_trigslot; + + /* + * Don't delete than more than the PK's duration, trimmed by an original + * FOR PORTION OF if necessary. + */ + targetRange = restrict_enforced_range(trigdata->tg_temporal, riinfo, oldslot); + + if (SPI_connect() != SPI_OK_CONNECT) + elog(ERROR, "SPI_connect failed"); + + /* Fetch or prepare a saved plan for the cascaded update */ + ri_BuildQueryKey(&qkey, riinfo, RI_PLAN_PERIOD_CASCADE_ONUPDATE); + + if ((qplan = ri_FetchPreparedPlan(&qkey)) == NULL) + { + StringInfoData querybuf; + StringInfoData qualbuf; + char fkrelname[MAX_QUOTED_REL_NAME_LEN]; + char attname[MAX_QUOTED_NAME_LEN]; + char paramname[16]; + const char *querysep; + const char *qualsep; + Oid queryoids[2 * RI_MAX_NUMKEYS + 1]; + const char *fk_only; + + /* ---------- + * The query string built is + * UPDATE [ONLY] + * FOR PORTION OF $fkatt (${2n+1}) + * SET fkatt1 = $1, [, ...] + * WHERE $n = fkatt1 [AND ...] + * The type id's for the $ parameters are those of the + * corresponding PK attributes. Note that we are assuming + * there is an assignment cast from the PK to the FK type; + * else the parser will fail. + * ---------- + */ + initStringInfo(&querybuf); + initStringInfo(&qualbuf); + fk_only = fk_rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE ? + "" : "ONLY "; + quoteRelationName(fkrelname, fk_rel); + quoteOneName(attname, RIAttName(fk_rel, riinfo->fk_attnums[riinfo->nkeys - 1])); + + appendStringInfo(&querybuf, "UPDATE %s%s FOR PORTION OF %s ($%d) SET", + fk_only, fkrelname, attname, 2 * riinfo->nkeys + 1); + + querysep = ""; + qualsep = "WHERE"; + for (int i = 0, j = riinfo->nkeys; i < riinfo->nkeys; i++, j++) + { + Oid pk_type = RIAttType(pk_rel, riinfo->pk_attnums[i]); + Oid pk_coll = RIAttCollation(pk_rel, riinfo->pk_attnums[i]); + Oid fk_type = RIAttType(fk_rel, riinfo->fk_attnums[i]); + Oid fk_coll = RIAttCollation(fk_rel, riinfo->fk_attnums[i]); + + quoteOneName(attname, + RIAttName(fk_rel, riinfo->fk_attnums[i])); + + /* + * Don't set the temporal column(s). FOR PORTION OF will take care + * of that. + */ + if (i < riinfo->nkeys - 1) + appendStringInfo(&querybuf, + "%s %s = $%d", + querysep, attname, i + 1); + + sprintf(paramname, "$%d", j + 1); + ri_GenerateQual(&qualbuf, qualsep, + paramname, pk_type, + riinfo->pf_eq_oprs[i], + attname, fk_type); + if (pk_coll != fk_coll && !get_collation_isdeterministic(pk_coll)) + ri_GenerateQualCollation(&querybuf, pk_coll); + querysep = ","; + qualsep = "AND"; + queryoids[i] = pk_type; + queryoids[j] = pk_type; + } + appendBinaryStringInfo(&querybuf, qualbuf.data, qualbuf.len); + + /* Set a param for FOR PORTION OF TO/FROM */ + queryoids[2 * riinfo->nkeys] = RIAttType(pk_rel, riinfo->pk_attnums[riinfo->nkeys - 1]); + + /* Prepare and save the plan */ + qplan = ri_PlanCheck(querybuf.data, 2 * riinfo->nkeys + 1, queryoids, + &qkey, fk_rel, pk_rel); + } + + /* + * We have a plan now. Run it to update the existing references. + */ + ri_PerformCheck(riinfo, &qkey, qplan, + fk_rel, pk_rel, + oldslot, newslot, + riinfo->nkeys * 2 + 1, targetRange, + false, + true, /* must detect new rows */ + SPI_OK_UPDATE); + + if (SPI_finish() != SPI_OK_FINISH) + elog(ERROR, "SPI_finish failed"); + + table_close(fk_rel, RowExclusiveLock); + + return PointerGetDatum(NULL); +} + +/* + * RI_FKey_period_setnull_del - + * + * Set foreign key references to NULL values at delete event on PK table. + */ +Datum +RI_FKey_period_setnull_del(PG_FUNCTION_ARGS) +{ + /* Check that this is a valid trigger call on the right time and event. */ + ri_CheckTrigger(fcinfo, "RI_FKey_period_setnull_del", RI_TRIGTYPE_DELETE); + + /* Share code with UPDATE case */ + return tri_set((TriggerData *) fcinfo->context, true, RI_TRIGTYPE_DELETE); +} + +/* + * RI_FKey_period_setnull_upd - + * + * Set foreign key references to NULL at update event on PK table. + */ +Datum +RI_FKey_period_setnull_upd(PG_FUNCTION_ARGS) +{ + /* Check that this is a valid trigger call on the right time and event. */ + ri_CheckTrigger(fcinfo, "RI_FKey_period_setnull_upd", RI_TRIGTYPE_UPDATE); + + /* Share code with DELETE case */ + return tri_set((TriggerData *) fcinfo->context, true, RI_TRIGTYPE_UPDATE); +} + +/* + * RI_FKey_period_setdefault_del - + * + * Set foreign key references to defaults at delete event on PK table. + */ +Datum +RI_FKey_period_setdefault_del(PG_FUNCTION_ARGS) +{ + /* Check that this is a valid trigger call on the right time and event. */ + ri_CheckTrigger(fcinfo, "RI_FKey_period_setdefault_del", RI_TRIGTYPE_DELETE); + + /* Share code with UPDATE case */ + return tri_set((TriggerData *) fcinfo->context, false, RI_TRIGTYPE_DELETE); +} + +/* + * RI_FKey_period_setdefault_upd - + * + * Set foreign key references to defaults at update event on PK table. + */ +Datum +RI_FKey_period_setdefault_upd(PG_FUNCTION_ARGS) +{ + /* Check that this is a valid trigger call on the right time and event. */ + ri_CheckTrigger(fcinfo, "RI_FKey_period_setdefault_upd", RI_TRIGTYPE_UPDATE); + + /* Share code with DELETE case */ + return tri_set((TriggerData *) fcinfo->context, false, RI_TRIGTYPE_UPDATE); +} + +/* + * tri_set - + * + * Common code for temporal ON DELETE SET NULL, ON DELETE SET DEFAULT, ON + * UPDATE SET NULL, and ON UPDATE SET DEFAULT. + */ +static Datum +tri_set(TriggerData *trigdata, bool is_set_null, int tgkind) +{ + const RI_ConstraintInfo *riinfo; + Relation fk_rel; + Relation pk_rel; + TupleTableSlot *oldslot; + RI_QueryKey qkey; + SPIPlanPtr qplan; + Datum targetRange; + int32 queryno; + + riinfo = ri_FetchConstraintInfo(trigdata->tg_trigger, + trigdata->tg_relation, true); + + /* + * Get the relation descriptors of the FK and PK tables and the old tuple. + * + * fk_rel is opened in RowExclusiveLock mode since that's what our + * eventual UPDATE will get on it. + */ + fk_rel = table_open(riinfo->fk_relid, RowExclusiveLock); + pk_rel = trigdata->tg_relation; + oldslot = trigdata->tg_trigslot; + + /* + * Don't SET NULL/DEFAULT more than the PK's duration, trimmed by an + * original FOR PORTION OF if necessary. + */ + targetRange = restrict_enforced_range(trigdata->tg_temporal, riinfo, oldslot); + + if (SPI_connect() != SPI_OK_CONNECT) + elog(ERROR, "SPI_connect failed"); + + /* + * Fetch or prepare a saved plan for the trigger. + */ + switch (tgkind) + { + case RI_TRIGTYPE_UPDATE: + queryno = is_set_null + ? RI_PLAN_PERIOD_SETNULL_ONUPDATE + : RI_PLAN_PERIOD_SETDEFAULT_ONUPDATE; + break; + case RI_TRIGTYPE_DELETE: + queryno = is_set_null + ? RI_PLAN_PERIOD_SETNULL_ONDELETE + : RI_PLAN_PERIOD_SETDEFAULT_ONDELETE; + break; + default: + elog(ERROR, "invalid tgkind passed to ri_set"); + } + + ri_BuildQueryKey(&qkey, riinfo, queryno); + + if ((qplan = ri_FetchPreparedPlan(&qkey)) == NULL) + { + StringInfoData querybuf; + StringInfoData qualbuf; + char fkrelname[MAX_QUOTED_REL_NAME_LEN]; + char attname[MAX_QUOTED_NAME_LEN]; + char paramname[16]; + const char *querysep; + const char *qualsep; + Oid queryoids[RI_MAX_NUMKEYS + 1]; /* +1 for FOR PORTION OF */ + const char *fk_only; + int num_cols_to_set; + const int16 *set_cols; + + switch (tgkind) + { + case RI_TRIGTYPE_UPDATE: + /* -1 so we let FOR PORTION OF set the range. */ + num_cols_to_set = riinfo->nkeys - 1; + set_cols = riinfo->fk_attnums; + break; + case RI_TRIGTYPE_DELETE: + + /* + * If confdelsetcols are present, then we only update the + * columns specified in that array, otherwise we update all + * the referencing columns. + */ + if (riinfo->ndelsetcols != 0) + { + num_cols_to_set = riinfo->ndelsetcols; + set_cols = riinfo->confdelsetcols; + } + else + { + /* -1 so we let FOR PORTION OF set the range. */ + num_cols_to_set = riinfo->nkeys - 1; + set_cols = riinfo->fk_attnums; + } + break; + default: + elog(ERROR, "invalid tgkind passed to ri_set"); + } + + /* ---------- + * The query string built is + * UPDATE [ONLY] + * FOR PORTION OF $fkatt (${n+1}) + * SET fkatt1 = {NULL|DEFAULT} [, ...] + * WHERE $1 = fkatt1 [AND ...] + * The type id's for the $ parameters are those of the + * corresponding PK attributes. + * ---------- + */ + initStringInfo(&querybuf); + initStringInfo(&qualbuf); + fk_only = fk_rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE ? + "" : "ONLY "; + quoteRelationName(fkrelname, fk_rel); + quoteOneName(attname, RIAttName(fk_rel, riinfo->fk_attnums[riinfo->nkeys - 1])); + + appendStringInfo(&querybuf, "UPDATE %s%s FOR PORTION OF %s ($%d) SET", + fk_only, fkrelname, attname, riinfo->nkeys + 1); + + /* + * Add assignment clauses + */ + querysep = ""; + for (int i = 0; i < num_cols_to_set; i++) + { + quoteOneName(attname, RIAttName(fk_rel, set_cols[i])); + appendStringInfo(&querybuf, + "%s %s = %s", + querysep, attname, + is_set_null ? "NULL" : "DEFAULT"); + querysep = ","; + } + + /* + * Add WHERE clause + */ + qualsep = "WHERE"; + for (int i = 0; i < riinfo->nkeys; i++) + { + Oid pk_type = RIAttType(pk_rel, riinfo->pk_attnums[i]); + Oid fk_type = RIAttType(fk_rel, riinfo->fk_attnums[i]); + Oid pk_coll = RIAttCollation(pk_rel, riinfo->pk_attnums[i]); + Oid fk_coll = RIAttCollation(fk_rel, riinfo->fk_attnums[i]); + + quoteOneName(attname, + RIAttName(fk_rel, riinfo->fk_attnums[i])); + + sprintf(paramname, "$%d", i + 1); + ri_GenerateQual(&querybuf, qualsep, + paramname, pk_type, + riinfo->pf_eq_oprs[i], + attname, fk_type); + if (pk_coll != fk_coll && !get_collation_isdeterministic(pk_coll)) + ri_GenerateQualCollation(&querybuf, pk_coll); + qualsep = "AND"; + queryoids[i] = pk_type; + } + + /* Set a param for FOR PORTION OF TO/FROM */ + queryoids[riinfo->nkeys] = RIAttType(pk_rel, riinfo->pk_attnums[riinfo->nkeys - 1]); + + /* Prepare and save the plan */ + qplan = ri_PlanCheck(querybuf.data, riinfo->nkeys + 1, queryoids, + &qkey, fk_rel, pk_rel); + } + + /* + * We have a plan now. Run it to update the existing references. + */ + ri_PerformCheck(riinfo, &qkey, qplan, + fk_rel, pk_rel, + oldslot, NULL, + riinfo->nkeys + 1, targetRange, + false, + true, /* must detect new rows */ + SPI_OK_UPDATE); + + if (SPI_finish() != SPI_OK_FINISH) + elog(ERROR, "SPI_finish failed"); + + table_close(fk_rel, RowExclusiveLock); + + if (is_set_null) + return PointerGetDatum(NULL); + else + { + /* + * If we just deleted or updated the PK row whose key was equal to the + * FK columns' default values, and a referencing row exists in the FK + * table, we would have updated that row to the same values it already + * had --- and RI_FKey_fk_upd_check_required would hence believe no + * check is necessary. So we need to do another lookup now and in + * case a reference still exists, abort the operation. That is + * already implemented in the NO ACTION trigger, so just run it. (This + * recheck is only needed in the SET DEFAULT case, since CASCADE would + * remove such rows in case of a DELETE operation or would change the + * FK key values in case of an UPDATE, while SET NULL is certain to + * result in rows that satisfy the FK constraint.) + */ + return ri_restrict(trigdata, true); + } +} + /* * RI_FKey_pk_upd_check_required - * @@ -2487,6 +3040,7 @@ ri_PerformCheck(const RI_ConstraintInfo *riinfo, RI_QueryKey *qkey, SPIPlanPtr qplan, Relation fk_rel, Relation pk_rel, TupleTableSlot *oldslot, TupleTableSlot *newslot, + int periodParam, Datum period, bool is_restrict, bool detectNewRows, int expect_OK) { @@ -2499,8 +3053,8 @@ ri_PerformCheck(const RI_ConstraintInfo *riinfo, int spi_result; Oid save_userid; int save_sec_context; - Datum vals[RI_MAX_NUMKEYS * 2]; - char nulls[RI_MAX_NUMKEYS * 2]; + Datum vals[RI_MAX_NUMKEYS * 2 + 1]; + char nulls[RI_MAX_NUMKEYS * 2 + 1]; /* * Use the query type code to determine whether the query is run against @@ -2543,6 +3097,12 @@ ri_PerformCheck(const RI_ConstraintInfo *riinfo, ri_ExtractValues(source_rel, oldslot, riinfo, source_is_pk, vals, nulls); } + /* Add/replace a query param for the PERIOD if needed */ + if (period) + { + vals[periodParam - 1] = period; + nulls[periodParam - 1] = ' '; + } /* * In READ COMMITTED mode, we just need to use an up-to-date regular @@ -3223,6 +3783,12 @@ RI_FKey_trigger_type(Oid tgfoid) case F_RI_FKEY_SETDEFAULT_UPD: case F_RI_FKEY_NOACTION_DEL: case F_RI_FKEY_NOACTION_UPD: + case F_RI_FKEY_PERIOD_CASCADE_DEL: + case F_RI_FKEY_PERIOD_CASCADE_UPD: + case F_RI_FKEY_PERIOD_SETNULL_DEL: + case F_RI_FKEY_PERIOD_SETNULL_UPD: + case F_RI_FKEY_PERIOD_SETDEFAULT_DEL: + case F_RI_FKEY_PERIOD_SETDEFAULT_UPD: return RI_TRIGGER_PK; case F_RI_FKEY_CHECK_INS: @@ -3232,3 +3798,50 @@ RI_FKey_trigger_type(Oid tgfoid) return RI_TRIGGER_NONE; } + +/* + * fpo_targets_pk_range + * + * Returns true iff the primary key referenced by riinfo includes the range + * column targeted by the FOR PORTION OF clause (according to tg_temporal). + */ +static bool +fpo_targets_pk_range(const ForPortionOfState *tg_temporal, const RI_ConstraintInfo *riinfo) +{ + if (tg_temporal == NULL) + return false; + + return riinfo->pk_attnums[riinfo->nkeys - 1] == tg_temporal->fp_rangeAttno; +} + +/* + * restrict_enforced_range - + * + * Returns a Datum of RangeTypeP holding the appropriate timespan + * to target child records when we RESTRICT/CASCADE/SET NULL/SET DEFAULT. + * + * In a normal UPDATE/DELETE this should be the referenced row's own valid time, + * but if there was a FOR PORTION OF clause, then we should use that to + * trim down the span further. + */ +static Datum +restrict_enforced_range(const ForPortionOfState *tg_temporal, const RI_ConstraintInfo *riinfo, TupleTableSlot *oldslot) +{ + Datum pkRecordRange; + bool isnull; + AttrNumber attno = riinfo->pk_attnums[riinfo->nkeys - 1]; + + pkRecordRange = slot_getattr(oldslot, attno, &isnull); + if (isnull) + elog(ERROR, "application time should not be null"); + + if (fpo_targets_pk_range(tg_temporal, riinfo)) + { + if (!OidIsValid(riinfo->period_intersect_proc)) + elog(ERROR, "invalid intersect support function"); + + return OidFunctionCall2(riinfo->period_intersect_proc, pkRecordRange, tg_temporal->fp_targetRange); + } + else + return pkRecordRange; +} diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat index 4aca47919ed4..cb01361fa9f9 100644 --- a/src/include/catalog/pg_proc.dat +++ b/src/include/catalog/pg_proc.dat @@ -4120,6 +4120,28 @@ prorettype => 'trigger', proargtypes => '', prosrc => 'RI_FKey_noaction_upd' }, +# Temporal referential integrity constraint triggers +{ oid => '6124', descr => 'temporal referential integrity ON DELETE CASCADE', + proname => 'RI_FKey_period_cascade_del', provolatile => 'v', prorettype => 'trigger', + proargtypes => '', prosrc => 'RI_FKey_period_cascade_del' }, +{ oid => '6125', descr => 'temporal referential integrity ON UPDATE CASCADE', + proname => 'RI_FKey_period_cascade_upd', provolatile => 'v', prorettype => 'trigger', + proargtypes => '', prosrc => 'RI_FKey_period_cascade_upd' }, +{ oid => '6128', descr => 'temporal referential integrity ON DELETE SET NULL', + proname => 'RI_FKey_period_setnull_del', provolatile => 'v', prorettype => 'trigger', + proargtypes => '', prosrc => 'RI_FKey_period_setnull_del' }, +{ oid => '6129', descr => 'temporal referential integrity ON UPDATE SET NULL', + proname => 'RI_FKey_period_setnull_upd', provolatile => 'v', prorettype => 'trigger', + proargtypes => '', prosrc => 'RI_FKey_period_setnull_upd' }, +{ oid => '6130', descr => 'temporal referential integrity ON DELETE SET DEFAULT', + proname => 'RI_FKey_period_setdefault_del', provolatile => 'v', + prorettype => 'trigger', proargtypes => '', + prosrc => 'RI_FKey_period_setdefault_del' }, +{ oid => '6131', descr => 'temporal referential integrity ON UPDATE SET DEFAULT', + proname => 'RI_FKey_period_setdefault_upd', provolatile => 'v', + prorettype => 'trigger', proargtypes => '', + prosrc => 'RI_FKey_period_setdefault_upd' }, + { oid => '1666', proname => 'varbiteq', proleakproof => 't', prorettype => 'bool', proargtypes => 'varbit varbit', prosrc => 'biteq' }, diff --git a/src/test/regress/expected/btree_index.out b/src/test/regress/expected/btree_index.out index 21dc9b5783a7..c3bf94797e74 100644 --- a/src/test/regress/expected/btree_index.out +++ b/src/test/regress/expected/btree_index.out @@ -454,14 +454,17 @@ select proname from pg_proc where proname like E'RI\\_FKey%del' order by 1; (3 rows) select proname from pg_proc where proname like E'RI\\_FKey%del' order by 1; - proname ------------------------- + proname +------------------------------- RI_FKey_cascade_del RI_FKey_noaction_del + RI_FKey_period_cascade_del + RI_FKey_period_setdefault_del + RI_FKey_period_setnull_del RI_FKey_restrict_del RI_FKey_setdefault_del RI_FKey_setnull_del -(5 rows) +(8 rows) explain (costs off) select proname from pg_proc where proname ilike '00%foo' order by 1; @@ -500,14 +503,17 @@ select proname from pg_proc where proname like E'RI\\_FKey%del' order by 1; (6 rows) select proname from pg_proc where proname like E'RI\\_FKey%del' order by 1; - proname ------------------------- + proname +------------------------------- RI_FKey_cascade_del RI_FKey_noaction_del + RI_FKey_period_cascade_del + RI_FKey_period_setdefault_del + RI_FKey_period_setnull_del RI_FKey_restrict_del RI_FKey_setdefault_del RI_FKey_setnull_del -(5 rows) +(8 rows) explain (costs off) select proname from pg_proc where proname ilike '00%foo' order by 1; diff --git a/src/test/regress/expected/without_overlaps.out b/src/test/regress/expected/without_overlaps.out index 401550b5482d..4d9f25ac405a 100644 --- a/src/test/regress/expected/without_overlaps.out +++ b/src/test/regress/expected/without_overlaps.out @@ -1947,7 +1947,24 @@ ERROR: unsupported ON DELETE action for foreign key constraint using PERIOD -- -- rng2rng test ON UPDATE/DELETE options -- +-- TOC: +-- referenced updates CASCADE +-- referenced deletes CASCADE +-- referenced updates SET NULL +-- referenced deletes SET NULL +-- referenced updates SET DEFAULT +-- referenced deletes SET DEFAULT +-- referenced updates CASCADE (two scalar cols) +-- referenced deletes CASCADE (two scalar cols) +-- referenced updates SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- referenced updates SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) +-- -- test FK referenced updates CASCADE +-- TRUNCATE temporal_rng, temporal_fk_rng2rng; INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); @@ -1956,29 +1973,593 @@ ALTER TABLE temporal_fk_rng2rng FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_rng ON DELETE CASCADE ON UPDATE CASCADE; -ERROR: unsupported ON UPDATE action for foreign key constraint using PERIOD +-- leftovers on both sides: +UPDATE temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [7,8) + [100,101) | [2020-01-01,2021-01-01) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_rng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [7,8) + [100,101) | [2019-01-01,2020-01-01) | [7,8) + [100,101) | [2020-01-01,2021-01-01) | [7,8) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)'); +UPDATE temporal_rng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [200,201) | [2018-01-01,2020-01-01) | [9,10) + [200,201) | [2020-01-01,2021-01-01) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes CASCADE +-- +TRUNCATE temporal_rng, temporal_fk_rng2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [6,7) + [100,101) | [2020-01-01,2021-01-01) | [6,7) +(2 rows) + +-- non-FPO delete: +DELETE FROM temporal_rng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +----+----------+----------- +(0 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)'); +DELETE FROM temporal_rng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [200,201) | [2020-01-01,2021-01-01) | [8,9) +(1 row) + +-- -- test FK referenced updates SET NULL +-- TRUNCATE temporal_rng, temporal_fk_rng2rng; INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); ALTER TABLE temporal_fk_rng2rng + DROP CONSTRAINT temporal_fk_rng2rng_fk, ADD CONSTRAINT temporal_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_rng ON DELETE SET NULL ON UPDATE SET NULL; -ERROR: unsupported ON UPDATE action for foreign key constraint using PERIOD +-- leftovers on both sides: +UPDATE temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | + [100,101) | [2020-01-01,2021-01-01) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_rng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | + [100,101) | [2019-01-01,2020-01-01) | + [100,101) | [2020-01-01,2021-01-01) | +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)'); +UPDATE temporal_rng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [200,201) | [2018-01-01,2020-01-01) | + [200,201) | [2020-01-01,2021-01-01) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET NULL +-- +TRUNCATE temporal_rng, temporal_fk_rng2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | + [100,101) | [2020-01-01,2021-01-01) | [6,7) +(3 rows) + +-- non-FPO delete: +DELETE FROM temporal_rng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | + [100,101) | [2019-01-01,2020-01-01) | + [100,101) | [2020-01-01,2021-01-01) | +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)'); +DELETE FROM temporal_rng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [200,201) | [2018-01-01,2020-01-01) | + [200,201) | [2020-01-01,2021-01-01) | [8,9) +(2 rows) + +-- -- test FK referenced updates SET DEFAULT +-- TRUNCATE temporal_rng, temporal_fk_rng2rng; INSERT INTO temporal_rng (id, valid_at) VALUES ('[-1,-1]', daterange(null, null)); INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); ALTER TABLE temporal_fk_rng2rng ALTER COLUMN parent_id SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk_rng2rng_fk, ADD CONSTRAINT temporal_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_rng ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; -ERROR: unsupported ON UPDATE action for foreign key constraint using PERIOD +-- leftovers on both sides: +UPDATE temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) + [100,101) | [2020-01-01,2021-01-01) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_rng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [-1,0) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) + [100,101) | [2020-01-01,2021-01-01) | [-1,0) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)'); +UPDATE temporal_rng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [200,201) | [2018-01-01,2020-01-01) | [-1,0) + [200,201) | [2020-01-01,2021-01-01) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET DEFAULT +-- +TRUNCATE temporal_rng, temporal_fk_rng2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[-1,-1]', daterange(null, null)); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) + [100,101) | [2020-01-01,2021-01-01) | [6,7) +(3 rows) + +-- non-FPO update: +DELETE FROM temporal_rng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [-1,0) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) + [100,101) | [2020-01-01,2021-01-01) | [-1,0) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)'); +DELETE FROM temporal_rng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [200,201) | [2018-01-01,2020-01-01) | [-1,0) + [200,201) | [2020-01-01,2021-01-01) | [8,9) +(2 rows) + +-- +-- test FK referenced updates CASCADE (two scalar cols) +-- +TRUNCATE temporal_rng2, temporal_fk2_rng2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_rng2rng + DROP CONSTRAINT temporal_fk2_rng2rng_fk, + ADD CONSTRAINT temporal_fk2_rng2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [6,7) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [7,8) | [6,7) + [100,101) | [2020-01-01,2021-01-01) | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_rng2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [7,8) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [7,8) | [6,7) + [100,101) | [2020-01-01,2021-01-01) | [7,8) | [6,7) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)', '[8,9)'); +UPDATE temporal_rng2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [200,201) | [2018-01-01,2020-01-01) | [9,10) | [8,9) + [200,201) | [2020-01-01,2021-01-01) | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes CASCADE (two scalar cols) +-- +TRUNCATE temporal_rng2, temporal_fk2_rng2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [6,7) | [6,7) + [100,101) | [2020-01-01,2021-01-01) | [6,7) | [6,7) +(2 rows) + +-- non-FPO delete: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +----+----------+------------+------------ +(0 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [200,201) | [2020-01-01,2021-01-01) | [8,9) | [8,9) +(1 row) + +-- +-- test FK referenced updates SET NULL (two scalar cols) +-- +TRUNCATE temporal_rng2, temporal_fk2_rng2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_rng2rng + DROP CONSTRAINT temporal_fk2_rng2rng_fk, + ADD CONSTRAINT temporal_fk2_rng2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [6,7) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | | + [100,101) | [2020-01-01,2021-01-01) | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_rng2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | | + [100,101) | [2019-01-01,2020-01-01) | | + [100,101) | [2020-01-01,2021-01-01) | | +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)', '[8,9)'); +UPDATE temporal_rng2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [200,201) | [2018-01-01,2020-01-01) | | + [200,201) | [2020-01-01,2021-01-01) | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET NULL (two scalar cols) +-- +TRUNCATE temporal_rng2, temporal_fk2_rng2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [6,7) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | | + [100,101) | [2020-01-01,2021-01-01) | [6,7) | [6,7) +(3 rows) + +-- non-FPO delete: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | | + [100,101) | [2019-01-01,2020-01-01) | | + [100,101) | [2020-01-01,2021-01-01) | | +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [200,201) | [2018-01-01,2020-01-01) | | + [200,201) | [2020-01-01,2021-01-01) | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- +TRUNCATE temporal_rng2, temporal_fk2_rng2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_rng2rng + DROP CONSTRAINT temporal_fk2_rng2rng_fk, + ADD CONSTRAINT temporal_fk2_rng2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET NULL (valid_at) ON UPDATE SET NULL; +ERROR: column "valid_at" referenced in ON DELETE SET action cannot be PERIOD +-- ok: +ALTER TABLE temporal_fk2_rng2rng + DROP CONSTRAINT temporal_fk2_rng2rng_fk, + ADD CONSTRAINT temporal_fk2_rng2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET NULL (parent_id1) ON UPDATE SET NULL; +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [6,7) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | | [6,7) + [100,101) | [2020-01-01,2021-01-01) | [6,7) | [6,7) +(3 rows) + +-- non-FPO delete: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | | [6,7) + [100,101) | [2019-01-01,2020-01-01) | | [6,7) + [100,101) | [2020-01-01,2021-01-01) | | [6,7) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [200,201) | [2018-01-01,2020-01-01) | | [8,9) + [200,201) | [2020-01-01,2021-01-01) | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced updates SET DEFAULT (two scalar cols) +-- +TRUNCATE temporal_rng2, temporal_fk2_rng2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[-1,-1]', daterange(null, null)); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_rng2rng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + ALTER COLUMN parent_id2 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_rng2rng_fk, + ADD CONSTRAINT temporal_fk2_rng2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [6,7) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) | [-1,0) + [100,101) | [2020-01-01,2021-01-01) | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_rng2 SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [-1,0) | [-1,0) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) | [-1,0) + [100,101) | [2020-01-01,2021-01-01) | [-1,0) | [-1,0) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)', '[8,9)'); +UPDATE temporal_rng2 SET id1 = '[9,10)', id2 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [200,201) | [2018-01-01,2020-01-01) | [-1,0) | [-1,0) + [200,201) | [2020-01-01,2021-01-01) | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols) +-- +TRUNCATE temporal_rng2, temporal_fk2_rng2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[-1,-1]', daterange(null, null)); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [6,7) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) | [-1,0) + [100,101) | [2020-01-01,2021-01-01) | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [-1,0) | [-1,0) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) | [-1,0) + [100,101) | [2020-01-01,2021-01-01) | [-1,0) | [-1,0) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [200,201) | [2018-01-01,2020-01-01) | [-1,0) | [-1,0) + [200,201) | [2020-01-01,2021-01-01) | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) +-- +TRUNCATE temporal_rng2, temporal_fk2_rng2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[6,7)', daterange(null, null)); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_rng2rng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_rng2rng_fk, + ADD CONSTRAINT temporal_fk2_rng2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET DEFAULT (valid_at) ON UPDATE SET DEFAULT; +ERROR: column "valid_at" referenced in ON DELETE SET action cannot be PERIOD +-- ok: +ALTER TABLE temporal_fk2_rng2rng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_rng2rng_fk, + ADD CONSTRAINT temporal_fk2_rng2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET DEFAULT (parent_id1) ON UPDATE SET DEFAULT; +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [6,7) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) | [6,7) + [100,101) | [2020-01-01,2021-01-01) | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [-1,0) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) | [6,7) + [100,101) | [2020-01-01,2021-01-01) | [-1,0) | [6,7) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[8,9)', daterange(null, null)); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [200,201) | [2018-01-01,2020-01-01) | [-1,0) | [8,9) + [200,201) | [2020-01-01,2021-01-01) | [8,9) | [8,9) +(2 rows) + -- -- test FOREIGN KEY, multirange references multirange -- @@ -2413,6 +2994,626 @@ DETAIL: Key (id, valid_at)=([5,6), {[2018-01-01,2018-01-02),[2018-01-03,2018-02 DELETE FROM temporal_fk_mltrng2mltrng WHERE id = '[3,4)'; DELETE FROM temporal_mltrng WHERE id = '[5,6)' AND valid_at = datemultirange(daterange('2018-01-01', '2018-02-01')); -- +-- +-- mltrng2mltrng test ON UPDATE/DELETE options +-- +-- TOC: +-- referenced updates CASCADE +-- referenced deletes CASCADE +-- referenced updates SET NULL +-- referenced deletes SET NULL +-- referenced updates SET DEFAULT +-- referenced deletes SET DEFAULT +-- referenced updates CASCADE (two scalar cols) +-- referenced deletes CASCADE (two scalar cols) +-- referenced updates SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- referenced updates SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) +-- +-- test FK referenced updates CASCADE +-- +TRUNCATE temporal_mltrng, temporal_fk_mltrng2mltrng; +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)'); +ALTER TABLE temporal_fk_mltrng2mltrng + DROP CONSTRAINT temporal_fk_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk_mltrng2mltrng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_mltrng + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------------------------------+----------- + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [6,7) + [100,101) | {[2019-01-01,2020-01-01)} | [7,8) +(2 rows) + +-- non-FPO update: +UPDATE temporal_mltrng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------------------------------+----------- + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [7,8) + [100,101) | {[2019-01-01,2020-01-01)} | [7,8) +(2 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)'); +UPDATE temporal_mltrng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------+----------- + [200,201) | {[2018-01-01,2020-01-01)} | [9,10) + [200,201) | {[2020-01-01,2021-01-01)} | [8,9) +(2 rows) + +-- +-- test FK referenced deletes CASCADE +-- +TRUNCATE temporal_mltrng, temporal_fk_mltrng2mltrng; +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------------------------------+----------- + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [6,7) +(1 row) + +-- non-FPO delete: +DELETE FROM temporal_mltrng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +----+----------+----------- +(0 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)'); +DELETE FROM temporal_mltrng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------+----------- + [200,201) | {[2020-01-01,2021-01-01)} | [8,9) +(1 row) + +-- +-- test FK referenced updates SET NULL +-- +TRUNCATE temporal_mltrng, temporal_fk_mltrng2mltrng; +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)'); +ALTER TABLE temporal_fk_mltrng2mltrng + DROP CONSTRAINT temporal_fk_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk_mltrng2mltrng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_mltrng + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------------------------------+----------- + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [6,7) + [100,101) | {[2019-01-01,2020-01-01)} | +(2 rows) + +-- non-FPO update: +UPDATE temporal_mltrng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------------------------------+----------- + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | + [100,101) | {[2019-01-01,2020-01-01)} | +(2 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)'); +UPDATE temporal_mltrng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------+----------- + [200,201) | {[2018-01-01,2020-01-01)} | + [200,201) | {[2020-01-01,2021-01-01)} | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET NULL +-- +TRUNCATE temporal_mltrng, temporal_fk_mltrng2mltrng; +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------------------------------+----------- + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [6,7) + [100,101) | {[2019-01-01,2020-01-01)} | +(2 rows) + +-- non-FPO delete: +DELETE FROM temporal_mltrng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------------------------------+----------- + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | + [100,101) | {[2019-01-01,2020-01-01)} | +(2 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)'); +DELETE FROM temporal_mltrng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------+----------- + [200,201) | {[2018-01-01,2020-01-01)} | + [200,201) | {[2020-01-01,2021-01-01)} | [8,9) +(2 rows) + +-- +-- test FK referenced updates SET DEFAULT +-- +TRUNCATE temporal_mltrng, temporal_fk_mltrng2mltrng; +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[-1,-1]', datemultirange(daterange(null, null))); +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)'); +ALTER TABLE temporal_fk_mltrng2mltrng + ALTER COLUMN parent_id SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk_mltrng2mltrng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_mltrng + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------------------------------+----------- + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [6,7) + [100,101) | {[2019-01-01,2020-01-01)} | [-1,0) +(2 rows) + +-- non-FPO update: +UPDATE temporal_mltrng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------------------------------+----------- + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [-1,0) + [100,101) | {[2019-01-01,2020-01-01)} | [-1,0) +(2 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)'); +UPDATE temporal_mltrng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------+----------- + [200,201) | {[2018-01-01,2020-01-01)} | [-1,0) + [200,201) | {[2020-01-01,2021-01-01)} | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET DEFAULT +-- +TRUNCATE temporal_mltrng, temporal_fk_mltrng2mltrng; +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[-1,-1]', datemultirange(daterange(null, null))); +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------------------------------+----------- + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [6,7) + [100,101) | {[2019-01-01,2020-01-01)} | [-1,0) +(2 rows) + +-- non-FPO update: +DELETE FROM temporal_mltrng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------------------------------+----------- + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [-1,0) + [100,101) | {[2019-01-01,2020-01-01)} | [-1,0) +(2 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)'); +DELETE FROM temporal_mltrng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+---------------------------+----------- + [200,201) | {[2018-01-01,2020-01-01)} | [-1,0) + [200,201) | {[2020-01-01,2021-01-01)} | [8,9) +(2 rows) + +-- +-- test FK referenced updates CASCADE (two scalar cols) +-- +TRUNCATE temporal_mltrng2, temporal_fk2_mltrng2mltrng; +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_mltrng2mltrng + DROP CONSTRAINT temporal_fk2_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk2_mltrng2mltrng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_mltrng2 + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_mltrng2 FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------------------------------+------------+------------ + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [6,7) | [6,7) + [100,101) | {[2019-01-01,2020-01-01)} | [7,8) | [6,7) +(2 rows) + +-- non-FPO update: +UPDATE temporal_mltrng2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------------------------------+------------+------------ + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [7,8) | [6,7) + [100,101) | {[2019-01-01,2020-01-01)} | [7,8) | [6,7) +(2 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)', '[8,9)'); +UPDATE temporal_mltrng2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------+------------+------------ + [200,201) | {[2018-01-01,2020-01-01)} | [9,10) | [8,9) + [200,201) | {[2020-01-01,2021-01-01)} | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes CASCADE (two scalar cols) +-- +TRUNCATE temporal_mltrng2, temporal_fk2_mltrng2mltrng; +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_mltrng2 FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------------------------------+------------+------------ + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [6,7) | [6,7) +(1 row) + +-- non-FPO delete: +DELETE FROM temporal_mltrng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +----+----------+------------+------------ +(0 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)', '[8,9)'); +DELETE FROM temporal_mltrng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------+------------+------------ + [200,201) | {[2020-01-01,2021-01-01)} | [8,9) | [8,9) +(1 row) + +-- +-- test FK referenced updates SET NULL (two scalar cols) +-- +TRUNCATE temporal_mltrng2, temporal_fk2_mltrng2mltrng; +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_mltrng2mltrng + DROP CONSTRAINT temporal_fk2_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk2_mltrng2mltrng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_mltrng2 + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_mltrng2 FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------------------------------+------------+------------ + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [6,7) | [6,7) + [100,101) | {[2019-01-01,2020-01-01)} | | +(2 rows) + +-- non-FPO update: +UPDATE temporal_mltrng2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------------------------------+------------+------------ + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | | + [100,101) | {[2019-01-01,2020-01-01)} | | +(2 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)', '[8,9)'); +UPDATE temporal_mltrng2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------+------------+------------ + [200,201) | {[2018-01-01,2020-01-01)} | | + [200,201) | {[2020-01-01,2021-01-01)} | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET NULL (two scalar cols) +-- +TRUNCATE temporal_mltrng2, temporal_fk2_mltrng2mltrng; +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_mltrng2 FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------------------------------+------------+------------ + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [6,7) | [6,7) + [100,101) | {[2019-01-01,2020-01-01)} | | +(2 rows) + +-- non-FPO delete: +DELETE FROM temporal_mltrng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------------------------------+------------+------------ + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | | + [100,101) | {[2019-01-01,2020-01-01)} | | +(2 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)', '[8,9)'); +DELETE FROM temporal_mltrng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------+------------+------------ + [200,201) | {[2018-01-01,2020-01-01)} | | + [200,201) | {[2020-01-01,2021-01-01)} | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- +TRUNCATE temporal_mltrng2, temporal_fk2_mltrng2mltrng; +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_mltrng2mltrng + DROP CONSTRAINT temporal_fk2_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk2_mltrng2mltrng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_mltrng2 + ON DELETE SET NULL (valid_at) ON UPDATE SET NULL; +ERROR: column "valid_at" referenced in ON DELETE SET action cannot be PERIOD +-- ok: +ALTER TABLE temporal_fk2_mltrng2mltrng + DROP CONSTRAINT temporal_fk2_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk2_mltrng2mltrng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_mltrng2 + ON DELETE SET NULL (parent_id1) ON UPDATE SET NULL; +-- leftovers on both sides: +DELETE FROM temporal_mltrng2 FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------------------------------+------------+------------ + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [6,7) | [6,7) + [100,101) | {[2019-01-01,2020-01-01)} | | [6,7) +(2 rows) + +-- non-FPO delete: +DELETE FROM temporal_mltrng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------------------------------+------------+------------ + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | | [6,7) + [100,101) | {[2019-01-01,2020-01-01)} | | [6,7) +(2 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)', '[8,9)'); +DELETE FROM temporal_mltrng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------+------------+------------ + [200,201) | {[2018-01-01,2020-01-01)} | | [8,9) + [200,201) | {[2020-01-01,2021-01-01)} | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced updates SET DEFAULT (two scalar cols) +-- +TRUNCATE temporal_mltrng2, temporal_fk2_mltrng2mltrng; +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[-1,-1]', datemultirange(daterange(null, null))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_mltrng2mltrng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + ALTER COLUMN parent_id2 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk2_mltrng2mltrng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_mltrng2 + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_mltrng2 FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------------------------------+------------+------------ + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [6,7) | [6,7) + [100,101) | {[2019-01-01,2020-01-01)} | [-1,0) | [-1,0) +(2 rows) + +-- non-FPO update: +UPDATE temporal_mltrng2 SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------------------------------+------------+------------ + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [-1,0) | [-1,0) + [100,101) | {[2019-01-01,2020-01-01)} | [-1,0) | [-1,0) +(2 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)', '[8,9)'); +UPDATE temporal_mltrng2 SET id1 = '[9,10)', id2 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------+------------+------------ + [200,201) | {[2018-01-01,2020-01-01)} | [-1,0) | [-1,0) + [200,201) | {[2020-01-01,2021-01-01)} | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols) +-- +TRUNCATE temporal_mltrng2, temporal_fk2_mltrng2mltrng; +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[-1,-1]', datemultirange(daterange(null, null))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_mltrng2 FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------------------------------+------------+------------ + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [6,7) | [6,7) + [100,101) | {[2019-01-01,2020-01-01)} | [-1,0) | [-1,0) +(2 rows) + +-- non-FPO update: +DELETE FROM temporal_mltrng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------------------------------+------------+------------ + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [-1,0) | [-1,0) + [100,101) | {[2019-01-01,2020-01-01)} | [-1,0) | [-1,0) +(2 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)', '[8,9)'); +DELETE FROM temporal_mltrng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------+------------+------------ + [200,201) | {[2018-01-01,2020-01-01)} | [-1,0) | [-1,0) + [200,201) | {[2020-01-01,2021-01-01)} | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) +-- +TRUNCATE temporal_mltrng2, temporal_fk2_mltrng2mltrng; +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[6,7)', datemultirange(daterange(null, null))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_mltrng2mltrng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk2_mltrng2mltrng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_mltrng2 + ON DELETE SET DEFAULT (valid_at) ON UPDATE SET DEFAULT; +ERROR: column "valid_at" referenced in ON DELETE SET action cannot be PERIOD +-- ok: +ALTER TABLE temporal_fk2_mltrng2mltrng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk2_mltrng2mltrng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_mltrng2 + ON DELETE SET DEFAULT (parent_id1) ON UPDATE SET DEFAULT; +-- leftovers on both sides: +DELETE FROM temporal_mltrng2 FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------------------------------+------------+------------ + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [6,7) | [6,7) + [100,101) | {[2019-01-01,2020-01-01)} | [-1,0) | [6,7) +(2 rows) + +-- non-FPO update: +DELETE FROM temporal_mltrng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------------------------------+------------+------------ + [100,101) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [-1,0) | [6,7) + [100,101) | {[2019-01-01,2020-01-01)} | [-1,0) | [6,7) +(2 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[8,9)', datemultirange(daterange(null, null))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)', '[8,9)'); +DELETE FROM temporal_mltrng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+---------------------------+------------+------------ + [200,201) | {[2018-01-01,2020-01-01)} | [-1,0) | [8,9) + [200,201) | {[2020-01-01,2021-01-01)} | [8,9) | [8,9) +(2 rows) + +-- FK with a custom range type +CREATE TYPE mydaterange AS range(subtype=date); +CREATE TABLE temporal_rng3 ( + id int4range, + valid_at mydaterange, + CONSTRAINT temporal_rng3_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +CREATE TABLE temporal_fk3_rng2rng ( + id int4range, + valid_at mydaterange, + parent_id int4range, + CONSTRAINT temporal_fk3_rng2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk3_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng3 (id, PERIOD valid_at) ON DELETE CASCADE +); +INSERT INTO temporal_rng3 (id, valid_at) VALUES ('[8,9)', mydaterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk3_rng2rng (id, valid_at, parent_id) VALUES ('[5,6)', mydaterange('2018-01-01', '2021-01-01'), '[8,9)'); +DELETE FROM temporal_rng3 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[8,9)'; +SELECT * FROM temporal_fk3_rng2rng WHERE id = '[5,6)'; + id | valid_at | parent_id +-------+-------------------------+----------- + [5,6) | [2018-01-01,2019-01-01) | [8,9) + [5,6) | [2020-01-01,2021-01-01) | [8,9) +(2 rows) + +DROP TABLE temporal_fk3_rng2rng; +DROP TABLE temporal_rng3; +DROP TYPE mydaterange; +-- -- FK between partitioned tables: ranges -- CREATE TABLE temporal_partitioned_rng ( @@ -2421,8 +3622,8 @@ CREATE TABLE temporal_partitioned_rng ( name text, CONSTRAINT temporal_paritioned_rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) ) PARTITION BY LIST (id); -CREATE TABLE tp1 partition OF temporal_partitioned_rng FOR VALUES IN ('[1,2)', '[3,4)', '[5,6)', '[7,8)', '[9,10)', '[11,12)'); -CREATE TABLE tp2 partition OF temporal_partitioned_rng FOR VALUES IN ('[2,3)', '[4,5)', '[6,7)', '[8,9)', '[10,11)', '[12,13)'); +CREATE TABLE tp1 PARTITION OF temporal_partitioned_rng FOR VALUES IN ('[1,2)', '[3,4)', '[5,6)', '[7,8)', '[9,10)', '[11,12)', '[13,14)', '[15,16)', '[17,18)', '[19,20)', '[21,22)', '[23,24)'); +CREATE TABLE tp2 PARTITION OF temporal_partitioned_rng FOR VALUES IN ('[0,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)'); INSERT INTO temporal_partitioned_rng (id, valid_at, name) VALUES ('[1,2)', daterange('2000-01-01', '2000-02-01'), 'one'), ('[1,2)', daterange('2000-02-01', '2000-03-01'), 'one'), @@ -2435,8 +3636,8 @@ CREATE TABLE temporal_partitioned_fk_rng2rng ( CONSTRAINT temporal_partitioned_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_partitioned_rng (id, PERIOD valid_at) ) PARTITION BY LIST (id); -CREATE TABLE tfkp1 partition OF temporal_partitioned_fk_rng2rng FOR VALUES IN ('[1,2)', '[3,4)', '[5,6)', '[7,8)', '[9,10)', '[11,12)'); -CREATE TABLE tfkp2 partition OF temporal_partitioned_fk_rng2rng FOR VALUES IN ('[2,3)', '[4,5)', '[6,7)', '[8,9)', '[10,11)', '[12,13)'); +CREATE TABLE tfkp1 PARTITION OF temporal_partitioned_fk_rng2rng FOR VALUES IN ('[1,2)', '[3,4)', '[5,6)', '[7,8)', '[9,10)', '[11,12)', '[13,14)', '[15,16)', '[17,18)', '[19,20)', '[21,22)', '[23,24)'); +CREATE TABLE tfkp2 PARTITION OF temporal_partitioned_fk_rng2rng FOR VALUES IN ('[0,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)'); -- -- partitioned FK referencing inserts -- @@ -2478,7 +3679,7 @@ UPDATE temporal_partitioned_rng SET valid_at = daterange('2016-02-01', '2016-03- -- should fail: UPDATE temporal_partitioned_rng SET valid_at = daterange('2016-01-01', '2016-02-01') WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); -ERROR: update or delete on table "tp1" violates foreign key constraint "temporal_partitioned_fk_rng2rng_fk_1" on table "temporal_partitioned_fk_rng2rng" +ERROR: update or delete on table "tp1" violates foreign key constraint "temporal_partitioned_fk_rng2rng_fk_2" on table "temporal_partitioned_fk_rng2rng" DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_partitioned_fk_rng2rng". -- -- partitioned FK referenced deletes NO ACTION @@ -2490,37 +3691,162 @@ INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[ DELETE FROM temporal_partitioned_rng WHERE id = '[5,6)' AND valid_at = daterange('2018-02-01', '2018-03-01'); -- should fail: DELETE FROM temporal_partitioned_rng WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); -ERROR: update or delete on table "tp1" violates foreign key constraint "temporal_partitioned_fk_rng2rng_fk_1" on table "temporal_partitioned_fk_rng2rng" +ERROR: update or delete on table "tp1" violates foreign key constraint "temporal_partitioned_fk_rng2rng_fk_2" on table "temporal_partitioned_fk_rng2rng" DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_partitioned_fk_rng2rng". -- -- partitioned FK referenced updates CASCADE -- +TRUNCATE temporal_partitioned_rng, temporal_partitioned_fk_rng2rng; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[4,5)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); ALTER TABLE temporal_partitioned_fk_rng2rng DROP CONSTRAINT temporal_partitioned_fk_rng2rng_fk, ADD CONSTRAINT temporal_partitioned_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_partitioned_rng ON DELETE CASCADE ON UPDATE CASCADE; -ERROR: unsupported ON UPDATE action for foreign key constraint using PERIOD +UPDATE temporal_partitioned_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[4,5)'; + id | valid_at | parent_id +-------+-------------------------+----------- + [4,5) | [2019-01-01,2020-01-01) | [7,8) + [4,5) | [2018-01-01,2019-01-01) | [6,7) + [4,5) | [2020-01-01,2021-01-01) | [6,7) +(3 rows) + +UPDATE temporal_partitioned_rng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[4,5)'; + id | valid_at | parent_id +-------+-------------------------+----------- + [4,5) | [2019-01-01,2020-01-01) | [7,8) + [4,5) | [2018-01-01,2019-01-01) | [7,8) + [4,5) | [2020-01-01,2021-01-01) | [7,8) +(3 rows) + +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[15,16)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[15,16)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[10,11)', daterange('2018-01-01', '2021-01-01'), '[15,16)'); +UPDATE temporal_partitioned_rng SET id = '[16,17)' WHERE id = '[15,16)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[10,11)'; + id | valid_at | parent_id +---------+-------------------------+----------- + [10,11) | [2018-01-01,2020-01-01) | [16,17) + [10,11) | [2020-01-01,2021-01-01) | [15,16) +(2 rows) + -- -- partitioned FK referenced deletes CASCADE -- +TRUNCATE temporal_partitioned_rng, temporal_partitioned_fk_rng2rng; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[8,9)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[5,6)', daterange('2018-01-01', '2021-01-01'), '[8,9)'); +DELETE FROM temporal_partitioned_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[8,9)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[5,6)'; + id | valid_at | parent_id +-------+-------------------------+----------- + [5,6) | [2018-01-01,2019-01-01) | [8,9) + [5,6) | [2020-01-01,2021-01-01) | [8,9) +(2 rows) + +DELETE FROM temporal_partitioned_rng WHERE id = '[8,9)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[5,6)'; + id | valid_at | parent_id +----+----------+----------- +(0 rows) + +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[17,18)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[17,18)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[11,12)', daterange('2018-01-01', '2021-01-01'), '[17,18)'); +DELETE FROM temporal_partitioned_rng WHERE id = '[17,18)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[11,12)'; + id | valid_at | parent_id +---------+-------------------------+----------- + [11,12) | [2020-01-01,2021-01-01) | [17,18) +(1 row) + -- -- partitioned FK referenced updates SET NULL -- +TRUNCATE temporal_partitioned_rng, temporal_partitioned_fk_rng2rng; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[9,10)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01'), '[9,10)'); ALTER TABLE temporal_partitioned_fk_rng2rng DROP CONSTRAINT temporal_partitioned_fk_rng2rng_fk, ADD CONSTRAINT temporal_partitioned_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_partitioned_rng ON DELETE SET NULL ON UPDATE SET NULL; -ERROR: unsupported ON UPDATE action for foreign key constraint using PERIOD +UPDATE temporal_partitioned_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[10,11)' WHERE id = '[9,10)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[6,7)'; + id | valid_at | parent_id +-------+-------------------------+----------- + [6,7) | [2019-01-01,2020-01-01) | + [6,7) | [2018-01-01,2019-01-01) | [9,10) + [6,7) | [2020-01-01,2021-01-01) | [9,10) +(3 rows) + +UPDATE temporal_partitioned_rng SET id = '[10,11)' WHERE id = '[9,10)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[6,7)'; + id | valid_at | parent_id +-------+-------------------------+----------- + [6,7) | [2019-01-01,2020-01-01) | + [6,7) | [2018-01-01,2019-01-01) | + [6,7) | [2020-01-01,2021-01-01) | +(3 rows) + +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[18,19)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[18,19)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[12,13)', daterange('2018-01-01', '2021-01-01'), '[18,19)'); +UPDATE temporal_partitioned_rng SET id = '[19,20)' WHERE id = '[18,19)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[12,13)'; + id | valid_at | parent_id +---------+-------------------------+----------- + [12,13) | [2018-01-01,2020-01-01) | + [12,13) | [2020-01-01,2021-01-01) | [18,19) +(2 rows) + -- -- partitioned FK referenced deletes SET NULL -- +TRUNCATE temporal_partitioned_rng, temporal_partitioned_fk_rng2rng; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[11,12)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[7,8)', daterange('2018-01-01', '2021-01-01'), '[11,12)'); +DELETE FROM temporal_partitioned_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[11,12)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[7,8)'; + id | valid_at | parent_id +-------+-------------------------+----------- + [7,8) | [2019-01-01,2020-01-01) | + [7,8) | [2018-01-01,2019-01-01) | [11,12) + [7,8) | [2020-01-01,2021-01-01) | [11,12) +(3 rows) + +DELETE FROM temporal_partitioned_rng WHERE id = '[11,12)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[7,8)'; + id | valid_at | parent_id +-------+-------------------------+----------- + [7,8) | [2019-01-01,2020-01-01) | + [7,8) | [2018-01-01,2019-01-01) | + [7,8) | [2020-01-01,2021-01-01) | +(3 rows) + +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[20,21)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[20,21)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[13,14)', daterange('2018-01-01', '2021-01-01'), '[20,21)'); +DELETE FROM temporal_partitioned_rng WHERE id = '[20,21)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[13,14)'; + id | valid_at | parent_id +---------+-------------------------+----------- + [13,14) | [2018-01-01,2020-01-01) | + [13,14) | [2020-01-01,2021-01-01) | [20,21) +(2 rows) + -- -- partitioned FK referenced updates SET DEFAULT -- +TRUNCATE temporal_partitioned_rng, temporal_partitioned_fk_rng2rng; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[0,1)', daterange(null, null)); +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[12,13)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[8,9)', daterange('2018-01-01', '2021-01-01'), '[12,13)'); ALTER TABLE temporal_partitioned_fk_rng2rng ALTER COLUMN parent_id SET DEFAULT '[-1,-1]', DROP CONSTRAINT temporal_partitioned_fk_rng2rng_fk, @@ -2528,10 +3854,73 @@ ALTER TABLE temporal_partitioned_fk_rng2rng FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_partitioned_rng ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; -ERROR: unsupported ON UPDATE action for foreign key constraint using PERIOD +UPDATE temporal_partitioned_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[13,14)' WHERE id = '[12,13)'; +ERROR: insert or update on table "tfkp2" violates foreign key constraint "temporal_partitioned_fk_rng2rng_fk" +DETAIL: Key (parent_id, valid_at)=([-1,0), [2019-01-01,2020-01-01)) is not present in table "temporal_partitioned_rng". +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[8,9)'; + id | valid_at | parent_id +-------+-------------------------+----------- + [8,9) | [2018-01-01,2021-01-01) | [12,13) +(1 row) + +UPDATE temporal_partitioned_rng SET id = '[13,14)' WHERE id = '[12,13)'; +ERROR: insert or update on table "tfkp2" violates foreign key constraint "temporal_partitioned_fk_rng2rng_fk" +DETAIL: Key (parent_id, valid_at)=([-1,0), [2018-01-01,2021-01-01)) is not present in table "temporal_partitioned_rng". +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[8,9)'; + id | valid_at | parent_id +-------+-------------------------+----------- + [8,9) | [2018-01-01,2021-01-01) | [12,13) +(1 row) + +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[22,23)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[22,23)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[14,15)', daterange('2018-01-01', '2021-01-01'), '[22,23)'); +UPDATE temporal_partitioned_rng SET id = '[23,24)' WHERE id = '[22,23)' AND valid_at @> '2019-01-01'::date; +ERROR: insert or update on table "tfkp2" violates foreign key constraint "temporal_partitioned_fk_rng2rng_fk" +DETAIL: Key (parent_id, valid_at)=([-1,0), [2018-01-01,2020-01-01)) is not present in table "temporal_partitioned_rng". +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[14,15)'; + id | valid_at | parent_id +---------+-------------------------+----------- + [14,15) | [2018-01-01,2021-01-01) | [22,23) +(1 row) + -- -- partitioned FK referenced deletes SET DEFAULT -- +TRUNCATE temporal_partitioned_rng, temporal_partitioned_fk_rng2rng; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[0,1)', daterange(null, null)); +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[14,15)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[9,10)', daterange('2018-01-01', '2021-01-01'), '[14,15)'); +DELETE FROM temporal_partitioned_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[14,15)'; +ERROR: insert or update on table "tfkp1" violates foreign key constraint "temporal_partitioned_fk_rng2rng_fk" +DETAIL: Key (parent_id, valid_at)=([-1,0), [2019-01-01,2020-01-01)) is not present in table "temporal_partitioned_rng". +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[9,10)'; + id | valid_at | parent_id +--------+-------------------------+----------- + [9,10) | [2018-01-01,2021-01-01) | [14,15) +(1 row) + +DELETE FROM temporal_partitioned_rng WHERE id = '[14,15)'; +ERROR: insert or update on table "tfkp1" violates foreign key constraint "temporal_partitioned_fk_rng2rng_fk" +DETAIL: Key (parent_id, valid_at)=([-1,0), [2018-01-01,2021-01-01)) is not present in table "temporal_partitioned_rng". +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[9,10)'; + id | valid_at | parent_id +--------+-------------------------+----------- + [9,10) | [2018-01-01,2021-01-01) | [14,15) +(1 row) + +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[24,25)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[24,25)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[15,16)', daterange('2018-01-01', '2021-01-01'), '[24,25)'); +DELETE FROM temporal_partitioned_rng WHERE id = '[24,25)' AND valid_at @> '2019-01-01'::date; +ERROR: insert or update on table "tfkp1" violates foreign key constraint "temporal_partitioned_fk_rng2rng_fk" +DETAIL: Key (parent_id, valid_at)=([-1,0), [2018-01-01,2020-01-01)) is not present in table "temporal_partitioned_rng". +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[15,16)'; + id | valid_at | parent_id +---------+-------------------------+----------- + [15,16) | [2018-01-01,2021-01-01) | [24,25) +(1 row) + DROP TABLE temporal_partitioned_fk_rng2rng; DROP TABLE temporal_partitioned_rng; -- @@ -2617,32 +4006,150 @@ DETAIL: Key (id, valid_at)=([5,6), {[2018-01-01,2018-02-01)}) is still referenc -- -- partitioned FK referenced updates CASCADE -- +TRUNCATE temporal_partitioned_mltrng, temporal_partitioned_fk_mltrng2mltrng; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[4,5)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)'); ALTER TABLE temporal_partitioned_fk_mltrng2mltrng DROP CONSTRAINT temporal_partitioned_fk_mltrng2mltrng_fk, ADD CONSTRAINT temporal_partitioned_fk_mltrng2mltrng_fk FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_partitioned_mltrng ON DELETE CASCADE ON UPDATE CASCADE; -ERROR: unsupported ON UPDATE action for foreign key constraint using PERIOD +UPDATE temporal_partitioned_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[4,5)'; + id | valid_at | parent_id +-------+---------------------------------------------------+----------- + [4,5) | {[2019-01-01,2020-01-01)} | [7,8) + [4,5) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [6,7) +(2 rows) + +UPDATE temporal_partitioned_mltrng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[4,5)'; + id | valid_at | parent_id +-------+---------------------------------------------------+----------- + [4,5) | {[2019-01-01,2020-01-01)} | [7,8) + [4,5) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [7,8) +(2 rows) + +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[15,16)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[15,16)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[10,11)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[15,16)'); +UPDATE temporal_partitioned_mltrng SET id = '[16,17)' WHERE id = '[15,16)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[10,11)'; + id | valid_at | parent_id +---------+---------------------------+----------- + [10,11) | {[2018-01-01,2020-01-01)} | [16,17) + [10,11) | {[2020-01-01,2021-01-01)} | [15,16) +(2 rows) + -- -- partitioned FK referenced deletes CASCADE -- +TRUNCATE temporal_partitioned_mltrng, temporal_partitioned_fk_mltrng2mltrng; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[5,6)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)'); +DELETE FROM temporal_partitioned_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id = '[8,9)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[5,6)'; + id | valid_at | parent_id +-------+---------------------------------------------------+----------- + [5,6) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [8,9) +(1 row) + +DELETE FROM temporal_partitioned_mltrng WHERE id = '[8,9)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[5,6)'; + id | valid_at | parent_id +----+----------+----------- +(0 rows) + +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[17,18)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[17,18)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[11,12)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[17,18)'); +DELETE FROM temporal_partitioned_mltrng WHERE id = '[17,18)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[11,12)'; + id | valid_at | parent_id +---------+---------------------------+----------- + [11,12) | {[2020-01-01,2021-01-01)} | [17,18) +(1 row) + -- -- partitioned FK referenced updates SET NULL -- +TRUNCATE temporal_partitioned_mltrng, temporal_partitioned_fk_mltrng2mltrng; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[9,10)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[9,10)'); ALTER TABLE temporal_partitioned_fk_mltrng2mltrng DROP CONSTRAINT temporal_partitioned_fk_mltrng2mltrng_fk, ADD CONSTRAINT temporal_partitioned_fk_mltrng2mltrng_fk FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_partitioned_mltrng ON DELETE SET NULL ON UPDATE SET NULL; -ERROR: unsupported ON UPDATE action for foreign key constraint using PERIOD +UPDATE temporal_partitioned_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id = '[10,11)' WHERE id = '[9,10)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[6,7)'; + id | valid_at | parent_id +-------+---------------------------------------------------+----------- + [6,7) | {[2019-01-01,2020-01-01)} | + [6,7) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [9,10) +(2 rows) + +UPDATE temporal_partitioned_mltrng SET id = '[10,11)' WHERE id = '[9,10)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[6,7)'; + id | valid_at | parent_id +-------+---------------------------------------------------+----------- + [6,7) | {[2019-01-01,2020-01-01)} | + [6,7) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | +(2 rows) + +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[18,19)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[18,19)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[12,13)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[18,19)'); +UPDATE temporal_partitioned_mltrng SET id = '[19,20)' WHERE id = '[18,19)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[12,13)'; + id | valid_at | parent_id +---------+---------------------------+----------- + [12,13) | {[2018-01-01,2020-01-01)} | + [12,13) | {[2020-01-01,2021-01-01)} | [18,19) +(2 rows) + -- -- partitioned FK referenced deletes SET NULL -- +TRUNCATE temporal_partitioned_mltrng, temporal_partitioned_fk_mltrng2mltrng; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[11,12)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[7,8)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[11,12)'); +DELETE FROM temporal_partitioned_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id = '[11,12)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[7,8)'; + id | valid_at | parent_id +-------+---------------------------------------------------+----------- + [7,8) | {[2019-01-01,2020-01-01)} | + [7,8) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [11,12) +(2 rows) + +DELETE FROM temporal_partitioned_mltrng WHERE id = '[11,12)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[7,8)'; + id | valid_at | parent_id +-------+---------------------------------------------------+----------- + [7,8) | {[2019-01-01,2020-01-01)} | + [7,8) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | +(2 rows) + +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[20,21)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[20,21)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[13,14)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[20,21)'); +DELETE FROM temporal_partitioned_mltrng WHERE id = '[20,21)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[13,14)'; + id | valid_at | parent_id +---------+---------------------------+----------- + [13,14) | {[2018-01-01,2020-01-01)} | + [13,14) | {[2020-01-01,2021-01-01)} | [20,21) +(2 rows) + -- -- partitioned FK referenced updates SET DEFAULT -- +TRUNCATE temporal_partitioned_mltrng, temporal_partitioned_fk_mltrng2mltrng; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[0,1)', datemultirange(daterange(null, null))); +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[12,13)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[8,9)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[12,13)'); ALTER TABLE temporal_partitioned_fk_mltrng2mltrng ALTER COLUMN parent_id SET DEFAULT '[0,1)', DROP CONSTRAINT temporal_partitioned_fk_mltrng2mltrng_fk, @@ -2650,10 +4157,67 @@ ALTER TABLE temporal_partitioned_fk_mltrng2mltrng FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_partitioned_mltrng ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; -ERROR: unsupported ON UPDATE action for foreign key constraint using PERIOD +UPDATE temporal_partitioned_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id = '[13,14)' WHERE id = '[12,13)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[8,9)'; + id | valid_at | parent_id +-------+---------------------------------------------------+----------- + [8,9) | {[2019-01-01,2020-01-01)} | [0,1) + [8,9) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [12,13) +(2 rows) + +UPDATE temporal_partitioned_mltrng SET id = '[13,14)' WHERE id = '[12,13)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[8,9)'; + id | valid_at | parent_id +-------+---------------------------------------------------+----------- + [8,9) | {[2019-01-01,2020-01-01)} | [0,1) + [8,9) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [0,1) +(2 rows) + +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[22,23)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[22,23)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[14,15)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[22,23)'); +UPDATE temporal_partitioned_mltrng SET id = '[23,24)' WHERE id = '[22,23)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[14,15)'; + id | valid_at | parent_id +---------+---------------------------+----------- + [14,15) | {[2018-01-01,2020-01-01)} | [0,1) + [14,15) | {[2020-01-01,2021-01-01)} | [22,23) +(2 rows) + -- -- partitioned FK referenced deletes SET DEFAULT -- +TRUNCATE temporal_partitioned_mltrng, temporal_partitioned_fk_mltrng2mltrng; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[0,1)', datemultirange(daterange(null, null))); +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[14,15)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[9,10)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[14,15)'); +DELETE FROM temporal_partitioned_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id = '[14,15)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[9,10)'; + id | valid_at | parent_id +--------+---------------------------------------------------+----------- + [9,10) | {[2019-01-01,2020-01-01)} | [0,1) + [9,10) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [14,15) +(2 rows) + +DELETE FROM temporal_partitioned_mltrng WHERE id = '[14,15)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[9,10)'; + id | valid_at | parent_id +--------+---------------------------------------------------+----------- + [9,10) | {[2019-01-01,2020-01-01)} | [0,1) + [9,10) | {[2018-01-01,2019-01-01),[2020-01-01,2021-01-01)} | [0,1) +(2 rows) + +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[24,25)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[24,25)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[15,16)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[24,25)'); +DELETE FROM temporal_partitioned_mltrng WHERE id = '[24,25)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[15,16)'; + id | valid_at | parent_id +---------+---------------------------+----------- + [15,16) | {[2018-01-01,2020-01-01)} | [0,1) + [15,16) | {[2020-01-01,2021-01-01)} | [24,25) +(2 rows) + DROP TABLE temporal_partitioned_fk_mltrng2mltrng; DROP TABLE temporal_partitioned_mltrng; RESET datestyle; diff --git a/src/test/regress/sql/without_overlaps.sql b/src/test/regress/sql/without_overlaps.sql index c5c89fe40ab5..224ddef84307 100644 --- a/src/test/regress/sql/without_overlaps.sql +++ b/src/test/regress/sql/without_overlaps.sql @@ -1424,8 +1424,26 @@ ALTER TABLE temporal_fk_rng2rng -- -- rng2rng test ON UPDATE/DELETE options -- +-- TOC: +-- referenced updates CASCADE +-- referenced deletes CASCADE +-- referenced updates SET NULL +-- referenced deletes SET NULL +-- referenced updates SET DEFAULT +-- referenced deletes SET DEFAULT +-- referenced updates CASCADE (two scalar cols) +-- referenced deletes CASCADE (two scalar cols) +-- referenced updates SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- referenced updates SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) +-- -- test FK referenced updates CASCADE +-- + TRUNCATE temporal_rng, temporal_fk_rng2rng; INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); @@ -1434,28 +1452,346 @@ ALTER TABLE temporal_fk_rng2rng FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_rng ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_rng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)'); +UPDATE temporal_rng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes CASCADE +-- + +TRUNCATE temporal_rng, temporal_fk_rng2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_rng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)'); +DELETE FROM temporal_rng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; +-- -- test FK referenced updates SET NULL +-- + TRUNCATE temporal_rng, temporal_fk_rng2rng; INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); ALTER TABLE temporal_fk_rng2rng + DROP CONSTRAINT temporal_fk_rng2rng_fk, ADD CONSTRAINT temporal_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_rng ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_rng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)'); +UPDATE temporal_rng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET NULL +-- + +TRUNCATE temporal_rng, temporal_fk_rng2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_rng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)'); +DELETE FROM temporal_rng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; +-- -- test FK referenced updates SET DEFAULT +-- + TRUNCATE temporal_rng, temporal_fk_rng2rng; INSERT INTO temporal_rng (id, valid_at) VALUES ('[-1,-1]', daterange(null, null)); INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); ALTER TABLE temporal_fk_rng2rng ALTER COLUMN parent_id SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk_rng2rng_fk, ADD CONSTRAINT temporal_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_rng ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_rng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)'); +UPDATE temporal_rng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET DEFAULT +-- + +TRUNCATE temporal_rng, temporal_fk_rng2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[-1,-1]', daterange(null, null)); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +DELETE FROM temporal_rng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)'); +DELETE FROM temporal_rng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced updates CASCADE (two scalar cols) +-- + +TRUNCATE temporal_rng2, temporal_fk2_rng2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_rng2rng + DROP CONSTRAINT temporal_fk2_rng2rng_fk, + ADD CONSTRAINT temporal_fk2_rng2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_rng2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)', '[8,9)'); +UPDATE temporal_rng2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes CASCADE (two scalar cols) +-- + +TRUNCATE temporal_rng2, temporal_fk2_rng2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET NULL (two scalar cols) +-- +TRUNCATE temporal_rng2, temporal_fk2_rng2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_rng2rng + DROP CONSTRAINT temporal_fk2_rng2rng_fk, + ADD CONSTRAINT temporal_fk2_rng2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_rng2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)', '[8,9)'); +UPDATE temporal_rng2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET NULL (two scalar cols) +-- + +TRUNCATE temporal_rng2, temporal_fk2_rng2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- + +TRUNCATE temporal_rng2, temporal_fk2_rng2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_rng2rng + DROP CONSTRAINT temporal_fk2_rng2rng_fk, + ADD CONSTRAINT temporal_fk2_rng2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET NULL (valid_at) ON UPDATE SET NULL; +-- ok: +ALTER TABLE temporal_fk2_rng2rng + DROP CONSTRAINT temporal_fk2_rng2rng_fk, + ADD CONSTRAINT temporal_fk2_rng2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET NULL (parent_id1) ON UPDATE SET NULL; +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET DEFAULT (two scalar cols) +-- + +TRUNCATE temporal_rng2, temporal_fk2_rng2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[-1,-1]', daterange(null, null)); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_rng2rng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + ALTER COLUMN parent_id2 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_rng2rng_fk, + ADD CONSTRAINT temporal_fk2_rng2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_rng2 SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)', '[8,9)'); +UPDATE temporal_rng2 SET id1 = '[9,10)', id2 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols) +-- + +TRUNCATE temporal_rng2, temporal_fk2_rng2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[-1,-1]', daterange(null, null)); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) +-- + +TRUNCATE temporal_rng2, temporal_fk2_rng2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[6,7)', daterange(null, null)); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', daterange('2018-01-01', '2021-01-01'), '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_rng2rng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_rng2rng_fk, + ADD CONSTRAINT temporal_fk2_rng2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET DEFAULT (valid_at) ON UPDATE SET DEFAULT; +-- ok: +ALTER TABLE temporal_fk2_rng2rng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_rng2rng_fk, + ADD CONSTRAINT temporal_fk2_rng2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET DEFAULT (parent_id1) ON UPDATE SET DEFAULT; +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[8,9)', daterange(null, null)); +INSERT INTO temporal_fk2_rng2rng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', daterange('2018-01-01', '2021-01-01'), '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2rng WHERE id = '[200,201)' ORDER BY id, valid_at; -- -- test FOREIGN KEY, multirange references multirange @@ -1855,6 +2191,408 @@ WHERE id = '[5,6)'; DELETE FROM temporal_fk_mltrng2mltrng WHERE id = '[3,4)'; DELETE FROM temporal_mltrng WHERE id = '[5,6)' AND valid_at = datemultirange(daterange('2018-01-01', '2018-02-01')); +-- + +-- +-- mltrng2mltrng test ON UPDATE/DELETE options +-- +-- TOC: +-- referenced updates CASCADE +-- referenced deletes CASCADE +-- referenced updates SET NULL +-- referenced deletes SET NULL +-- referenced updates SET DEFAULT +-- referenced deletes SET DEFAULT +-- referenced updates CASCADE (two scalar cols) +-- referenced deletes CASCADE (two scalar cols) +-- referenced updates SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- referenced updates SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) + +-- +-- test FK referenced updates CASCADE +-- + +TRUNCATE temporal_mltrng, temporal_fk_mltrng2mltrng; +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)'); +ALTER TABLE temporal_fk_mltrng2mltrng + DROP CONSTRAINT temporal_fk_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk_mltrng2mltrng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_mltrng + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_mltrng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)'); +UPDATE temporal_mltrng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes CASCADE +-- + +TRUNCATE temporal_mltrng, temporal_fk_mltrng2mltrng; +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_mltrng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)'); +DELETE FROM temporal_mltrng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET NULL +-- + +TRUNCATE temporal_mltrng, temporal_fk_mltrng2mltrng; +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)'); +ALTER TABLE temporal_fk_mltrng2mltrng + DROP CONSTRAINT temporal_fk_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk_mltrng2mltrng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_mltrng + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_mltrng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)'); +UPDATE temporal_mltrng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET NULL +-- + +TRUNCATE temporal_mltrng, temporal_fk_mltrng2mltrng; +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_mltrng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)'); +DELETE FROM temporal_mltrng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET DEFAULT +-- + +TRUNCATE temporal_mltrng, temporal_fk_mltrng2mltrng; +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[-1,-1]', datemultirange(daterange(null, null))); +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)'); +ALTER TABLE temporal_fk_mltrng2mltrng + ALTER COLUMN parent_id SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk_mltrng2mltrng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_mltrng + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_mltrng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)'); +UPDATE temporal_mltrng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET DEFAULT +-- + +TRUNCATE temporal_mltrng, temporal_fk_mltrng2mltrng; +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[-1,-1]', datemultirange(daterange(null, null))); +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +DELETE FROM temporal_mltrng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)'); +DELETE FROM temporal_mltrng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced updates CASCADE (two scalar cols) +-- + +TRUNCATE temporal_mltrng2, temporal_fk2_mltrng2mltrng; +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_mltrng2mltrng + DROP CONSTRAINT temporal_fk2_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk2_mltrng2mltrng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_mltrng2 + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_mltrng2 FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_mltrng2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)', '[8,9)'); +UPDATE temporal_mltrng2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes CASCADE (two scalar cols) +-- + +TRUNCATE temporal_mltrng2, temporal_fk2_mltrng2mltrng; +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_mltrng2 FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_mltrng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)', '[8,9)'); +DELETE FROM temporal_mltrng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET NULL (two scalar cols) +-- + +TRUNCATE temporal_mltrng2, temporal_fk2_mltrng2mltrng; +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_mltrng2mltrng + DROP CONSTRAINT temporal_fk2_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk2_mltrng2mltrng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_mltrng2 + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_mltrng2 FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_mltrng2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)', '[8,9)'); +UPDATE temporal_mltrng2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET NULL (two scalar cols) +-- + +TRUNCATE temporal_mltrng2, temporal_fk2_mltrng2mltrng; +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_mltrng2 FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_mltrng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)', '[8,9)'); +DELETE FROM temporal_mltrng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- + +TRUNCATE temporal_mltrng2, temporal_fk2_mltrng2mltrng; +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_mltrng2mltrng + DROP CONSTRAINT temporal_fk2_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk2_mltrng2mltrng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_mltrng2 + ON DELETE SET NULL (valid_at) ON UPDATE SET NULL; +-- ok: +ALTER TABLE temporal_fk2_mltrng2mltrng + DROP CONSTRAINT temporal_fk2_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk2_mltrng2mltrng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_mltrng2 + ON DELETE SET NULL (parent_id1) ON UPDATE SET NULL; +-- leftovers on both sides: +DELETE FROM temporal_mltrng2 FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_mltrng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)', '[8,9)'); +DELETE FROM temporal_mltrng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET DEFAULT (two scalar cols) +-- + +TRUNCATE temporal_mltrng2, temporal_fk2_mltrng2mltrng; +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[-1,-1]', datemultirange(daterange(null, null))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_mltrng2mltrng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + ALTER COLUMN parent_id2 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk2_mltrng2mltrng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_mltrng2 + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_mltrng2 FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_mltrng2 SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)', '[8,9)'); +UPDATE temporal_mltrng2 SET id1 = '[9,10)', id2 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols) +-- + +TRUNCATE temporal_mltrng2, temporal_fk2_mltrng2mltrng; +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[-1,-1]', datemultirange(daterange(null, null))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_mltrng2 FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +DELETE FROM temporal_mltrng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)', '[8,9)'); +DELETE FROM temporal_mltrng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) +-- + +TRUNCATE temporal_mltrng2, temporal_fk2_mltrng2mltrng; +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[6,7)', datemultirange(daterange(null, null))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[100,101)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_mltrng2mltrng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk2_mltrng2mltrng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_mltrng2 + ON DELETE SET DEFAULT (valid_at) ON UPDATE SET DEFAULT; +-- ok: +ALTER TABLE temporal_fk2_mltrng2mltrng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_mltrng2mltrng_fk, + ADD CONSTRAINT temporal_fk2_mltrng2mltrng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_mltrng2 + ON DELETE SET DEFAULT (parent_id1) ON UPDATE SET DEFAULT; +-- leftovers on both sides: +DELETE FROM temporal_mltrng2 FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- non-FPO update: +DELETE FROM temporal_mltrng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[100,101)' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_mltrng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[8,9)', datemultirange(daterange(null, null))); +INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VALUES ('[200,201)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)', '[8,9)'); +DELETE FROM temporal_mltrng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; + +-- FK with a custom range type + +CREATE TYPE mydaterange AS range(subtype=date); + +CREATE TABLE temporal_rng3 ( + id int4range, + valid_at mydaterange, + CONSTRAINT temporal_rng3_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +CREATE TABLE temporal_fk3_rng2rng ( + id int4range, + valid_at mydaterange, + parent_id int4range, + CONSTRAINT temporal_fk3_rng2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk3_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng3 (id, PERIOD valid_at) ON DELETE CASCADE +); +INSERT INTO temporal_rng3 (id, valid_at) VALUES ('[8,9)', mydaterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk3_rng2rng (id, valid_at, parent_id) VALUES ('[5,6)', mydaterange('2018-01-01', '2021-01-01'), '[8,9)'); +DELETE FROM temporal_rng3 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[8,9)'; +SELECT * FROM temporal_fk3_rng2rng WHERE id = '[5,6)'; + +DROP TABLE temporal_fk3_rng2rng; +DROP TABLE temporal_rng3; +DROP TYPE mydaterange; + -- -- FK between partitioned tables: ranges -- @@ -1865,8 +2603,8 @@ CREATE TABLE temporal_partitioned_rng ( name text, CONSTRAINT temporal_paritioned_rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) ) PARTITION BY LIST (id); -CREATE TABLE tp1 partition OF temporal_partitioned_rng FOR VALUES IN ('[1,2)', '[3,4)', '[5,6)', '[7,8)', '[9,10)', '[11,12)'); -CREATE TABLE tp2 partition OF temporal_partitioned_rng FOR VALUES IN ('[2,3)', '[4,5)', '[6,7)', '[8,9)', '[10,11)', '[12,13)'); +CREATE TABLE tp1 PARTITION OF temporal_partitioned_rng FOR VALUES IN ('[1,2)', '[3,4)', '[5,6)', '[7,8)', '[9,10)', '[11,12)', '[13,14)', '[15,16)', '[17,18)', '[19,20)', '[21,22)', '[23,24)'); +CREATE TABLE tp2 PARTITION OF temporal_partitioned_rng FOR VALUES IN ('[0,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)'); INSERT INTO temporal_partitioned_rng (id, valid_at, name) VALUES ('[1,2)', daterange('2000-01-01', '2000-02-01'), 'one'), ('[1,2)', daterange('2000-02-01', '2000-03-01'), 'one'), @@ -1880,8 +2618,8 @@ CREATE TABLE temporal_partitioned_fk_rng2rng ( CONSTRAINT temporal_partitioned_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_partitioned_rng (id, PERIOD valid_at) ) PARTITION BY LIST (id); -CREATE TABLE tfkp1 partition OF temporal_partitioned_fk_rng2rng FOR VALUES IN ('[1,2)', '[3,4)', '[5,6)', '[7,8)', '[9,10)', '[11,12)'); -CREATE TABLE tfkp2 partition OF temporal_partitioned_fk_rng2rng FOR VALUES IN ('[2,3)', '[4,5)', '[6,7)', '[8,9)', '[10,11)', '[12,13)'); +CREATE TABLE tfkp1 PARTITION OF temporal_partitioned_fk_rng2rng FOR VALUES IN ('[1,2)', '[3,4)', '[5,6)', '[7,8)', '[9,10)', '[11,12)', '[13,14)', '[15,16)', '[17,18)', '[19,20)', '[21,22)', '[23,24)'); +CREATE TABLE tfkp2 PARTITION OF temporal_partitioned_fk_rng2rng FOR VALUES IN ('[0,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)'); -- -- partitioned FK referencing inserts @@ -1940,36 +2678,90 @@ DELETE FROM temporal_partitioned_rng WHERE id = '[5,6)' AND valid_at = daterange -- partitioned FK referenced updates CASCADE -- +TRUNCATE temporal_partitioned_rng, temporal_partitioned_fk_rng2rng; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[4,5)', daterange('2018-01-01', '2021-01-01'), '[6,7)'); ALTER TABLE temporal_partitioned_fk_rng2rng DROP CONSTRAINT temporal_partitioned_fk_rng2rng_fk, ADD CONSTRAINT temporal_partitioned_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_partitioned_rng ON DELETE CASCADE ON UPDATE CASCADE; +UPDATE temporal_partitioned_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[4,5)'; +UPDATE temporal_partitioned_rng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[4,5)'; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[15,16)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[15,16)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[10,11)', daterange('2018-01-01', '2021-01-01'), '[15,16)'); +UPDATE temporal_partitioned_rng SET id = '[16,17)' WHERE id = '[15,16)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[10,11)'; -- -- partitioned FK referenced deletes CASCADE -- +TRUNCATE temporal_partitioned_rng, temporal_partitioned_fk_rng2rng; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[8,9)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[5,6)', daterange('2018-01-01', '2021-01-01'), '[8,9)'); +DELETE FROM temporal_partitioned_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[8,9)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[5,6)'; +DELETE FROM temporal_partitioned_rng WHERE id = '[8,9)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[5,6)'; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[17,18)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[17,18)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[11,12)', daterange('2018-01-01', '2021-01-01'), '[17,18)'); +DELETE FROM temporal_partitioned_rng WHERE id = '[17,18)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[11,12)'; + -- -- partitioned FK referenced updates SET NULL -- +TRUNCATE temporal_partitioned_rng, temporal_partitioned_fk_rng2rng; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[9,10)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[6,7)', daterange('2018-01-01', '2021-01-01'), '[9,10)'); ALTER TABLE temporal_partitioned_fk_rng2rng DROP CONSTRAINT temporal_partitioned_fk_rng2rng_fk, ADD CONSTRAINT temporal_partitioned_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_partitioned_rng ON DELETE SET NULL ON UPDATE SET NULL; +UPDATE temporal_partitioned_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[10,11)' WHERE id = '[9,10)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[6,7)'; +UPDATE temporal_partitioned_rng SET id = '[10,11)' WHERE id = '[9,10)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[6,7)'; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[18,19)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[18,19)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[12,13)', daterange('2018-01-01', '2021-01-01'), '[18,19)'); +UPDATE temporal_partitioned_rng SET id = '[19,20)' WHERE id = '[18,19)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[12,13)'; -- -- partitioned FK referenced deletes SET NULL -- +TRUNCATE temporal_partitioned_rng, temporal_partitioned_fk_rng2rng; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[11,12)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[7,8)', daterange('2018-01-01', '2021-01-01'), '[11,12)'); +DELETE FROM temporal_partitioned_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[11,12)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[7,8)'; +DELETE FROM temporal_partitioned_rng WHERE id = '[11,12)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[7,8)'; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[20,21)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[20,21)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[13,14)', daterange('2018-01-01', '2021-01-01'), '[20,21)'); +DELETE FROM temporal_partitioned_rng WHERE id = '[20,21)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[13,14)'; + -- -- partitioned FK referenced updates SET DEFAULT -- +TRUNCATE temporal_partitioned_rng, temporal_partitioned_fk_rng2rng; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[0,1)', daterange(null, null)); +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[12,13)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[8,9)', daterange('2018-01-01', '2021-01-01'), '[12,13)'); ALTER TABLE temporal_partitioned_fk_rng2rng ALTER COLUMN parent_id SET DEFAULT '[-1,-1]', DROP CONSTRAINT temporal_partitioned_fk_rng2rng_fk, @@ -1977,11 +2769,34 @@ ALTER TABLE temporal_partitioned_fk_rng2rng FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_partitioned_rng ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +UPDATE temporal_partitioned_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[13,14)' WHERE id = '[12,13)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[8,9)'; +UPDATE temporal_partitioned_rng SET id = '[13,14)' WHERE id = '[12,13)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[8,9)'; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[22,23)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[22,23)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[14,15)', daterange('2018-01-01', '2021-01-01'), '[22,23)'); +UPDATE temporal_partitioned_rng SET id = '[23,24)' WHERE id = '[22,23)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[14,15)'; -- -- partitioned FK referenced deletes SET DEFAULT -- +TRUNCATE temporal_partitioned_rng, temporal_partitioned_fk_rng2rng; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[0,1)', daterange(null, null)); +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[14,15)', daterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[9,10)', daterange('2018-01-01', '2021-01-01'), '[14,15)'); +DELETE FROM temporal_partitioned_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[14,15)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[9,10)'; +DELETE FROM temporal_partitioned_rng WHERE id = '[14,15)'; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[9,10)'; +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[24,25)', daterange('2018-01-01', '2020-01-01')); +INSERT INTO temporal_partitioned_rng (id, valid_at) VALUES ('[24,25)', daterange('2020-01-01', '2021-01-01')); +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES ('[15,16)', daterange('2018-01-01', '2021-01-01'), '[24,25)'); +DELETE FROM temporal_partitioned_rng WHERE id = '[24,25)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_rng2rng WHERE id = '[15,16)'; + DROP TABLE temporal_partitioned_fk_rng2rng; DROP TABLE temporal_partitioned_rng; @@ -2070,36 +2885,90 @@ DELETE FROM temporal_partitioned_mltrng WHERE id = '[5,6)' AND valid_at = datemu -- partitioned FK referenced updates CASCADE -- +TRUNCATE temporal_partitioned_mltrng, temporal_partitioned_fk_mltrng2mltrng; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[4,5)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[6,7)'); ALTER TABLE temporal_partitioned_fk_mltrng2mltrng DROP CONSTRAINT temporal_partitioned_fk_mltrng2mltrng_fk, ADD CONSTRAINT temporal_partitioned_fk_mltrng2mltrng_fk FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_partitioned_mltrng ON DELETE CASCADE ON UPDATE CASCADE; +UPDATE temporal_partitioned_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[4,5)'; +UPDATE temporal_partitioned_mltrng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[4,5)'; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[15,16)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[15,16)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[10,11)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[15,16)'); +UPDATE temporal_partitioned_mltrng SET id = '[16,17)' WHERE id = '[15,16)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[10,11)'; -- -- partitioned FK referenced deletes CASCADE -- +TRUNCATE temporal_partitioned_mltrng, temporal_partitioned_fk_mltrng2mltrng; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[8,9)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[5,6)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[8,9)'); +DELETE FROM temporal_partitioned_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id = '[8,9)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[5,6)'; +DELETE FROM temporal_partitioned_mltrng WHERE id = '[8,9)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[5,6)'; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[17,18)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[17,18)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[11,12)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[17,18)'); +DELETE FROM temporal_partitioned_mltrng WHERE id = '[17,18)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[11,12)'; + -- -- partitioned FK referenced updates SET NULL -- +TRUNCATE temporal_partitioned_mltrng, temporal_partitioned_fk_mltrng2mltrng; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[9,10)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[6,7)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[9,10)'); ALTER TABLE temporal_partitioned_fk_mltrng2mltrng DROP CONSTRAINT temporal_partitioned_fk_mltrng2mltrng_fk, ADD CONSTRAINT temporal_partitioned_fk_mltrng2mltrng_fk FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_partitioned_mltrng ON DELETE SET NULL ON UPDATE SET NULL; +UPDATE temporal_partitioned_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id = '[10,11)' WHERE id = '[9,10)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[6,7)'; +UPDATE temporal_partitioned_mltrng SET id = '[10,11)' WHERE id = '[9,10)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[6,7)'; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[18,19)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[18,19)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[12,13)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[18,19)'); +UPDATE temporal_partitioned_mltrng SET id = '[19,20)' WHERE id = '[18,19)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[12,13)'; -- -- partitioned FK referenced deletes SET NULL -- +TRUNCATE temporal_partitioned_mltrng, temporal_partitioned_fk_mltrng2mltrng; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[11,12)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[7,8)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[11,12)'); +DELETE FROM temporal_partitioned_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id = '[11,12)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[7,8)'; +DELETE FROM temporal_partitioned_mltrng WHERE id = '[11,12)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[7,8)'; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[20,21)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[20,21)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[13,14)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[20,21)'); +DELETE FROM temporal_partitioned_mltrng WHERE id = '[20,21)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[13,14)'; + -- -- partitioned FK referenced updates SET DEFAULT -- +TRUNCATE temporal_partitioned_mltrng, temporal_partitioned_fk_mltrng2mltrng; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[0,1)', datemultirange(daterange(null, null))); +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[12,13)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[8,9)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[12,13)'); ALTER TABLE temporal_partitioned_fk_mltrng2mltrng ALTER COLUMN parent_id SET DEFAULT '[0,1)', DROP CONSTRAINT temporal_partitioned_fk_mltrng2mltrng_fk, @@ -2107,11 +2976,34 @@ ALTER TABLE temporal_partitioned_fk_mltrng2mltrng FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_partitioned_mltrng ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +UPDATE temporal_partitioned_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) SET id = '[13,14)' WHERE id = '[12,13)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[8,9)'; +UPDATE temporal_partitioned_mltrng SET id = '[13,14)' WHERE id = '[12,13)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[8,9)'; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[22,23)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[22,23)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[14,15)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[22,23)'); +UPDATE temporal_partitioned_mltrng SET id = '[23,24)' WHERE id = '[22,23)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[14,15)'; -- -- partitioned FK referenced deletes SET DEFAULT -- +TRUNCATE temporal_partitioned_mltrng, temporal_partitioned_fk_mltrng2mltrng; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[0,1)', datemultirange(daterange(null, null))); +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[14,15)', datemultirange(daterange('2018-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[9,10)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[14,15)'); +DELETE FROM temporal_partitioned_mltrng FOR PORTION OF valid_at (datemultirange(daterange('2019-01-01', '2020-01-01'))) WHERE id = '[14,15)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[9,10)'; +DELETE FROM temporal_partitioned_mltrng WHERE id = '[14,15)'; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[9,10)'; +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[24,25)', datemultirange(daterange('2018-01-01', '2020-01-01'))); +INSERT INTO temporal_partitioned_mltrng (id, valid_at) VALUES ('[24,25)', datemultirange(daterange('2020-01-01', '2021-01-01'))); +INSERT INTO temporal_partitioned_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES ('[15,16)', datemultirange(daterange('2018-01-01', '2021-01-01')), '[24,25)'); +DELETE FROM temporal_partitioned_mltrng WHERE id = '[24,25)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[15,16)'; + DROP TABLE temporal_partitioned_fk_mltrng2mltrng; DROP TABLE temporal_partitioned_mltrng; From d089a53fb10ad85c08ed8762ac09f5f94b488644 Mon Sep 17 00:00:00 2001 From: "Paul A. Jungwirth" Date: Tue, 29 Oct 2024 18:54:37 -0700 Subject: [PATCH 10/11] Expose FOR PORTION OF to plpgsql triggers It is helpful for triggers to see what the FOR PORTION OF clause specified: both the column/period name and the targeted bounds. Our RI triggers require this information, and we are passing it as part of the TriggerData struct. This commit allows plpgsql trigger functions to access the same information, using the new TG_PERIOD_COLUMN and TG_PERIOD_TARGET variables. Author: Paul A. Jungwirth --- doc/src/sgml/plpgsql.sgml | 24 +++++++++ src/pl/plpgsql/src/pl_comp.c | 26 +++++++++ src/pl/plpgsql/src/pl_exec.c | 32 ++++++++++++ src/pl/plpgsql/src/plpgsql.h | 2 + src/test/regress/expected/for_portion_of.out | 55 +++++++++++--------- src/test/regress/sql/for_portion_of.sql | 9 +++- 6 files changed, 121 insertions(+), 27 deletions(-) diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml index e937491e6b89..f5199872e2e1 100644 --- a/doc/src/sgml/plpgsql.sgml +++ b/doc/src/sgml/plpgsql.sgml @@ -4247,6 +4247,30 @@ ASSERT condition , + + + TG_PERIOD_NAME text + + + the column name used in a FOR PORTION OF clause, + or else NULL. + + + + + + TG_PERIOD_BOUNDS text + + + the range/multirange/etc. given as the bounds of a + FOR PORTION OF clause, either directly (with parens syntax) + or computed from the FROM and TO bounds. + NULL if FOR PORTION OF was not used. + This is a text value based on the type's output function, + since the type can't be known at function creation time. + + + diff --git a/src/pl/plpgsql/src/pl_comp.c b/src/pl/plpgsql/src/pl_comp.c index f6976689a692..59776358a653 100644 --- a/src/pl/plpgsql/src/pl_comp.c +++ b/src/pl/plpgsql/src/pl_comp.c @@ -617,6 +617,32 @@ plpgsql_compile_callback(FunctionCallInfo fcinfo, var->dtype = PLPGSQL_DTYPE_PROMISE; ((PLpgSQL_var *) var)->promise = PLPGSQL_PROMISE_TG_ARGV; + /* Add the variable tg_period_name */ + var = plpgsql_build_variable("tg_period_name", 0, + plpgsql_build_datatype(TEXTOID, + -1, + function->fn_input_collation, + NULL), + true); + Assert(var->dtype == PLPGSQL_DTYPE_VAR); + var->dtype = PLPGSQL_DTYPE_PROMISE; + ((PLpgSQL_var *) var)->promise = PLPGSQL_PROMISE_TG_PERIOD_NAME; + + /* + * Add the variable to tg_period_bounds. This could be any + * rangetype or multirangetype or user-supplied type, so the best + * we can offer is a TEXT variable. + */ + var = plpgsql_build_variable("tg_period_bounds", 0, + plpgsql_build_datatype(TEXTOID, + -1, + function->fn_input_collation, + NULL), + true); + Assert(var->dtype == PLPGSQL_DTYPE_VAR); + var->dtype = PLPGSQL_DTYPE_PROMISE; + ((PLpgSQL_var *) var)->promise = PLPGSQL_PROMISE_TG_PERIOD_BOUNDS; + break; case PLPGSQL_EVENT_TRIGGER: diff --git a/src/pl/plpgsql/src/pl_exec.c b/src/pl/plpgsql/src/pl_exec.c index d19425b7a71a..11eb5a60a799 100644 --- a/src/pl/plpgsql/src/pl_exec.c +++ b/src/pl/plpgsql/src/pl_exec.c @@ -1385,6 +1385,7 @@ plpgsql_fulfill_promise(PLpgSQL_execstate *estate, PLpgSQL_var *var) { MemoryContext oldcontext; + ForPortionOfState *fpo; if (var->promise == PLPGSQL_PROMISE_NONE) return; /* nothing to do */ @@ -1516,6 +1517,37 @@ plpgsql_fulfill_promise(PLpgSQL_execstate *estate, } break; + case PLPGSQL_PROMISE_TG_PERIOD_NAME: + if (estate->trigdata == NULL) + elog(ERROR, "trigger promise is not in a trigger function"); + if (estate->trigdata->tg_temporal) + assign_text_var(estate, var, estate->trigdata->tg_temporal->fp_rangeName); + else + assign_simple_var(estate, var, (Datum) 0, true, false); + break; + + case PLPGSQL_PROMISE_TG_PERIOD_BOUNDS: + fpo = estate->trigdata->tg_temporal; + + if (estate->trigdata == NULL) + elog(ERROR, "trigger promise is not in a trigger function"); + if (fpo) + { + + Oid funcid; + bool varlena; + + getTypeOutputInfo(fpo->fp_rangeType, &funcid, &varlena); + Assert(OidIsValid(funcid)); + + assign_text_var(estate, var, + OidOutputFunctionCall(funcid, + fpo->fp_targetRange)); + } + else + assign_simple_var(estate, var, (Datum) 0, true, false); + break; + case PLPGSQL_PROMISE_TG_EVENT: if (estate->evtrigdata == NULL) elog(ERROR, "event trigger promise is not in an event trigger function"); diff --git a/src/pl/plpgsql/src/plpgsql.h b/src/pl/plpgsql/src/plpgsql.h index 5f193a371839..8000104bc89c 100644 --- a/src/pl/plpgsql/src/plpgsql.h +++ b/src/pl/plpgsql/src/plpgsql.h @@ -85,6 +85,8 @@ typedef enum PLpgSQL_promise_type PLPGSQL_PROMISE_TG_ARGV, PLPGSQL_PROMISE_TG_EVENT, PLPGSQL_PROMISE_TG_TAG, + PLPGSQL_PROMISE_TG_PERIOD_NAME, + PLPGSQL_PROMISE_TG_PERIOD_BOUNDS, } PLpgSQL_promise_type; /* diff --git a/src/test/regress/expected/for_portion_of.out b/src/test/regress/expected/for_portion_of.out index 9288b4224f73..52fb044d2e58 100644 --- a/src/test/regress/expected/for_portion_of.out +++ b/src/test/regress/expected/for_portion_of.out @@ -613,8 +613,13 @@ CREATE FUNCTION dump_trigger() RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN - RAISE NOTICE '%: % % %:', - TG_NAME, TG_WHEN, TG_OP, TG_LEVEL; + IF TG_PERIOD_NAME IS NOT NULL THEN + RAISE NOTICE '%: % % FOR PORTION OF % (%) %:', + TG_NAME, TG_WHEN, TG_OP, TG_PERIOD_NAME, TG_PERIOD_BOUNDS, TG_LEVEL; + ELSE + RAISE NOTICE '%: % % %:', + TG_NAME, TG_WHEN, TG_OP, TG_LEVEL; + END IF; IF TG_ARGV[0] THEN RAISE NOTICE ' old: %', (SELECT string_agg(old_table::text, '\n ') FROM old_table); @@ -664,10 +669,10 @@ UPDATE for_portion_of_test FOR PORTION OF valid_at FROM '2021-01-01' TO '2022-01-01' SET name = 'five^3' WHERE id = '[5,6)'; -NOTICE: fpo_before_stmt: BEFORE UPDATE STATEMENT: +NOTICE: fpo_before_stmt: BEFORE UPDATE FOR PORTION OF valid_at ([2021-01-01,2022-01-01)) STATEMENT: NOTICE: old: NOTICE: new: -NOTICE: fpo_before_row: BEFORE UPDATE ROW: +NOTICE: fpo_before_row: BEFORE UPDATE FOR PORTION OF valid_at ([2021-01-01,2022-01-01)) ROW: NOTICE: old: [2019-01-01,2030-01-01) NOTICE: new: [2021-01-01,2022-01-01) NOTICE: fpo_before_stmt: BEFORE INSERT STATEMENT: @@ -694,19 +699,19 @@ NOTICE: new: [2022-01-01,2030-01-01) NOTICE: fpo_after_insert_stmt: AFTER INSERT STATEMENT: NOTICE: old: NOTICE: new: -NOTICE: fpo_after_update_row: AFTER UPDATE ROW: +NOTICE: fpo_after_update_row: AFTER UPDATE FOR PORTION OF valid_at ([2021-01-01,2022-01-01)) ROW: NOTICE: old: [2019-01-01,2030-01-01) NOTICE: new: [2021-01-01,2022-01-01) -NOTICE: fpo_after_update_stmt: AFTER UPDATE STATEMENT: +NOTICE: fpo_after_update_stmt: AFTER UPDATE FOR PORTION OF valid_at ([2021-01-01,2022-01-01)) STATEMENT: NOTICE: old: NOTICE: new: DELETE FROM for_portion_of_test FOR PORTION OF valid_at FROM '2023-01-01' TO '2024-01-01' WHERE id = '[5,6)'; -NOTICE: fpo_before_stmt: BEFORE DELETE STATEMENT: +NOTICE: fpo_before_stmt: BEFORE DELETE FOR PORTION OF valid_at ([2023-01-01,2024-01-01)) STATEMENT: NOTICE: old: NOTICE: new: -NOTICE: fpo_before_row: BEFORE DELETE ROW: +NOTICE: fpo_before_row: BEFORE DELETE FOR PORTION OF valid_at ([2023-01-01,2024-01-01)) ROW: NOTICE: old: [2022-01-01,2030-01-01) NOTICE: new: NOTICE: fpo_before_stmt: BEFORE INSERT STATEMENT: @@ -733,10 +738,10 @@ NOTICE: new: [2024-01-01,2030-01-01) NOTICE: fpo_after_insert_stmt: AFTER INSERT STATEMENT: NOTICE: old: NOTICE: new: -NOTICE: fpo_after_delete_row: AFTER DELETE ROW: +NOTICE: fpo_after_delete_row: AFTER DELETE FOR PORTION OF valid_at ([2023-01-01,2024-01-01)) ROW: NOTICE: old: [2022-01-01,2030-01-01) NOTICE: new: -NOTICE: fpo_after_delete_stmt: AFTER DELETE STATEMENT: +NOTICE: fpo_after_delete_stmt: AFTER DELETE FOR PORTION OF valid_at ([2023-01-01,2024-01-01)) STATEMENT: NOTICE: old: NOTICE: new: SELECT * FROM for_portion_of_test ORDER BY id, valid_at; @@ -802,10 +807,10 @@ BEGIN; UPDATE for_portion_of_test FOR PORTION OF valid_at FROM '2018-01-15' TO '2019-01-01' SET name = '2018-01-15_to_2019-01-01'; -NOTICE: fpo_before_stmt: BEFORE UPDATE STATEMENT: +NOTICE: fpo_before_stmt: BEFORE UPDATE FOR PORTION OF valid_at ([2018-01-15,2019-01-01)) STATEMENT: NOTICE: old: NOTICE: new: -NOTICE: fpo_before_row: BEFORE UPDATE ROW: +NOTICE: fpo_before_row: BEFORE UPDATE FOR PORTION OF valid_at ([2018-01-15,2019-01-01)) ROW: NOTICE: old: [2018-01-01,2020-01-01) NOTICE: new: [2018-01-15,2019-01-01) NOTICE: fpo_before_stmt: BEFORE INSERT STATEMENT: @@ -832,20 +837,20 @@ NOTICE: new: ("[1,2)","[2019-01-01,2020-01-01)",one) NOTICE: fpo_after_insert_stmt: AFTER INSERT STATEMENT: NOTICE: old: NOTICE: new: ("[1,2)","[2019-01-01,2020-01-01)",one) -NOTICE: fpo_after_update_row: AFTER UPDATE ROW: +NOTICE: fpo_after_update_row: AFTER UPDATE FOR PORTION OF valid_at ([2018-01-15,2019-01-01)) ROW: NOTICE: old: ("[1,2)","[2018-01-01,2020-01-01)",one) NOTICE: new: ("[1,2)","[2018-01-15,2019-01-01)",2018-01-15_to_2019-01-01) -NOTICE: fpo_after_update_stmt: AFTER UPDATE STATEMENT: +NOTICE: fpo_after_update_stmt: AFTER UPDATE FOR PORTION OF valid_at ([2018-01-15,2019-01-01)) STATEMENT: NOTICE: old: ("[1,2)","[2018-01-01,2020-01-01)",one) NOTICE: new: ("[1,2)","[2018-01-15,2019-01-01)",2018-01-15_to_2019-01-01) ROLLBACK; BEGIN; DELETE FROM for_portion_of_test FOR PORTION OF valid_at FROM NULL TO '2018-01-21'; -NOTICE: fpo_before_stmt: BEFORE DELETE STATEMENT: +NOTICE: fpo_before_stmt: BEFORE DELETE FOR PORTION OF valid_at ((,2018-01-21)) STATEMENT: NOTICE: old: NOTICE: new: -NOTICE: fpo_before_row: BEFORE DELETE ROW: +NOTICE: fpo_before_row: BEFORE DELETE FOR PORTION OF valid_at ((,2018-01-21)) ROW: NOTICE: old: [2018-01-01,2020-01-01) NOTICE: new: NOTICE: fpo_before_stmt: BEFORE INSERT STATEMENT: @@ -860,10 +865,10 @@ NOTICE: new: ("[1,2)","[2018-01-21,2020-01-01)",one) NOTICE: fpo_after_insert_stmt: AFTER INSERT STATEMENT: NOTICE: old: NOTICE: new: ("[1,2)","[2018-01-21,2020-01-01)",one) -NOTICE: fpo_after_delete_row: AFTER DELETE ROW: +NOTICE: fpo_after_delete_row: AFTER DELETE FOR PORTION OF valid_at ((,2018-01-21)) ROW: NOTICE: old: ("[1,2)","[2018-01-01,2020-01-01)",one) NOTICE: new: -NOTICE: fpo_after_delete_stmt: AFTER DELETE STATEMENT: +NOTICE: fpo_after_delete_stmt: AFTER DELETE FOR PORTION OF valid_at ((,2018-01-21)) STATEMENT: NOTICE: old: ("[1,2)","[2018-01-01,2020-01-01)",one) NOTICE: new: ROLLBACK; @@ -871,10 +876,10 @@ BEGIN; UPDATE for_portion_of_test FOR PORTION OF valid_at FROM NULL TO '2018-01-02' SET name = 'NULL_to_2018-01-01'; -NOTICE: fpo_before_stmt: BEFORE UPDATE STATEMENT: +NOTICE: fpo_before_stmt: BEFORE UPDATE FOR PORTION OF valid_at ((,2018-01-02)) STATEMENT: NOTICE: old: NOTICE: new: -NOTICE: fpo_before_row: BEFORE UPDATE ROW: +NOTICE: fpo_before_row: BEFORE UPDATE FOR PORTION OF valid_at ((,2018-01-02)) ROW: NOTICE: old: [2018-01-01,2020-01-01) NOTICE: new: [2018-01-01,2018-01-02) NOTICE: fpo_before_stmt: BEFORE INSERT STATEMENT: @@ -889,10 +894,10 @@ NOTICE: new: ("[1,2)","[2018-01-02,2020-01-01)",one) NOTICE: fpo_after_insert_stmt: AFTER INSERT STATEMENT: NOTICE: old: NOTICE: new: ("[1,2)","[2018-01-02,2020-01-01)",one) -NOTICE: fpo_after_update_row: AFTER UPDATE ROW: +NOTICE: fpo_after_update_row: AFTER UPDATE FOR PORTION OF valid_at ((,2018-01-02)) ROW: NOTICE: old: ("[1,2)","[2018-01-01,2020-01-01)",one) NOTICE: new: ("[1,2)","[2018-01-01,2018-01-02)",NULL_to_2018-01-01) -NOTICE: fpo_after_update_stmt: AFTER UPDATE STATEMENT: +NOTICE: fpo_after_update_stmt: AFTER UPDATE FOR PORTION OF valid_at ((,2018-01-02)) STATEMENT: NOTICE: old: ("[1,2)","[2018-01-01,2020-01-01)",one) NOTICE: new: ("[1,2)","[2018-01-01,2018-01-02)",NULL_to_2018-01-01) ROLLBACK; @@ -929,7 +934,7 @@ NOTICE: new: [2018-01-01,2018-01-15) NOTICE: fpo_after_insert_row: AFTER INSERT ROW: NOTICE: old: NOTICE: new: [2019-01-01,2020-01-01) -NOTICE: fpo_after_update_row: AFTER UPDATE ROW: +NOTICE: fpo_after_update_row: AFTER UPDATE FOR PORTION OF valid_at ([2018-01-15,2019-01-01)) ROW: NOTICE: old: [2018-01-01,2020-01-01) NOTICE: new: [2018-01-15,2019-01-01) BEGIN; @@ -939,10 +944,10 @@ COMMIT; NOTICE: fpo_after_insert_row: AFTER INSERT ROW: NOTICE: old: NOTICE: new: [2018-01-21,2019-01-01) -NOTICE: fpo_after_delete_row: AFTER DELETE ROW: +NOTICE: fpo_after_delete_row: AFTER DELETE FOR PORTION OF valid_at ((,2018-01-21)) ROW: NOTICE: old: [2018-01-15,2019-01-01) NOTICE: new: -NOTICE: fpo_after_delete_row: AFTER DELETE ROW: +NOTICE: fpo_after_delete_row: AFTER DELETE FOR PORTION OF valid_at ((,2018-01-21)) ROW: NOTICE: old: [2018-01-01,2018-01-15) NOTICE: new: BEGIN; diff --git a/src/test/regress/sql/for_portion_of.sql b/src/test/regress/sql/for_portion_of.sql index 0e6c2db5a75b..7493cc4c233d 100644 --- a/src/test/regress/sql/for_portion_of.sql +++ b/src/test/regress/sql/for_portion_of.sql @@ -484,8 +484,13 @@ CREATE FUNCTION dump_trigger() RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN - RAISE NOTICE '%: % % %:', - TG_NAME, TG_WHEN, TG_OP, TG_LEVEL; + IF TG_PERIOD_NAME IS NOT NULL THEN + RAISE NOTICE '%: % % FOR PORTION OF % (%) %:', + TG_NAME, TG_WHEN, TG_OP, TG_PERIOD_NAME, TG_PERIOD_BOUNDS, TG_LEVEL; + ELSE + RAISE NOTICE '%: % % %:', + TG_NAME, TG_WHEN, TG_OP, TG_LEVEL; + END IF; IF TG_ARGV[0] THEN RAISE NOTICE ' old: %', (SELECT string_agg(old_table::text, '\n ') FROM old_table); From 64c7c252924b5850833eb953036cf62cdc3baced Mon Sep 17 00:00:00 2001 From: "Paul A. Jungwirth" Date: Tue, 17 Jun 2025 23:23:23 -0700 Subject: [PATCH 11/11] Add PERIODs - Added parsing for SQL:2011 syntax to define an application-time PERIOD on a table (in both CREATE TABLE and ALTER TABLE). Make sure we create the PERIOD after columns are known (since PERIODs can refer to them) but before constraints are handled (since PERIODs can appear in them). - Added ALTER TABLE DROP support for PERIODs. - Created postgres.pg_period table. - Created information_schema.periods view. - Added pg_dump support. - Added tests and documentation. - Automatically define a constraint for each PERIOD requiring the start column to be less than the end column. - When creating a PERIOD, choose an appropriate range type we can use to implement PERIOD-related operations. You can choose one explicitly if there is ambiguity (due to multiple range types created over the same base type). Author: Paul Jungwirth --- doc/src/sgml/catalogs.sgml | 112 + doc/src/sgml/ddl.sgml | 46 + doc/src/sgml/information_schema.sgml | 63 + doc/src/sgml/plpgsql.sgml | 2 +- doc/src/sgml/ref/alter_table.sgml | 31 +- doc/src/sgml/ref/comment.sgml | 2 + doc/src/sgml/ref/create_table.sgml | 65 +- doc/src/sgml/ref/delete.sgml | 21 +- doc/src/sgml/ref/update.sgml | 21 +- doc/src/sgml/trigger.sgml | 9 +- src/backend/catalog/Makefile | 1 + src/backend/catalog/aclchk.c | 2 + src/backend/catalog/dependency.c | 13 + src/backend/catalog/heap.c | 75 + src/backend/catalog/information_schema.sql | 23 +- src/backend/catalog/meson.build | 1 + src/backend/catalog/objectaddress.c | 72 + src/backend/catalog/pg_constraint.c | 10 +- src/backend/catalog/pg_period.c | 132 + src/backend/catalog/sql_features.txt | 2 +- src/backend/commands/comment.c | 10 + src/backend/commands/dropcmds.c | 1 + src/backend/commands/event_trigger.c | 2 + src/backend/commands/seclabel.c | 1 + src/backend/commands/tablecmds.c | 978 +++- src/backend/commands/trigger.c | 2 + src/backend/commands/view.c | 4 +- src/backend/executor/nodeModifyTable.c | 41 +- src/backend/nodes/nodeFuncs.c | 3 + src/backend/parser/analyze.c | 130 +- src/backend/parser/gram.y | 45 +- src/backend/parser/parse_relation.c | 10 + src/backend/parser/parse_utilcmd.c | 182 +- src/backend/utils/adt/Makefile | 1 + src/backend/utils/adt/period.c | 58 + src/backend/utils/cache/lsyscache.c | 88 + src/bin/pg_dump/pg_backup_archiver.c | 1 + src/bin/pg_dump/pg_dump.c | 180 +- src/bin/pg_dump/pg_dump.h | 15 + src/bin/pg_dump/pg_dump_sort.c | 24 + src/bin/psql/describe.c | 36 + src/include/catalog/Makefile | 1 + src/include/catalog/heap.h | 4 + src/include/catalog/meson.build | 1 + src/include/catalog/pg_constraint.h | 3 +- src/include/catalog/pg_index.h | 1 - src/include/catalog/pg_period.h | 58 + src/include/catalog/pg_range.h | 2 + src/include/commands/tablecmds.h | 4 +- src/include/nodes/execnodes.h | 4 + src/include/nodes/parsenodes.h | 39 +- src/include/nodes/primnodes.h | 2 + src/include/parser/kwlist.h | 2 +- src/include/parser/parse_utilcmd.h | 1 + src/include/utils/lsyscache.h | 3 + src/include/utils/period.h | 21 + .../test_ddl_deparse/test_ddl_deparse.c | 6 + src/test/regress/expected/for_portion_of.out | 58 + src/test/regress/expected/periods.out | 318 ++ src/test/regress/expected/privileges.out | 29 + .../regress/expected/without_overlaps.out | 4500 ++++++++++++++++- src/test/regress/parallel_schedule | 2 +- src/test/regress/sql/for_portion_of.sql | 50 + src/test/regress/sql/periods.sql | 198 + src/test/regress/sql/privileges.sql | 28 + src/test/regress/sql/without_overlaps.sql | 3063 ++++++++++- src/tools/pgindent/typedefs.list | 3 + 67 files changed, 10695 insertions(+), 221 deletions(-) create mode 100644 src/backend/catalog/pg_period.c create mode 100644 src/backend/utils/adt/period.c create mode 100644 src/include/catalog/pg_period.h create mode 100644 src/include/utils/period.h create mode 100644 src/test/regress/expected/periods.out create mode 100644 src/test/regress/sql/periods.sql diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml index 6c8a0f173c97..eff736626b13 100644 --- a/doc/src/sgml/catalogs.sgml +++ b/doc/src/sgml/catalogs.sgml @@ -230,6 +230,11 @@ information about partition key of tables + + pg_period + periods + + pg_policy row-security policies @@ -5773,6 +5778,113 @@ SCRAM-SHA-256$<iteration count>:&l are simple references. + + + + + + + + + <structname>pg_period</structname> + + + pg_period + + + + The catalog pg_period stores + information about system and application time periods. + + + + Periods are described in . + + + + <structname>pg_period</structname> Columns + + + + + + Column Type + + + Description + + + + + + + + oid oid + + + Row identifier + + + + + + pername text + + + Period name + + + + + + perrelid oid + (references pg_class.oid) + + + The table this period belongs to + + + + + + perstart int2 + (references pg_attribute.attnum) + + + The number of the start column + + + + + + perend int2 + (references pg_attribute.attnum) + + + The number of the end column + + + + + + perrange int2 + (references pg_attribute.attnum) + + + The number of the GENERATED column that implements the PERIOD. + + + + + + perconstraint oid + (references pg_constraint.oid) + + + The OID of the period's CHECK constraint + + +
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index 13c174b47a97..cf1730d7bcac 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -1601,6 +1601,52 @@ CREATE TABLE circles ( tables. + + Periods + + + periods + + + + A period is metadata attached to a table + uniting two columns, a start time and end time, into one range-like + construct. Periods are used to represent system time and application time. A system-time + period must be named system_time, and an + application-time period can be named anything else. Their names must + not conflict with column names from the same table. + + + + Application-time periods are referenced in several temporal operations described in + this chapter: temporal primary keys, unique constraints, foreign keys, + update commands, and delete commands. + In all cases, PostgreSQL supports either periods + or regular columns with a rangetype or + multirangetype. + + + + Application periods are defined on a table using the following syntax: + + + +CREATE TABLE billing_addresses ( + customer_id integer, + address_id integer, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til) +); + + + + Periods for SYSTEM_TIME are currently not implemented. + + + Application Time diff --git a/doc/src/sgml/information_schema.sgml b/doc/src/sgml/information_schema.sgml index 19dffe7be6aa..91b26881c650 100644 --- a/doc/src/sgml/information_schema.sgml +++ b/doc/src/sgml/information_schema.sgml @@ -4171,6 +4171,69 @@ ORDER BY c.ordinal_position;
+ + <literal>periods</literal> + + + The view periods contains information about the + periods of all tables in the current database. The start and end column + names are only shown if the current user has access to them (by way of being + the owner or having some privilege). + + + + <literal>periods</literal> Columns + + + + + Name + Data Type + Description + + + + + + table_catalog + sql_identifier + Name of the database containing the period (always the current database) + + + + table_schema + sql_identifier + Name of the schema containing the period + + + + table_name + sql_identifier + Name of the table containing the period + + + + period_name + sql_identifier + Name of the period + + + + start_column_name + sql_identifier + Name of the start column for the period + + + + end_column_name + sql_identifier + Name of the end column for the period + + + +
+
+ <literal>referential_constraints</literal> diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml index f5199872e2e1..dab9864c94bb 100644 --- a/doc/src/sgml/plpgsql.sgml +++ b/doc/src/sgml/plpgsql.sgml @@ -4252,7 +4252,7 @@ ASSERT condition , TG_PERIOD_NAME text - the column name used in a FOR PORTION OF clause, + the column/period name used in a FOR PORTION OF clause, or else NULL. diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml index bea9f90138ba..3309a0a99010 100644 --- a/doc/src/sgml/ref/alter_table.sgml +++ b/doc/src/sgml/ref/alter_table.sgml @@ -62,6 +62,8 @@ ALTER TABLE [ IF EXISTS ] name ALTER CONSTRAINT constraint_name [ INHERIT | NO INHERIT ] VALIDATE CONSTRAINT constraint_name DROP CONSTRAINT [ IF EXISTS ] constraint_name [ RESTRICT | CASCADE ] + ADD PERIOD FOR period_name ( start_column, end_column ) [ WITH ( period_option = value [, ... ] ) ] + DROP PERIOD FOR period_name [ RESTRICT | CASCADE ] DISABLE TRIGGER [ trigger_name | ALL | USER ] ENABLE TRIGGER [ trigger_name | ALL | USER ] ENABLE REPLICA TRIGGER trigger_name @@ -116,10 +118,10 @@ WITH ( MODULUS numeric_literal, REM [ CONSTRAINT constraint_name ] { CHECK ( expression ) [ NO INHERIT ] | NOT NULL column_name [ NO INHERIT ] | - UNIQUE [ NULLS [ NOT ] DISTINCT ] ( column_name [, ... ] [, column_name WITHOUT OVERLAPS ] ) index_parameters | - PRIMARY KEY ( column_name [, ... ] [, column_name WITHOUT OVERLAPS ] ) index_parameters | + UNIQUE [ NULLS [ NOT ] DISTINCT ] ( column_name [, ... ] [, { column_name | period_name } WITHOUT OVERLAPS ] ) index_parameters | + PRIMARY KEY ( column_name [, ... ] [, { column_name | period_name } WITHOUT OVERLAPS ] ) index_parameters | EXCLUDE [ USING index_method ] ( exclude_element WITH operator [, ... ] ) index_parameters [ WHERE ( predicate ) ] | - FOREIGN KEY ( column_name [, ... ] [, PERIOD column_name ] ) REFERENCES reftable [ ( refcolumn [, ... ] [, PERIOD refcolumn ] ) ] + FOREIGN KEY ( column_name [, ... ] [, PERIOD { column_name | period_name } ] ) REFERENCES reftable [ ( refcolumn [, ... ] [, PERIOD { refcolumn | period_name } ] ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ] [ ON DELETE referential_action ] [ ON UPDATE referential_action ] } [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ] [ ENFORCED | NOT ENFORCED ] @@ -624,6 +626,29 @@ WITH ( MODULUS numeric_literal, REM + + ADD PERIOD FOR + + + This form adds a new period to a table using the same syntax as + . + + + + + + DROP PERIOD FOR + + + This form drops the specified period on a table. The start and end + columns will not be dropped by this command but the + CHECK constraint will be. You will need to say + CASCADE if anything outside the table depends on the + column. + + + + DISABLE/ENABLE [ REPLICA | ALWAYS ] TRIGGER diff --git a/doc/src/sgml/ref/comment.sgml b/doc/src/sgml/ref/comment.sgml index 5b43c56b1335..49c2df994497 100644 --- a/doc/src/sgml/ref/comment.sgml +++ b/doc/src/sgml/ref/comment.sgml @@ -44,6 +44,7 @@ COMMENT ON OPERATOR operator_name (left_type, right_type) | OPERATOR CLASS object_name USING index_method | OPERATOR FAMILY object_name USING index_method | + PERIOD relation_name.period_name | POLICY policy_name ON table_name | [ PROCEDURAL ] LANGUAGE object_name | PROCEDURE procedure_name [ ( [ [ argmode ] [ argname ] argtype [, ...] ] ) ] | @@ -341,6 +342,7 @@ COMMENT ON OPERATOR ^ (text, text) IS 'Performs intersection of two texts'; COMMENT ON OPERATOR - (NONE, integer) IS 'Unary minus'; COMMENT ON OPERATOR CLASS int4ops USING btree IS '4 byte integer operators for btrees'; COMMENT ON OPERATOR FAMILY integer_ops USING btree IS 'all integer operators for btrees'; +COMMENT ON PERIOD my_table.my_column IS 'Sales promotion validity'; COMMENT ON POLICY my_policy ON mytable IS 'Filter rows by users'; COMMENT ON PROCEDURE my_proc (integer, integer) IS 'Runs a report'; COMMENT ON PUBLICATION alltables IS 'Publishes all operations on all tables'; diff --git a/doc/src/sgml/ref/create_table.sgml b/doc/src/sgml/ref/create_table.sgml index 975d5daa0c16..f3dcda78cf49 100644 --- a/doc/src/sgml/ref/create_table.sgml +++ b/doc/src/sgml/ref/create_table.sgml @@ -23,6 +23,7 @@ PostgreSQL documentation CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXISTS ] table_name ( [ { column_name data_type [ STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN | DEFAULT } ] [ COMPRESSION compression_method ] [ COLLATE collation ] [ column_constraint [ ... ] ] + | period_definition | table_constraint | LIKE source_table [ like_option ... ] } [, ... ] @@ -37,6 +38,7 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXI CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXISTS ] table_name OF type_name [ ( { column_name [ WITH OPTIONS ] [ column_constraint [ ... ] ] + | period_definition | table_constraint } [, ... ] ) ] @@ -49,6 +51,7 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXI CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXISTS ] table_name PARTITION OF parent_table [ ( { column_name [ WITH OPTIONS ] [ column_constraint [ ... ] ] + | period_definition | table_constraint } [, ... ] ) ] { FOR VALUES partition_bound_spec | DEFAULT } @@ -73,15 +76,20 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXI [ ON DELETE referential_action ] [ ON UPDATE referential_action ] } [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ] [ ENFORCED | NOT ENFORCED ] +and period_definition is: + +PERIOD FOR { period_name | SYSTEM_TIME } ( column_name, column_name ) +[ WITH ( period_option = value [, ... ] ) ] + and table_constraint is: [ CONSTRAINT constraint_name ] { CHECK ( expression ) [ NO INHERIT ] | NOT NULL column_name [ NO INHERIT ] | - UNIQUE [ NULLS [ NOT ] DISTINCT ] ( column_name [, ... ] [, column_name WITHOUT OVERLAPS ] ) index_parameters | - PRIMARY KEY ( column_name [, ... ] [, column_name WITHOUT OVERLAPS ] ) index_parameters | + UNIQUE [ NULLS [ NOT ] DISTINCT ] ( column_name [, ... ] [, { column_name | period_name } WITHOUT OVERLAPS ] ) index_parameters | + PRIMARY KEY ( column_name [, ... ] [, { column_name | period_name } WITHOUT OVERLAPS ] ) index_parameters | EXCLUDE [ USING index_method ] ( exclude_element WITH operator [, ... ] ) index_parameters [ WHERE ( predicate ) ] | - FOREIGN KEY ( column_name [, ... ] [, PERIOD column_name ] ) REFERENCES reftable [ ( refcolumn [, ... ] [, PERIOD refcolumn ] ) ] + FOREIGN KEY ( column_name [, ... ] [, PERIOD { column_name | period_name } ] ) REFERENCES reftable [ ( refcolumn [, ... ] [, PERIOD { refcolumn | period_name } ] ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ] [ ON DELETE referential_action ] [ ON UPDATE referential_action ] } [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ] [ ENFORCED | NOT ENFORCED ] @@ -140,6 +148,14 @@ WITH ( MODULUS numeric_literal, REM name as any existing data type in the same schema. + + Periods may be defined on tables, specifying that two existing columns + represent start and end values for the period. Periods may have any name + that doesn't conflict with a column name, but the name + SYSTEM_TIME is special, used for versioning tables. + System periods are not yet implemented. See for more details. + + The optional constraint clauses specify constraints (tests) that new or updated rows must satisfy for an insert or update operation @@ -800,6 +816,37 @@ WITH ( MODULUS numeric_literal, REM + + PERIOD FOR period_name ( column_name, column_name ) [ WITH ( period_option = value [, ... ] ) ] + + + A period definition gives semantic meaning to two existing columns of + the table. It defines a "start column" and an "end column" where the + start value is strictly less than the end value. A + CHECK constraint is automatically created to enforce + this. You can specify the name of that constraint with the + check_constraint_name period_option. + + + + Both columns must have exactly the same type and must have a range type + defined from their base type. If there are several range types for that + base type, you must specify which one you want by using the + rangetype period_option. + Any base type is allowed, as long as it has a range type, although it is + expected that most periods will use temporal types like timestamptz + or date. + + + + A hidden GENERATED column is used to implement the period, + with the same name as the period. If such a column already exists, you + can use the colexists period_option + with value true to avoid creating it. + + + + CONSTRAINT constraint_name @@ -1184,8 +1231,8 @@ WITH ( MODULUS numeric_literal, REM REFERENCES reftable [ ( refcolumn ) ] [ MATCH matchtype ] [ ON DELETE referential_action ] [ ON UPDATE referential_action ] (column constraint) - FOREIGN KEY ( column_name [, ... ] [, PERIOD column_name ] ) - REFERENCES reftable [ ( refcolumn [, ... ] [, PERIOD refcolumn ] ) ] + FOREIGN KEY ( column_name [, ... ] [, PERIOD { column_name | period_name } ] ) + REFERENCES reftable [ ( refcolumn [, ... ] [, PERIOD { refcolumn | period_name } ] ) ] [ MATCH matchtype ] [ ON DELETE referential_action ] [ ON UPDATE referential_action ] @@ -1205,7 +1252,7 @@ WITH ( MODULUS numeric_literal, REM - If the last column is marked with PERIOD, it is + If the last key part is marked with PERIOD, it is treated in a special way. While the non-PERIOD columns are compared for equality (and there must be at least one of them), the PERIOD column is not. Instead, the @@ -1213,8 +1260,10 @@ WITH ( MODULUS numeric_literal, REM records (based on the non-PERIOD parts of the key) whose combined PERIOD values completely cover the referencing record's. In other words, the reference must have a - referent for its entire duration. This column must be a range or - multirange type. In addition, the referenced table must have a primary + referent for its entire duration. This part must be either a + PERIOD + or a column with a range or multirange type. + In addition, the referenced table must have a primary key or unique constraint declared with WITHOUT OVERLAPS. Finally, if the foreign key has a PERIOD column_name specification diff --git a/doc/src/sgml/ref/delete.sgml b/doc/src/sgml/ref/delete.sgml index f425309fd5da..6abb1b5dc090 100644 --- a/doc/src/sgml/ref/delete.sgml +++ b/doc/src/sgml/ref/delete.sgml @@ -23,7 +23,7 @@ PostgreSQL documentation [ WITH [ RECURSIVE ] with_query [, ...] ] DELETE FROM [ ONLY ] table_name [ * ] - [ FOR PORTION OF range_name for_portion_of_target ] + [ FOR PORTION OF range_or_period_name for_portion_of_target ] [ [ AS ] alias ] [ USING from_item [, ...] ] [ WHERE condition | WHERE CURRENT OF cursor_name ] @@ -58,7 +58,8 @@ DELETE FROM [ ONLY ] table_name [ * - If the table has a range or multirange column, + If the table has a range or multirange column, or a + PERIOD, you may supply a FOR PORTION OF clause, and your delete will only affect rows that overlap the given interval. Furthermore, if a row's history extends outside the FOR PORTION OF bounds, then your delete @@ -157,10 +158,10 @@ DELETE FROM [ ONLY ] table_name [ * - range_name + range_or_period_name - The range or multirange column to use when performing a temporal delete. + The range or multirange column or period to use when performing a temporal delete. @@ -169,14 +170,14 @@ DELETE FROM [ ONLY ] table_name [ * for_portion_of_target - The interval to delete. If you are targeting a range column, + The interval to delete. If you are targeting a range column or PERIOD, you may give this in the form FROM start_time TO end_time. Otherwise you must use (expression) where the expression yields a value of the same type as - range_name. + range_or_period_name. @@ -186,8 +187,8 @@ DELETE FROM [ ONLY ] table_name [ * The earliest time (inclusive) to change in a temporal delete. - This must be a value matching the base type of the range from - range_name. A + This must be a value matching the base type of the range or period from + range_or_period_name. A NULL here indicates a delete whose beginning is unbounded (as with range types). @@ -199,8 +200,8 @@ DELETE FROM [ ONLY ] table_name [ * The latest time (exclusive) to change in a temporal delete. - This must be a value matching the base type of the range from - range_name. A + This must be a value matching the base type of the range or period from + range_or_period_name. A NULL here indicates a delete whose end is unbounded (as with range types). diff --git a/doc/src/sgml/ref/update.sgml b/doc/src/sgml/ref/update.sgml index ad3224c2df22..fc22de5b48ba 100644 --- a/doc/src/sgml/ref/update.sgml +++ b/doc/src/sgml/ref/update.sgml @@ -23,7 +23,7 @@ PostgreSQL documentation [ WITH [ RECURSIVE ] with_query [, ...] ] UPDATE [ ONLY ] table_name [ * ] - [ FOR PORTION OF range_name for_portion_of_target ] + [ FOR PORTION OF range_or_period_name for_portion_of_target ] [ [ AS ] alias ] SET { column_name = { expression | DEFAULT } | ( column_name [, ...] ) = [ ROW ] ( { expression | DEFAULT } [, ...] ) | @@ -55,7 +55,8 @@ UPDATE [ ONLY ] table_name [ * ] - If the table has a range or multirange column, + If the table has a range or multirange column, or a + PERIOD, you may supply a FOR PORTION OF clause, and your update will only affect rows that overlap the given interval. Furthermore, if a row's history extends outside the FOR PORTION OF bounds, then your update @@ -158,10 +159,10 @@ UPDATE [ ONLY ] table_name [ * ] - range_name + range_or_period_name - The range or multirange column to use when performing a temporal update. + The range or multirange column or period to use when performing a temporal update. @@ -170,14 +171,14 @@ UPDATE [ ONLY ] table_name [ * ] for_portion_of_target - The interval to update. If you are targeting a range column, + The interval to update. If you are targeting a range column or PERIOD, you may give this in the form FROM start_time TO end_time. Otherwise you must use (expression) where the expression yields a value of the same type as - range_name. + range_or_period_name. @@ -187,8 +188,8 @@ UPDATE [ ONLY ] table_name [ * ] The earliest time (inclusive) to change in a temporal update. - This must be a value matching the base type of the range from - range_name. A + This must be a value matching the base type of the range or period from + range_or_period_name. A NULL here indicates an update whose beginning is unbounded (as with range types). @@ -200,8 +201,8 @@ UPDATE [ ONLY ] table_name [ * ] The latest time (exclusive) to change in a temporal update. - This must be a value matching the base type of the range from - range_name. A + This must be a value matching the base type of the range or period from + range_or_period_name. A NULL here indicates an update whose end is unbounded (as with range types). diff --git a/doc/src/sgml/trigger.sgml b/doc/src/sgml/trigger.sgml index 0044a97a3fd9..da9ae0ffefd8 100644 --- a/doc/src/sgml/trigger.sgml +++ b/doc/src/sgml/trigger.sgml @@ -860,16 +860,21 @@ typedef struct ForPortionOfState char *fp_rangeName; /* the column named in FOR PORTION OF */ Oid fp_rangeType; /* the type of the FOR PORTION OF expression */ - int fp_rangeAttno; /* the attno of the range column */ + int fp_rangeAttno; /* the attno of the range column (or 0 for a PERIOD) */ + int fp_periodStartAttno; /* the attno of the PERIOD start column (or 0 for a range) */ + int fp_periodEndAttno; /* the attno of the PERIOD end column (or 0 for a range) */ Datum fp_targetRange; /* the range/multirange from FOR PORTION OF */ TypeCacheEntry *fp_leftoverstypcache; /* type cache entry of the range */ } ForPortionOfState; - where fp_rangeName is the range + where fp_rangeName is the period or range column named in the FOR PORTION OF clause, fp_rangeType is its range type, fp_rangeAttno is its attribute number, + fp_periodStartAttno and + fp_periodEndAttno are the attnos of the period's + start and end columns (or 0 if a range column was used), and fp_targetRange is a rangetype value created by evaluating the FOR PORTION OF bounds. diff --git a/src/backend/catalog/Makefile b/src/backend/catalog/Makefile index c090094ed08d..53eb67034f34 100644 --- a/src/backend/catalog/Makefile +++ b/src/backend/catalog/Makefile @@ -39,6 +39,7 @@ OBJS = \ pg_namespace.o \ pg_operator.o \ pg_parameter_acl.o \ + pg_period.o \ pg_proc.o \ pg_publication.o \ pg_range.o \ diff --git a/src/backend/catalog/aclchk.c b/src/backend/catalog/aclchk.c index cd139bd65a66..8d006a830d61 100644 --- a/src/backend/catalog/aclchk.c +++ b/src/backend/catalog/aclchk.c @@ -2774,6 +2774,7 @@ aclcheck_error(AclResult aclerr, ObjectType objtype, case OBJECT_DEFAULT: case OBJECT_DEFACL: case OBJECT_DOMCONSTRAINT: + case OBJECT_PERIOD: case OBJECT_PUBLICATION_NAMESPACE: case OBJECT_PUBLICATION_REL: case OBJECT_ROLE: @@ -2915,6 +2916,7 @@ aclcheck_error(AclResult aclerr, ObjectType objtype, case OBJECT_DEFACL: case OBJECT_DOMCONSTRAINT: case OBJECT_PARAMETER_ACL: + case OBJECT_PERIOD: case OBJECT_PUBLICATION_NAMESPACE: case OBJECT_PUBLICATION_REL: case OBJECT_ROLE: diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c index 7dded634eb81..0111df6081dc 100644 --- a/src/backend/catalog/dependency.c +++ b/src/backend/catalog/dependency.c @@ -48,6 +48,7 @@ #include "catalog/pg_operator.h" #include "catalog/pg_opfamily.h" #include "catalog/pg_parameter_acl.h" +#include "catalog/pg_period.h" #include "catalog/pg_policy.h" #include "catalog/pg_proc.h" #include "catalog/pg_publication.h" @@ -622,6 +623,14 @@ findDependentObjects(const ObjectAddress *object, return; } + /* + * If a table attribute is an internal part of something + * else (e.g. the GENERATED column used by a PERIOD), and + * we are deleting the whole table, then it's okay. + */ + if (foundDep->objsubid && !object->objectSubId) + break; + /* * We postpone actually issuing the error message until * after this loop, so that we can make the behavior @@ -1400,6 +1409,10 @@ doDeletion(const ObjectAddress *object, int flags) RemoveAttrDefaultById(object->objectId); break; + case PeriodRelationId: + RemovePeriodById(object->objectId); + break; + case LargeObjectRelationId: LargeObjectDrop(object->objectId); break; diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c index fd6537567ea2..99cda809d02b 100644 --- a/src/backend/catalog/heap.c +++ b/src/backend/catalog/heap.c @@ -49,6 +49,7 @@ #include "catalog/pg_namespace.h" #include "catalog/pg_opclass.h" #include "catalog/pg_partitioned_table.h" +#include "catalog/pg_period.h" #include "catalog/pg_statistic.h" #include "catalog/pg_subscription_rel.h" #include "catalog/pg_tablespace.h" @@ -2135,6 +2136,80 @@ SetAttrMissing(Oid relid, char *attname, char *value) table_close(tablerel, AccessExclusiveLock); } +/* + * Store a period of relation rel. + * + * Returns the OID of the new pg_period tuple. + */ +Oid +StorePeriod(Relation rel, const char *periodname, AttrNumber startnum, + AttrNumber endnum, AttrNumber rangenum, Oid conoid) +{ + Datum values[Natts_pg_period]; + bool nulls[Natts_pg_period]; + Relation pg_period; + HeapTuple tuple; + Oid oid; + NameData pername; + ObjectAddress myself, + referenced; + + Assert(rangenum != InvalidAttrNumber); + + namestrcpy(&pername, periodname); + + MemSet(values, 0, sizeof(values)); + MemSet(nulls, false, sizeof(nulls)); + + pg_period = table_open(PeriodRelationId, RowExclusiveLock); + + oid = GetNewOidWithIndex(pg_period, AttrDefaultOidIndexId, Anum_pg_period_oid); + values[Anum_pg_period_oid - 1] = ObjectIdGetDatum(oid); + values[Anum_pg_period_pername - 1] = NameGetDatum(&pername); + values[Anum_pg_period_perrelid - 1] = RelationGetRelid(rel); + values[Anum_pg_period_perstart - 1] = startnum; + values[Anum_pg_period_perend - 1] = endnum; + values[Anum_pg_period_perrange - 1] = rangenum; + values[Anum_pg_period_perconstraint - 1] = conoid; + + tuple = heap_form_tuple(RelationGetDescr(pg_period), values, nulls); + CatalogTupleInsert(pg_period, tuple); + + ObjectAddressSet(myself, PeriodRelationId, oid); + + /* Drop the period when the table is dropped. */ + ObjectAddressSet(referenced, RelationRelationId, RelationGetRelid(rel)); + recordDependencyOn(&myself, &referenced, DEPENDENCY_AUTO); + + /* Forbid dropping the columns of the period. */ + ObjectAddressSubSet(referenced, RelationRelationId, RelationGetRelid(rel), startnum); + recordDependencyOn(&myself, &referenced, DEPENDENCY_NORMAL); + ObjectAddressSubSet(referenced, RelationRelationId, RelationGetRelid(rel), endnum); + recordDependencyOn(&myself, &referenced, DEPENDENCY_NORMAL); + + /* + * The range column is an implementation detail, but we can't use + * DEPENDENCY_INTERNAL because dropping the table will check for + * dependencies on all subobjects too (in findDependentObjects). But if we + * make an AUTO dependency one way we will auto-drop the column when we + * drop the PERIOD, and a NORMAL dependency the other way we will forbid + * dropping the column directly. + */ + ObjectAddressSubSet(referenced, RelationRelationId, RelationGetRelid(rel), rangenum); + recordDependencyOn(&referenced, &myself, DEPENDENCY_INTERNAL); + + /* + * The constraint is an implementation detail, so we mark it as such. + * (Note that myself and referenced are reversed for this one.) + */ + ObjectAddressSet(referenced, ConstraintRelationId, conoid); + recordDependencyOn(&referenced, &myself, DEPENDENCY_INTERNAL); + + table_close(pg_period, RowExclusiveLock); + + return oid; +} + /* * Store a check-constraint expression for the given relation. * diff --git a/src/backend/catalog/information_schema.sql b/src/backend/catalog/information_schema.sql index a7bffca93d1d..282ead6ed4c5 100644 --- a/src/backend/catalog/information_schema.sql +++ b/src/backend/catalog/information_schema.sql @@ -1207,7 +1207,28 @@ GRANT SELECT ON parameters TO PUBLIC; * PERIODS view */ --- feature not supported +CREATE VIEW periods AS + SELECT current_database()::information_schema.sql_identifier AS table_catalog, + nc.nspname::information_schema.sql_identifier AS table_schema, + c.relname::information_schema.sql_identifier AS table_name, + p.pername::information_schema.sql_identifier AS period_name, + CASE WHEN pg_has_role(c.relowner, 'USAGE') + OR has_column_privilege(sa.attrelid, sa.attnum, 'SELECT, INSERT, UPDATE, REFERENCES') + THEN sa.attname::information_schema.sql_identifier + END AS start_column_name, + CASE WHEN pg_has_role(c.relowner, 'USAGE') + OR has_column_privilege(ea.attrelid, ea.attnum, 'SELECT, INSERT, UPDATE, REFERENCES') + THEN ea.attname::information_schema.sql_identifier + END AS end_column_name + FROM pg_period AS p + JOIN pg_class AS c ON c.oid = p.perrelid + JOIN pg_namespace AS nc ON nc.oid = c.relnamespace + JOIN pg_attribute AS sa ON (sa.attrelid, sa.attnum) = (p.perrelid, p.perstart) + JOIN pg_attribute AS ea ON (ea.attrelid, ea.attnum) = (p.perrelid, p.perend) + WHERE NOT pg_is_other_temp_schema(nc.oid) + AND c.relkind IN ('r', 'v'); + +GRANT SELECT ON periods TO PUBLIC; /* diff --git a/src/backend/catalog/meson.build b/src/backend/catalog/meson.build index 1958ea9238a7..6cdf89d0e932 100644 --- a/src/backend/catalog/meson.build +++ b/src/backend/catalog/meson.build @@ -26,6 +26,7 @@ backend_sources += files( 'pg_namespace.c', 'pg_operator.c', 'pg_parameter_acl.c', + 'pg_period.c', 'pg_proc.c', 'pg_publication.c', 'pg_range.c', diff --git a/src/backend/catalog/objectaddress.c b/src/backend/catalog/objectaddress.c index c75b7131ed70..e2b099e23608 100644 --- a/src/backend/catalog/objectaddress.c +++ b/src/backend/catalog/objectaddress.c @@ -45,6 +45,7 @@ #include "catalog/pg_operator.h" #include "catalog/pg_opfamily.h" #include "catalog/pg_parameter_acl.h" +#include "catalog/pg_period.h" #include "catalog/pg_policy.h" #include "catalog/pg_proc.h" #include "catalog/pg_publication.h" @@ -726,6 +727,9 @@ static const struct object_type_map { "domain constraint", OBJECT_DOMCONSTRAINT }, + { + "period", OBJECT_PERIOD + }, { "conversion", OBJECT_CONVERSION }, @@ -970,6 +974,7 @@ get_object_address(ObjectType objtype, Node *object, case OBJECT_TRIGGER: case OBJECT_TABCONSTRAINT: case OBJECT_POLICY: + case OBJECT_PERIOD: address = get_object_address_relobject(objtype, castNode(List, object), &relation, missing_ok); break; @@ -1472,6 +1477,13 @@ get_object_address_relobject(ObjectType objtype, List *object, InvalidOid; address.objectSubId = 0; break; + case OBJECT_PERIOD: + address.classId = PeriodRelationId; + address.objectId = relation ? + get_relation_period_oid(reloid, depname, missing_ok) : + InvalidOid; + address.objectSubId = 0; + break; default: elog(ERROR, "unrecognized object type: %d", (int) objtype); } @@ -2293,6 +2305,7 @@ pg_get_object_address(PG_FUNCTION_ARGS) case OBJECT_RULE: case OBJECT_TRIGGER: case OBJECT_TABCONSTRAINT: + case OBJECT_PERIOD: case OBJECT_OPCLASS: case OBJECT_OPFAMILY: objnode = (Node *) name; @@ -2403,6 +2416,7 @@ check_object_ownership(Oid roleid, ObjectType objtype, ObjectAddress address, case OBJECT_TRIGGER: case OBJECT_POLICY: case OBJECT_TABCONSTRAINT: + case OBJECT_PERIOD: if (!object_ownercheck(RelationRelationId, RelationGetRelid(relation), roleid)) aclcheck_error(ACLCHECK_NOT_OWNER, objtype, RelationGetRelationName(relation)); @@ -3076,6 +3090,38 @@ getObjectDescription(const ObjectAddress *object, bool missing_ok) break; } + case PeriodRelationId: + { + HeapTuple perTup; + Form_pg_period per; + + perTup = SearchSysCache1(PERIODOID, + ObjectIdGetDatum(object->objectId)); + if (!HeapTupleIsValid(perTup)) + elog(ERROR, "cache lookup failed for period %u", + object->objectId); + per = (Form_pg_period) GETSTRUCT(perTup); + + if (OidIsValid(per->perrelid)) + { + StringInfoData rel; + + initStringInfo(&rel); + getRelationDescription(&rel, per->perrelid, false); + appendStringInfo(&buffer, _("period %s on %s"), + NameStr(per->pername), rel.data); + pfree(rel.data); + } + else + { + appendStringInfo(&buffer, _("period %s"), + NameStr(per->pername)); + } + + ReleaseSysCache(perTup); + break; + } + case ConversionRelationId: { HeapTuple conTup; @@ -4529,6 +4575,10 @@ getObjectTypeDescription(const ObjectAddress *object, bool missing_ok) missing_ok); break; + case PeriodRelationId: + appendStringInfoString(&buffer, "period"); + break; + case ConversionRelationId: appendStringInfoString(&buffer, "conversion"); break; @@ -5034,6 +5084,28 @@ getObjectIdentityParts(const ObjectAddress *object, break; } + case PeriodRelationId: + { + HeapTuple perTup; + Form_pg_period per; + + perTup = SearchSysCache1(PERIODOID, + ObjectIdGetDatum(object->objectId)); + if (!HeapTupleIsValid(perTup)) + elog(ERROR, "cache lookup failed for period %u", + object->objectId); + per = (Form_pg_period) GETSTRUCT(perTup); + + appendStringInfo(&buffer, "%s on ", + quote_identifier(NameStr(per->pername))); + getRelationIdentity(&buffer, per->perrelid, objname, false); + if (objname) + *objname = lappend(*objname, pstrdup(NameStr(per->pername))); + + ReleaseSysCache(perTup); + break; + } + case ConversionRelationId: { HeapTuple conTup; diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c index 77152252ea1c..2c0451d6930e 100644 --- a/src/backend/catalog/pg_constraint.c +++ b/src/backend/catalog/pg_constraint.c @@ -812,9 +812,14 @@ AdjustNotNullInheritance(Oid relid, AttrNumber attnum, * This is seldom needed, so we just scan pg_constraint each time. * * 'include_noinh' determines whether to include NO INHERIT constraints or not. + * + * 'excludes' contains a list of attnos whose constraints we should exclude, + * for example constraints on PERIODs' hidden GENERATED columns (since those + * aren't exposed to users). */ List * -RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh) +RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh, + Bitmapset *excludes) { List *notnulls = NIL; Relation constrRel; @@ -842,6 +847,9 @@ RelationGetNotNullConstraints(Oid relid, bool cooked, bool include_noinh) colnum = extractNotNullColumn(htup); + if (bms_is_member(colnum, excludes)) + continue; + if (cooked) { CookedConstraint *cooked; diff --git a/src/backend/catalog/pg_period.c b/src/backend/catalog/pg_period.c new file mode 100644 index 000000000000..24b1938532be --- /dev/null +++ b/src/backend/catalog/pg_period.c @@ -0,0 +1,132 @@ +/*------------------------------------------------------------------------- + * + * pg_period.c + * routines to support manipulation of the pg_period relation + * + * Portions Copyright (c) 1996-2021, PostgreSQL Global Development Group + * + * + * IDENTIFICATION + * src/backend/catalog/pg_period.c + * + *------------------------------------------------------------------------- + */ +#include "postgres.h" + +#include "access/genam.h" +#include "access/heapam.h" +#include "access/htup_details.h" +#include "catalog/indexing.h" +#include "catalog/pg_period.h" +#include "utils/fmgroids.h" +#include "utils/lsyscache.h" +#include "utils/rel.h" +#include "utils/syscache.h" + + +/* + * Delete a single period record. + */ +void +RemovePeriodById(Oid periodId) +{ + Relation pg_period; + HeapTuple tup; + + pg_period = table_open(PeriodRelationId, RowExclusiveLock); + + tup = SearchSysCache1(PERIODOID, ObjectIdGetDatum(periodId)); + if (!HeapTupleIsValid(tup)) /* should not happen */ + elog(ERROR, "cache lookup failed for period %u", periodId); + + /* Fry the period itself */ + CatalogTupleDelete(pg_period, &tup->t_self); + + /* Clean up */ + ReleaseSysCache(tup); + table_close(pg_period, RowExclusiveLock); +} + +/* + * get_relation_period_oid + * Find a period on the specified relation with the specified name. + * Returns period's OID. + */ +Oid +get_relation_period_oid(Oid relid, const char *pername, bool missing_ok) +{ + Relation pg_period; + HeapTuple tuple; + SysScanDesc scan; + ScanKeyData skey[2]; + Oid perOid = InvalidOid; + + /* Fetch the period tuple from pg_period. */ + pg_period = table_open(PeriodRelationId, AccessShareLock); + + ScanKeyInit(&skey[0], + Anum_pg_period_perrelid, + BTEqualStrategyNumber, F_OIDEQ, + ObjectIdGetDatum(relid)); + ScanKeyInit(&skey[1], + Anum_pg_period_pername, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(pername)); + + scan = systable_beginscan(pg_period, PeriodRelidNameIndexId, true, + NULL, 2, skey); + + /* There can be at most one matching row */ + if (HeapTupleIsValid(tuple = systable_getnext(scan))) + perOid = ((Form_pg_period) GETSTRUCT(tuple))->oid; + + systable_endscan(scan); + + /* If no such period exists, complain */ + if (!OidIsValid(perOid) && !missing_ok) + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_OBJECT), + errmsg("period \"%s\" for table \"%s\" does not exist", + pername, get_rel_name(relid)))); + + table_close(pg_period, AccessShareLock); + + return perOid; +} + +/* + * get_period_attnos + * Get the attno of the GENERATED rangetype column + * for all PERIODs in this table. + */ +extern Bitmapset * +get_period_attnos(Oid relid) +{ + Bitmapset *attnos = NULL; + Relation pg_period; + HeapTuple tuple; + SysScanDesc scan; + ScanKeyData skey[1]; + + pg_period = table_open(PeriodRelationId, AccessShareLock); + + ScanKeyInit(&skey[0], + Anum_pg_period_perrelid, + BTEqualStrategyNumber, F_OIDEQ, + ObjectIdGetDatum(relid)); + + scan = systable_beginscan(pg_period, PeriodRelidNameIndexId, true, + NULL, 1, skey); + + while (HeapTupleIsValid(tuple = systable_getnext(scan))) + { + Form_pg_period period = (Form_pg_period) GETSTRUCT(tuple); + + attnos = bms_add_member(attnos, period->perrange); + } + + systable_endscan(scan); + table_close(pg_period, AccessShareLock); + + return attnos; +} diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt index 3a8ad201607f..016b67bcf1ce 100644 --- a/src/backend/catalog/sql_features.txt +++ b/src/backend/catalog/sql_features.txt @@ -448,7 +448,7 @@ T176 Sequence generator support NO supported except for NEXT VALUE FOR T177 Sequence generator support: simple restart option YES T178 Identity columns: simple restart option YES T180 System-versioned tables NO -T181 Application-time period tables NO +T181 Application-time period tables YES T191 Referential action RESTRICT YES T200 Trigger DDL NO similar but not fully compatible T201 Comparable data types for referential constraints YES diff --git a/src/backend/commands/comment.c b/src/backend/commands/comment.c index 5c783cc61f1d..36306c618b26 100644 --- a/src/backend/commands/comment.c +++ b/src/backend/commands/comment.c @@ -102,6 +102,16 @@ CommentObject(CommentStmt *stmt) RelationGetRelationName(relation)), errdetail_relkind_not_supported(relation->rd_rel->relkind))); break; + + case OBJECT_PERIOD: + /* Periods can only go on tables */ + if (relation->rd_rel->relkind != RELKIND_RELATION) + ereport(ERROR, + (errcode(ERRCODE_WRONG_OBJECT_TYPE), + errmsg("\"%s\" is not a table", + RelationGetRelationName(relation)))); + break; + default: break; } diff --git a/src/backend/commands/dropcmds.c b/src/backend/commands/dropcmds.c index ceb9a229b63b..526c3ff51426 100644 --- a/src/backend/commands/dropcmds.c +++ b/src/backend/commands/dropcmds.c @@ -504,6 +504,7 @@ does_not_exist_skipping(ObjectType objtype, Node *object) case OBJECT_DOMCONSTRAINT: case OBJECT_LARGEOBJECT: case OBJECT_PARAMETER_ACL: + case OBJECT_PERIOD: case OBJECT_PUBLICATION_NAMESPACE: case OBJECT_PUBLICATION_REL: case OBJECT_TABCONSTRAINT: diff --git a/src/backend/commands/event_trigger.c b/src/backend/commands/event_trigger.c index f34868da5ab9..514da04be771 100644 --- a/src/backend/commands/event_trigger.c +++ b/src/backend/commands/event_trigger.c @@ -2301,6 +2301,7 @@ stringify_grant_objtype(ObjectType objtype) case OBJECT_OPCLASS: case OBJECT_OPERATOR: case OBJECT_OPFAMILY: + case OBJECT_PERIOD: case OBJECT_POLICY: case OBJECT_PUBLICATION: case OBJECT_PUBLICATION_NAMESPACE: @@ -2385,6 +2386,7 @@ stringify_adefprivs_objtype(ObjectType objtype) case OBJECT_OPERATOR: case OBJECT_OPFAMILY: case OBJECT_PARAMETER_ACL: + case OBJECT_PERIOD: case OBJECT_POLICY: case OBJECT_PUBLICATION: case OBJECT_PUBLICATION_NAMESPACE: diff --git a/src/backend/commands/seclabel.c b/src/backend/commands/seclabel.c index cee5d7bbb9c7..f8650eb4fe48 100644 --- a/src/backend/commands/seclabel.c +++ b/src/backend/commands/seclabel.c @@ -79,6 +79,7 @@ SecLabelSupportsObjectType(ObjectType objtype) case OBJECT_OPERATOR: case OBJECT_OPFAMILY: case OBJECT_PARAMETER_ACL: + case OBJECT_PERIOD: case OBJECT_POLICY: case OBJECT_PUBLICATION_NAMESPACE: case OBJECT_PUBLICATION_REL: diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c index 7a917b31ed9c..44b7d4d8a3fe 100644 --- a/src/backend/commands/tablecmds.c +++ b/src/backend/commands/tablecmds.c @@ -45,6 +45,7 @@ #include "catalog/pg_largeobject_metadata.h" #include "catalog/pg_namespace.h" #include "catalog/pg_opclass.h" +#include "catalog/pg_period.h" #include "catalog/pg_policy.h" #include "catalog/pg_proc.h" #include "catalog/pg_publication_rel.h" @@ -156,6 +157,13 @@ typedef enum AlterTablePass AT_PASS_OLD_INDEX, /* re-add existing indexes */ AT_PASS_OLD_CONSTR, /* re-add existing constraints */ /* We could support a RENAME COLUMN pass here, but not currently used */ + + /* + * We must add PERIODs after columns, in case they reference a newly-added + * column, and before constraints, in case a newly-added PK/FK references + * them. + */ + AT_PASS_ADD_PERIOD, /* ADD PERIOD */ AT_PASS_ADD_CONSTR, /* ADD constraints (initial examination) */ AT_PASS_COL_ATTRS, /* set column attributes, eg NOT NULL */ AT_PASS_ADD_INDEXCONSTR, /* ADD index-based constraints */ @@ -375,6 +383,7 @@ static List *MergeAttributes(List *columns, const List *supers, char relpersiste bool is_partition, List **supconstr, List **supnotnulls); static List *MergeCheckConstraint(List *constraints, const char *name, Node *expr, bool is_enforced); +static List *MergePeriods(char *relname, List *periods, List *tableElts, List *supers); static void MergeChildAttribute(List *inh_columns, int exist_attno, int newcol_attno, const ColumnDef *newdef); static ColumnDef *MergeInheritedAttribute(List *inh_columns, int exist_attno, const ColumnDef *newdef); static void MergeAttributesIntoExisting(Relation child_rel, Relation parent_rel, bool ispartition); @@ -497,6 +506,8 @@ static ObjectAddress ATExecAddColumn(List **wqueue, AlteredTableInfo *tab, AlterTableUtilityContext *context); static bool check_for_column_name_collision(Relation rel, const char *colname, bool if_not_exists); +static bool check_for_period_name_collision(Relation rel, const char *pername, + bool colexists, bool if_not_exists); static void add_column_datatype_dependency(Oid relid, int32 attnum, Oid typid); static void add_column_collation_dependency(Oid relid, int32 attnum, Oid collid); static ObjectAddress ATExecDropNotNull(Relation rel, const char *colName, bool recurse, @@ -514,6 +525,15 @@ static ObjectAddress ATExecColumnDefault(Relation rel, const char *colName, Node *newDefault, LOCKMODE lockmode); static ObjectAddress ATExecCookedColumnDefault(Relation rel, AttrNumber attnum, Node *newDefault); +static void ATPrepAddPeriod(List **wqueue, Relation rel, AlterTableCmd *cmd, + LOCKMODE lockmode, AlterTableUtilityContext *context); +static ObjectAddress ATExecAddPeriod(List **wqueue, AlteredTableInfo *tab, + Relation rel, PeriodDef *period, + LOCKMODE lockmode, AlterTableUtilityContext *context); +static void ATExecDropPeriod(Relation rel, const char *periodName, + DropBehavior behavior, + bool recurse, bool recursing, + bool missing_ok); static ObjectAddress ATExecAddIdentity(Relation rel, const char *colName, Node *def, LOCKMODE lockmode, bool recurse, bool recursing); static ObjectAddress ATExecSetIdentity(Relation rel, const char *colName, @@ -739,6 +759,10 @@ static List *GetParentedForeignKeyRefs(Relation partition); static void ATDetachCheckNoForeignKeyRefs(Relation partition); static char GetAttributeCompression(Oid atttypid, const char *compression); static char GetAttributeStorage(Oid atttypid, const char *storagemode); +static void AddRelationNewPeriod(Relation rel, PeriodDef *period); +static void ValidatePeriod(Relation rel, PeriodDef *period); +static Constraint *make_constraint_for_period(Relation rel, PeriodDef *period); +static ColumnDef *make_range_column_for_period(PeriodDef *period); /* ---------------------------------------------------------------- @@ -968,6 +992,95 @@ DefineRelation(CreateStmt *stmt, char relkind, Oid ownerId, stmt->partbound != NULL, &old_constraints, &old_notnulls); + /* + * Using the column list (including inherited columns), find the start/end + * columns for each period. PERIODs should be inherited too (but aren't + * yet). + */ + stmt->periods = MergePeriods(relname, stmt->periods, stmt->tableElts, inheritOids); + + /* + * For each PERIOD we need a GENERATED column. Usually we must create + * this, so we add it to tableElts. If the user says the column already + * exists, make sure it is sensible. These columns are not inherited, so + * we don't worry about conflicts in tableElts. + * + * We allow this colexists option to support pg_upgrade, so we have more + * control over the GENERATED column (whose attnum must match the old + * value). + * + * Since the GENERATED column must be NOT NULL, we add a constraint to + * nnconstraints. + */ + foreach(listptr, stmt->periods) + { + PeriodDef *period = (PeriodDef *) lfirst(listptr); + + if (period->colexists) + { + ListCell *cell; + bool found = false; + + /* Find the existing column to use */ + foreach(cell, stmt->tableElts) + { + ColumnDef *colDef = lfirst(cell); + + if (strcmp(period->periodname, colDef->colname) == 0) + { + /* + * Make sure the existing column matches what we would have + * created. First all, it must be GENERATED. + */ + if (colDef->generated == '\0') + ereport(ERROR, (errmsg("Period %s uses a non-generated column", + period->periodname))); + + /* The GENERATED column must be STORED. */ + if (colDef->generated != ATTRIBUTE_GENERATED_STORED) + ereport(ERROR, (errmsg("Period %s uses a generated column that is not STORED", + period->periodname))); + + /* The GENERATED column must not allow nulls. */ + if (!colDef->is_not_null && !IsBinaryUpgrade) + ereport(ERROR, (errmsg("Period %s uses a generated column that allows nulls", + period->periodname))); + + /* The GENERATED column must match our rangetype. */ + if (period->rngtypid != typenameTypeId(NULL, colDef->typeName)) + ereport(ERROR, (errmsg("Period %s uses a generated column with the wrong type", + period->periodname))); + + /* + * The GENERATED column must not be inherited. + * XXX: If the PERIOD is inherited, they must come from the + * same parent. + */ + if (!colDef->is_local) + ereport(ERROR, (errmsg("Period %s uses a generated column that is inherited", + period->periodname))); + /* + * XXX: We should check the GENERATED expression also, but + * that is hard to do because one is cooked and one is raw. + */ + + found = true; + } + } + + if (!found) + ereport(ERROR, (errmsg("No column found with name %s", period->periodname))); + } + else + { + ColumnDef *col = make_range_column_for_period(period); + Constraint *constr = makeNotNullConstraint(makeString(col->colname)); + + stmt->tableElts = lappend(stmt->tableElts, col); + stmt->nnconstraints = lappend(stmt->nnconstraints, constr); + } + } + /* * Create a tuple descriptor from the relation schema. Note that this * deals with column names, types, and in-descriptor NOT NULL flags, but @@ -1336,7 +1449,7 @@ DefineRelation(CreateStmt *stmt, char relkind, Oid ownerId, true, true, false, queryString); /* - * Finally, merge the not-null constraints that are declared directly with + * Now merge the not-null constraints that are declared directly with * those that come from parent relations (making sure to count inheritance * appropriately for each), create them, and set the attnotnull flag on * columns that don't yet have it. @@ -1346,6 +1459,21 @@ DefineRelation(CreateStmt *stmt, char relkind, Oid ownerId, foreach_int(attrnum, nncols) set_attnotnull(NULL, rel, attrnum, true, false); + /* + * Finally, create periods for the table. This must come after we create + * columns and before we create index constraints. It will automatically + * create a CHECK constraint for the period. + */ + foreach(listptr, stmt->periods) + { + PeriodDef *period = (PeriodDef *) lfirst(listptr); + + /* Don't update the count of check constraints twice */ + CommandCounterIncrement(); + + AddRelationNewPeriod(rel, period); + } + ObjectAddressSet(address, RelationRelationId, relationId); /* @@ -1445,6 +1573,336 @@ BuildDescForRelation(const List *columns) return desc; } +/* + * make_constraint_for_period + * + * Builds a CHECK Constraint to ensure start < end. + * Returns the CHECK Constraint. + * Also fills in period->constraintname if needed. + * + * If either bound is NULL, the constraint passes + * (since that indicates an unbounded range). + */ +static Constraint * +make_constraint_for_period(Relation rel, PeriodDef *period) +{ + ColumnRef *scol, + *ecol; + Constraint *constr; + TypeCacheEntry *type; + + if (period->constraintname == NULL) + period->constraintname = ChooseConstraintName(RelationGetRelationName(rel), + period->periodname, + "check", + RelationGetNamespace(rel), + NIL); + scol = makeNode(ColumnRef); + scol->fields = list_make1(makeString(pstrdup(period->startcolname))); + scol->location = 0; + + ecol = makeNode(ColumnRef); + ecol->fields = list_make1(makeString(pstrdup(period->endcolname))); + ecol->location = 0; + + type = lookup_type_cache(period->coltypid, TYPECACHE_LT_OPR); + if (type->lt_opr == InvalidOid) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("column \"%s\" cannot be used in a PERIOD because its type %s has no less than operator", + period->startcolname, format_type_be(period->coltypid)))); + + constr = makeNode(Constraint); + constr->contype = CONSTR_CHECK; + constr->conname = period->constraintname; + constr->deferrable = false; + constr->initdeferred = false; + constr->location = -1; + constr->is_no_inherit = false; + constr->raw_expr = (Node *) makeSimpleA_Expr(AEXPR_OP, + get_opname(type->lt_opr), + (Node *) scol, + (Node *) ecol, + 0); + constr->cooked_expr = NULL; + constr->skip_validation = false; + constr->is_enforced = true; + constr->initially_valid = true; + + return constr; +} + +/* + * make_range_column_for_period + * + * Builds a GENERATED ALWAYS range column based on the PERIOD + * start/end columns. Returns the ColumnDef. + */ +ColumnDef * +make_range_column_for_period(PeriodDef *period) +{ + char *range_type_namespace; + char *range_type_name; + ColumnDef *col = makeNode(ColumnDef); + ColumnRef *startvar, + *endvar; + Expr *rangeConstructor; + + if (!get_typname_and_namespace(period->rngtypid, &range_type_name, + &range_type_namespace)) + elog(ERROR, "missing range type %d", period->rngtypid); + + startvar = makeNode(ColumnRef); + startvar->fields = list_make1(makeString(pstrdup(period->startcolname))); + endvar = makeNode(ColumnRef); + endvar->fields = list_make1(makeString(pstrdup(period->endcolname))); + rangeConstructor = (Expr *) makeFuncCall( + list_make2(makeString(range_type_namespace), makeString(range_type_name)), + list_make2(startvar, endvar), + COERCE_EXPLICIT_CALL, + period->location); + + col->colname = pstrdup(period->periodname); + col->typeName = makeTypeName(range_type_name); + col->compression = NULL; + col->inhcount = 0; + col->is_local = true; + col->is_not_null = true; + col->is_from_type = false; + col->storage = 0; + col->storage_name = NULL; + col->raw_default = (Node *) rangeConstructor; + col->cooked_default = NULL; + col->identity = 0; + col->generated = ATTRIBUTE_GENERATED_STORED; + col->collClause = NULL; + col->collOid = InvalidOid; + col->fdwoptions = NIL; + col->location = period->location; + + return col; +} + +/* + * ValidatePeriod + * + * Look up the attributes used by the PERIOD, + * make sure they exist, are not system columns, + * and have the same type and collation. + * + * Add our findings to these PeriodDef fields: + * + * coltypid - the type of PERIOD columns. + * startattnum - the attnum of the start column. + * endattnum - the attnum of the end column. + * rngtypid - the range type to use. + * rngattnum - the attnum of a pre-existing range column, or Invalid. + */ +static void +ValidatePeriod(Relation rel, PeriodDef *period) +{ + HeapTuple starttuple; + HeapTuple endtuple; + Form_pg_attribute atttuple; + Oid attcollation; + Oid endtypid; + Oid endcollation; + + /* Find the start column */ + starttuple = SearchSysCacheAttName(RelationGetRelid(rel), period->startcolname); + if (!HeapTupleIsValid(starttuple)) + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_COLUMN), + errmsg("column \"%s\" of relation \"%s\" does not exist", + period->startcolname, RelationGetRelationName(rel)))); + atttuple = (Form_pg_attribute) GETSTRUCT(starttuple); + period->coltypid = atttuple->atttypid; + attcollation = atttuple->attcollation; + period->startattnum = atttuple->attnum; + ReleaseSysCache(starttuple); + + /* Make sure it's not a system column */ + if (period->startattnum <= 0) + ereport(ERROR, + (errcode(ERRCODE_INVALID_OBJECT_DEFINITION), + errmsg("cannot use system column \"%s\" in period", + period->startcolname))); + + /* Find the end column */ + endtuple = SearchSysCacheAttName(RelationGetRelid(rel), period->endcolname); + if (!HeapTupleIsValid(endtuple)) + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_COLUMN), + errmsg("column \"%s\" of relation \"%s\" does not exist", + period->endcolname, RelationGetRelationName(rel)))); + atttuple = (Form_pg_attribute) GETSTRUCT(endtuple); + endtypid = atttuple->atttypid; + endcollation = atttuple->attcollation; + period->endattnum = atttuple->attnum; + ReleaseSysCache(endtuple); + + /* Make sure it's not a system column */ + if (period->endattnum <= 0) + ereport(ERROR, + (errcode(ERRCODE_INVALID_OBJECT_DEFINITION), + errmsg("cannot use system column \"%s\" in period", + period->endcolname))); + + /* Both columns must be of same type */ + if (period->coltypid != endtypid) + ereport(ERROR, + (errcode(ERRCODE_DATATYPE_MISMATCH), + errmsg("start and end columns of period must be of same type"))); + + /* Both columns must have the same collation */ + if (attcollation != endcollation) + ereport(ERROR, + (errcode(ERRCODE_COLLATION_MISMATCH), + errmsg("start and end columns of period must have same collation"))); + + /* Get the range type based on the start/end cols or the user's choice */ + period->rngtypid = choose_rangetype_for_period(period); + + /* + * If the GENERATED columns should already exist, make sure it is + * sensible. + */ + if (period->colexists) + { + HeapTuple rngtuple = SearchSysCacheAttName(RelationGetRelid(rel), + period->periodname); + + if (!HeapTupleIsValid(rngtuple)) + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_COLUMN), + errmsg("column \"%s\" of relation \"%s\" does not exist", + period->periodname, RelationGetRelationName(rel)))); + atttuple = (Form_pg_attribute) GETSTRUCT(rngtuple); + + /* + * Make sure the existing column matches what we would have created. + * First of all, it must be GENERATED. + */ + if (atttuple->attgenerated == '\0') + ereport(ERROR, (errmsg("Period %s uses a non-generated column", + period->periodname))); + + /* The GENERATED column must be STORED. */ + if (atttuple->attgenerated != ATTRIBUTE_GENERATED_STORED) + ereport(ERROR, (errmsg("Period %s uses a generated column that is not STORED", + period->periodname))); + + /* The GENERATED column must not allow nulls. */ + if (!atttuple->attnotnull && !IsBinaryUpgrade) + ereport(ERROR, (errmsg("Period %s uses a generated column that allows nulls", + period->periodname))); + + /* The GENERATED column must match our rangetype. */ + if (period->rngtypid != atttuple->atttypid) + ereport(ERROR, (errmsg("Period %s uses a generated column with the wrong type", + period->periodname))); + + /* + * The GENERATED column must not be inherited. + * XXX: If the PERIOD is inherited, they must come from the same parent. + */ + if (!atttuple->attislocal) + ereport(ERROR, (errmsg("Period %s uses a generated column that is inherited", + period->periodname))); + + /* + * XXX: We should check the GENERATED expression also, but that is + * hard to do because one is cooked and one is raw. + */ + + period->rngattnum = atttuple->attnum; + + ReleaseSysCache(rngtuple); + } +} + +/* + * choose_rangetype_for_period + * + * Find a suitable range type for operations involving this period. + * Use the rangetype option if provided, otherwise try to find a + * non-ambiguous existing type. + */ +Oid +choose_rangetype_for_period(PeriodDef *period) +{ + Oid rngtypid; + + if (period->rangetypename != NULL) + { + /* Make sure it exists */ + rngtypid = TypenameGetTypidExtended(period->rangetypename, false); + if (rngtypid == InvalidOid) + ereport(ERROR, (errcode(ERRCODE_UNDEFINED_OBJECT), + errmsg("Range type %s not found", + period->rangetypename))); + + /* Make sure it is a range type */ + if (!type_is_range(rngtypid)) + ereport(ERROR, + (errcode(ERRCODE_DATATYPE_MISMATCH), + errmsg("Type %s is not a range type", + period->rangetypename))); + + /* Make sure it matches the column type */ + if (get_range_subtype(rngtypid) != period->coltypid) + ereport(ERROR, + (errcode(ERRCODE_DATATYPE_MISMATCH), + errmsg("Range type %s does not match column type %s", + period->rangetypename, + format_type_be(period->coltypid)))); + } + else + { + rngtypid = get_subtype_range(period->coltypid); + if (rngtypid == InvalidOid) + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_OBJECT), + errmsg("no range type for %s found for period %s", + format_type_be(period->coltypid), + period->periodname), + errhint("You can define a custom range type with CREATE TYPE"))); + + } + + return rngtypid; +} + +static void +AddRelationNewPeriod(Relation rel, PeriodDef *period) +{ + Relation attrelation; + Oid conoid; + Constraint *constr; + List *newconstrs; + + attrelation = table_open(AttributeRelationId, RowExclusiveLock); + + /* Find the GENERATED range column */ + + period->rngattnum = get_attnum(RelationGetRelid(rel), period->periodname); + if (period->rngattnum == InvalidAttrNumber) + elog(ERROR, "missing attribute %s", period->periodname); + + /* The parser has already found period->coltypid */ + + constr = make_constraint_for_period(rel, period); + newconstrs = AddRelationNewConstraints(rel, NIL, list_make1(constr), false, + true, true, NULL); + conoid = ((CookedConstraint *) linitial(newconstrs))->conoid; + + /* Save it */ + StorePeriod(rel, period->periodname, period->startattnum, period->endattnum, + period->rngattnum, conoid); + + table_close(attrelation, RowExclusiveLock); +} + /* * Emit the right error or warning message for a "DROP" command issued on a * non-existent relation @@ -2747,7 +3205,7 @@ MergeAttributes(List *columns, const List *supers, char relpersistence, * that's not marked NO INHERIT (even if not valid). */ nnconstrs = RelationGetNotNullConstraints(RelationGetRelid(relation), - true, false); + true, false, NULL); foreach_ptr(CookedConstraint, cc, nnconstrs) nncols = bms_add_member(nncols, cc->attnum); @@ -3140,6 +3598,172 @@ MergeAttributes(List *columns, const List *supers, char relpersistence, } +/*---------- + * MergePeriods + * Returns new period list given initial periods and superclasses. + * + * For now we don't support inheritence with PERIODs, + * but we might make it work eventually. + * + * We can omit lots of checks here and assume MergeAttributes already did them, + * for example that child & parents are not a mix of permanent and temp. + */ +static List * +MergePeriods(char *relname, List *periods, List *tableElts, List *supers) +{ + ListCell *entry; + + /* If we have a PERIOD then supers must be empty. */ + + if (list_length(periods) > 0 && list_length(supers) > 0) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("Inheriting is not supported when a table has a PERIOD"))); + + /* If any parent table has a PERIOD, then fail. */ + + foreach(entry, supers) + { + Oid parent = lfirst_oid(entry); + Relation relation; + Relation pg_period; + SysScanDesc scan; + ScanKeyData skey[1]; + HeapTuple tuple; + + /* caller already got lock */ + relation = table_open(parent, NoLock); + pg_period = table_open(PeriodRelationId, AccessShareLock); + + ScanKeyInit(&skey[0], + Anum_pg_period_perrelid, + BTEqualStrategyNumber, F_OIDEQ, + ObjectIdGetDatum(parent)); + + scan = systable_beginscan(pg_period, PeriodRelidNameIndexId, true, + NULL, 1, skey); + + if (HeapTupleIsValid(tuple = systable_getnext(scan))) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("Inheriting from a table with a PERIOD is not supported"))); + + systable_endscan(scan); + table_close(pg_period, AccessShareLock); + table_close(relation, NoLock); + } + + /* + * Find the start & end columns and get their attno and type. In the same + * pass, make sure the period doesn't conflict with any column names. Also + * make sure the same period name isn't used more than once. + */ + foreach(entry, periods) + { + PeriodDef *period = lfirst(entry); + ListCell *entry2; + int i = 1; + Oid startcoltypid = InvalidOid; + Oid endcoltypid = InvalidOid; + Oid startcolcollation = InvalidOid; + Oid endcolcollation = InvalidOid; + + period->startattnum = InvalidAttrNumber; + period->endattnum = InvalidAttrNumber; + + if (SystemAttributeByName(period->periodname) != NULL) + ereport(ERROR, + (errcode(ERRCODE_DUPLICATE_COLUMN), + errmsg("period name \"%s\" conflicts with a system column name", + period->periodname))); + + foreach(entry2, periods) + { + PeriodDef *period2 = lfirst(entry2); + + if (period != period2 && strcmp(period->periodname, period2->periodname) == 0) + ereport(ERROR, + (errcode(ERRCODE_DUPLICATE_OBJECT), + errmsg("period name \"%s\" specified more than once", + period->periodname))); + } + + foreach(entry2, tableElts) + { + ColumnDef *col = lfirst(entry2); + int32 atttypmod; + AclResult aclresult; + + if (!period->colexists && strcmp(period->periodname, col->colname) == 0) + ereport(ERROR, + (errcode(ERRCODE_DUPLICATE_COLUMN), + errmsg("period name \"%s\" conflicts with a column name", + period->periodname))); + + if (strcmp(period->startcolname, col->colname) == 0) + { + period->startattnum = i; + + typenameTypeIdAndMod(NULL, col->typeName, &startcoltypid, + &atttypmod); + + aclresult = object_aclcheck(TypeRelationId, startcoltypid, + GetUserId(), ACL_USAGE); + if (aclresult != ACLCHECK_OK) + aclcheck_error_type(aclresult, startcoltypid); + + startcolcollation = GetColumnDefCollation(NULL, col, startcoltypid); + } + + if (strcmp(period->endcolname, col->colname) == 0) + { + period->endattnum = i; + + typenameTypeIdAndMod(NULL, col->typeName, &endcoltypid, + &atttypmod); + + aclresult = object_aclcheck(TypeRelationId, endcoltypid, + GetUserId(), ACL_USAGE); + if (aclresult != ACLCHECK_OK) + aclcheck_error_type(aclresult, endcoltypid); + + endcolcollation = GetColumnDefCollation(NULL, col, endcoltypid); + } + + i++; + } + + /* Did we find the columns? */ + if (period->startattnum == InvalidAttrNumber) + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_COLUMN), + errmsg("column \"%s\" of relation \"%s\" does not exist", + period->startcolname, relname))); + if (period->endattnum == InvalidAttrNumber) + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_COLUMN), + errmsg("column \"%s\" of relation \"%s\" does not exist", + period->endcolname, relname))); + + /* Both columns must be of same type */ + if (startcoltypid != endcoltypid) + ereport(ERROR, + (errcode(ERRCODE_DATATYPE_MISMATCH), + errmsg("start and end columns of period must be of same type"))); + + /* Both columns must have the same collation */ + if (startcolcollation != endcolcollation) + ereport(ERROR, + (errcode(ERRCODE_COLLATION_MISMATCH), + errmsg("start and end columns of period must have same collation"))); + + period->coltypid = startcoltypid; + period->rngtypid = choose_rangetype_for_period(period); + } + + return periods; +} + /* * MergeCheckConstraint * Try to merge an inherited CHECK constraint with previous ones @@ -4547,12 +5171,12 @@ AlterTable(AlterTableStmt *stmt, LOCKMODE lockmode, * existing query plans. On the assumption it's not used for such, we * don't have to reject pending AFTER triggers, either. * - * Also, since we don't have an AlterTableUtilityContext, this cannot be + * Also, if you don't pass an AlterTableUtilityContext, this cannot be * used for any subcommand types that require parse transformation or * could generate subcommands that have to be passed to ProcessUtility. */ void -AlterTableInternal(Oid relid, List *cmds, bool recurse) +AlterTableInternal(Oid relid, List *cmds, bool recurse, AlterTableUtilityContext *context) { Relation rel; LOCKMODE lockmode = AlterTableGetLockLevel(cmds); @@ -4561,7 +5185,7 @@ AlterTableInternal(Oid relid, List *cmds, bool recurse) EventTriggerAlterTableRelid(relid); - ATController(NULL, rel, cmds, recurse, lockmode, NULL); + ATController(NULL, rel, cmds, recurse, lockmode, context); } /* @@ -4654,6 +5278,9 @@ AlterTableGetLockLevel(List *cmds) case AT_EnableReplicaRule: /* may change SELECT rules */ case AT_EnableRule: /* may change SELECT rules */ case AT_DisableRule: /* may change SELECT rules */ + case AT_AddPeriod: /* shares namespace with columns, adds + * constraint */ + case AT_DropPeriod: cmd_lockmode = AccessExclusiveLock; break; @@ -4973,6 +5600,17 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd, /* This command never recurses */ pass = AT_PASS_ADD_OTHERCONSTR; break; + case AT_AddPeriod: /* ALTER TABLE ... ADD PERIOD FOR name (start, + * end) */ + ATSimplePermissions(cmd->subtype, rel, ATT_TABLE); + ATPrepAddPeriod(wqueue, rel, cmd, lockmode, context); + /* No recursion: inheritance not supported with PERIODs */ + pass = AT_PASS_ADD_PERIOD; + break; + case AT_DropPeriod: /* ALTER TABLE ... DROP PERIOD FOR name */ + ATSimplePermissions(cmd->subtype, rel, ATT_TABLE); + pass = AT_PASS_DROP; + break; case AT_AddIdentity: ATSimplePermissions(cmd->subtype, rel, ATT_TABLE | ATT_PARTITIONED_TABLE | ATT_VIEW | @@ -5386,6 +6024,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab, case AT_CookedColumnDefault: /* add a pre-cooked default */ address = ATExecCookedColumnDefault(rel, cmd->num, cmd->def); break; + case AT_AddPeriod: + address = ATExecAddPeriod(wqueue, tab, rel, (PeriodDef *) cmd->def, + lockmode, context); + break; + case AT_DropPeriod: + ATExecDropPeriod(rel, cmd->name, cmd->behavior, false, false, + cmd->missing_ok); + break; case AT_AddIdentity: cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode, cur_pass, context); @@ -6592,6 +7238,8 @@ alter_table_type_to_string(AlterTableType cmdtype) case AT_AddColumn: case AT_AddColumnToView: return "ADD COLUMN"; + case AT_AddPeriod: + return "ADD PERIOD"; case AT_ColumnDefault: case AT_CookedColumnDefault: return "ALTER COLUMN ... SET DEFAULT"; @@ -6615,6 +7263,8 @@ alter_table_type_to_string(AlterTableType cmdtype) return "ALTER COLUMN ... SET COMPRESSION"; case AT_DropColumn: return "DROP COLUMN"; + case AT_DropPeriod: + return "DROP PERIOD"; case AT_AddIndex: case AT_ReAddIndex: return NULL; /* not real grammar */ @@ -7633,14 +8283,30 @@ ATExecAddColumn(List **wqueue, AlteredTableInfo *tab, Relation rel, /* * If a new or renamed column will collide with the name of an existing * column and if_not_exists is false then error out, else do nothing. + * + * See also check_for_period_name_collision. */ static bool check_for_column_name_collision(Relation rel, const char *colname, bool if_not_exists) { - HeapTuple attTuple; + HeapTuple attTuple, + perTuple; int attnum; + /* If the name exists as a period, we're done. */ + perTuple = SearchSysCache2(PERIODNAME, + ObjectIdGetDatum(RelationGetRelid(rel)), + PointerGetDatum(colname)); + if (HeapTupleIsValid(perTuple)) + { + ReleaseSysCache(perTuple); + ereport(ERROR, + (errcode(ERRCODE_DUPLICATE_COLUMN), + errmsg("column name \"%s\" conflicts with a period name", + colname))); + } + /* * this test is deliberately not attisdropped-aware, since if one tries to * add a column matching a dropped column name, it's gonna fail anyway. @@ -7684,6 +8350,78 @@ check_for_column_name_collision(Relation rel, const char *colname, return true; } +/* + * If a new period name will collide with the name of an existing column or + * period [and if_not_exists is false] then error out, else do nothing. + * + * See also check_for_column_name_collision. + */ +static bool +check_for_period_name_collision(Relation rel, const char *pername, + bool colexists, bool if_not_exists) +{ + HeapTuple attTuple, + perTuple; + int attnum; + + /* XXX: implement IF [NOT] EXISTS for periods */ + Assert(!if_not_exists); + + /* If there is already a period with this name, then we're done. */ + perTuple = SearchSysCache2(PERIODNAME, + ObjectIdGetDatum(RelationGetRelid(rel)), + PointerGetDatum(pername)); + if (HeapTupleIsValid(perTuple)) + { + if (if_not_exists) + { + ReleaseSysCache(perTuple); + + ereport(NOTICE, + (errcode(ERRCODE_DUPLICATE_COLUMN), + errmsg("period \"%s\" of relation \"%s\" already exists, skipping", + pername, RelationGetRelationName(rel)))); + return false; + } + + ereport(ERROR, + (errcode(ERRCODE_DUPLICATE_COLUMN), + errmsg("period \"%s\" of relation \"%s\" already exists", + pername, RelationGetRelationName(rel)))); + } + + /* + * this test is deliberately not attisdropped-aware, since if one tries to + * add a column matching a dropped column name, it's gonna fail anyway. + */ + attTuple = SearchSysCache2(ATTNAME, + ObjectIdGetDatum(RelationGetRelid(rel)), + PointerGetDatum(pername)); + if (HeapTupleIsValid(attTuple)) + { + attnum = ((Form_pg_attribute) GETSTRUCT(attTuple))->attnum; + ReleaseSysCache(attTuple); + + /* + * We throw a different error message for conflicts with system column + * names, since they are normally not shown and the user might + * otherwise be confused about the reason for the conflict. + */ + if (attnum <= 0) + ereport(ERROR, + (errcode(ERRCODE_DUPLICATE_COLUMN), + errmsg("period name \"%s\" conflicts with a system column name", + pername))); + if (!colexists) + ereport(ERROR, + (errcode(ERRCODE_DUPLICATE_COLUMN), + errmsg("period name \"%s\" conflicts with a column name", + pername))); + } + + return true; +} + /* * Install a column's dependency on its datatype. */ @@ -8223,6 +8961,209 @@ ATExecCookedColumnDefault(Relation rel, AttrNumber attnum, return address; } +/* + * Prepare to add a PERIOD to a table, by adding all its constituent objects. + * + * We need a CHECK constraint enforcing we start before we end. + * + * Usually we also create a GENERATED column with a NOT NULL constraint, + * unless the command indicates we have one already. + * + * PERIODs are not supported in inheritance hierarchies, so we don't need + * to worry about recursion. + * + * ATExecAddPeriod will need the oid of the CHECK constraint and the attnum + * of the range column (whether new or not) to record the dependency. + */ +static void +ATPrepAddPeriod(List **wqueue, Relation rel, AlterTableCmd *cmd, + LOCKMODE lockmode, AlterTableUtilityContext *context) +{ + PeriodDef *period = (PeriodDef *) cmd->def; + + /* + * PERIOD FOR SYSTEM_TIME is not yet implemented, but make sure no one + * uses the name. + */ + if (strcmp(period->periodname, "system_time") == 0) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("PERIOD FOR SYSTEM_TIME is not supported"))); + + if (strcmp(period->startcolname, period->endcolname) == 0) + ereport(ERROR, (errmsg("column \"%s\" can't be the start and end column for period \"%s\"", + period->startcolname, period->periodname))); + + /* Parse options */ + transformPeriodOptions(period); +} + +/* + * ALTER TABLE ADD PERIOD + * + * Return the address of the period. + */ +static ObjectAddress +ATExecAddPeriod(List **wqueue, AlteredTableInfo *tab, Relation rel, + PeriodDef *period, LOCKMODE lockmode, + AlterTableUtilityContext *context) +{ + Relation attrelation; + ObjectAddress address = InvalidObjectAddress; + Constraint *constr; + ColumnDef *rangecol; + Oid conoid, + periodoid; + List *cmds = NIL; + AlterTableCmd *cmd; + + /* + * The period name must not already exist. We can't check this in + * ATPrepAddPeriod because the same ALTER TABLE command might do a DROP + * PERIOD as well. + */ + (void) check_for_period_name_collision(rel, period->periodname, + period->colexists, false); + + attrelation = table_open(AttributeRelationId, RowExclusiveLock); + ValidatePeriod(rel, period); + + /* Make the CHECK constraint */ + constr = make_constraint_for_period(rel, period); + cmd = makeNode(AlterTableCmd); + cmd->subtype = AT_AddConstraint; + cmd->def = (Node *) constr; + cmds = lappend(cmds, cmd); + AlterTableInternal(RelationGetRelid(rel), cmds, true, context); + conoid = get_relation_constraint_oid(RelationGetRelid(rel), + period->constraintname, false); + + + if (!period->colexists) + { + cmds = NIL; + + /* + * Make the range column. + * + * We have already passed the add-column pass, so we have to create it + * ourself. + */ + rangecol = make_range_column_for_period(period); + cmd = makeNode(AlterTableCmd); + cmd->subtype = AT_AddColumn; + cmd->def = (Node *) rangecol; + cmd->name = period->periodname; + cmd->recurse = false; /* No, let the PERIOD recurse instead. */ + ATExecAddColumn(wqueue, tab, rel, &cmd, false, false, lockmode, + AT_PASS_ADD_PERIOD, context); + + /* The range column should be NOT NULL. */ + cmd = makeNode(AlterTableCmd); + cmd->subtype = AT_AddConstraint; + cmd->def = (Node *) makeNotNullConstraint(makeString(period->periodname)); + cmd->recurse = false; /* No, let the PERIOD recurse instead. */ + ATPrepCmd(wqueue, rel, cmd, false, false, lockmode, context); + + /* Look up the GENERATED attnum */ + period->rngattnum = get_attnum(RelationGetRelid(rel), period->periodname); + if (period->rngattnum == InvalidAttrNumber) + elog(ERROR, "missing attribute %s", period->periodname); + } + + /* Save the Period */ + periodoid = StorePeriod(rel, period->periodname, period->startattnum, + period->endattnum, period->rngattnum, conoid); + + ObjectAddressSet(address, PeriodRelationId, periodoid); + + table_close(attrelation, RowExclusiveLock); + + return address; +} + +/* + * ALTER TABLE DROP PERIOD + * + * Like DROP COLUMN, we can't use the normal ALTER TABLE recursion mechanism. + */ +static void +ATExecDropPeriod(Relation rel, const char *periodName, + DropBehavior behavior, + bool recurse, bool recursing, + bool missing_ok) +{ + Relation pg_period; + Form_pg_period period; + SysScanDesc scan; + ScanKeyData key; + HeapTuple tuple; + bool found = false; + + /* At top level, permission check was done in ATPrepCmd, else do it */ + if (recursing) + ATSimplePermissions(AT_DropPeriod, rel, ATT_TABLE); + + pg_period = table_open(PeriodRelationId, RowExclusiveLock); + + /* + * Find and drop the target period + */ + ScanKeyInit(&key, + Anum_pg_period_perrelid, + BTEqualStrategyNumber, F_OIDEQ, + ObjectIdGetDatum(RelationGetRelid(rel))); + scan = systable_beginscan(pg_period, PeriodRelidNameIndexId, + true, NULL, 1, &key); + + while (HeapTupleIsValid(tuple = systable_getnext(scan))) + { + ObjectAddress perobj; + + period = (Form_pg_period) GETSTRUCT(tuple); + + if (strcmp(NameStr(period->pername), periodName) != 0) + continue; + + /* + * Perform the actual period deletion + */ + perobj.classId = PeriodRelationId; + perobj.objectId = period->oid; + perobj.objectSubId = 0; + + performDeletion(&perobj, behavior, 0); + + found = true; + + /* period found and dropped -- no need to keep looping */ + break; + } + + systable_endscan(scan); + + if (!found) + { + if (!missing_ok) + { + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_OBJECT), + errmsg("period \"%s\" on relation \"%s\" does not exist", + periodName, RelationGetRelationName(rel)))); + } + else + { + ereport(NOTICE, + (errmsg("period \"%s\" on relation \"%s\" does not exist, skipping", + periodName, RelationGetRelationName(rel)))); + table_close(pg_period, RowExclusiveLock); + return; + } + } + + table_close(pg_period, RowExclusiveLock); +} + /* * ALTER TABLE ALTER COLUMN ADD IDENTITY * @@ -10235,8 +11176,9 @@ ATAddForeignKeyConstraint(List **wqueue, AlteredTableInfo *tab, Relation rel, for (i = 0; i < numfks; i++) { char attgenerated = TupleDescAttr(RelationGetDescr(rel), fkattnum[i] - 1)->attgenerated; + Bitmapset *periods = get_period_attnos(RelationGetRelid(rel)); - if (attgenerated) + if (attgenerated && !bms_is_member(fkattnum[i], periods)) { /* * Check restrictions on UPDATE/DELETE actions, per SQL standard @@ -15133,6 +16075,16 @@ RememberAllDependentForRebuilding(AlteredTableInfo *tab, AlterTableType subtype, RememberConstraintForRebuilding(foundObject.objectId, tab); break; + case PeriodRelationId: + if (subtype == AT_AlterColumnType) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("cannot alter type of a column used by a period"), + errdetail("%s depends on column \"%s\"", + getObjectDescription(&foundObject, false), + colName))); + break; + case ProcedureRelationId: /* @@ -15222,6 +16174,16 @@ RememberAllDependentForRebuilding(AlteredTableInfo *tab, AlterTableType subtype, } else { + /* + * If this GENERATED column is implementing a PERIOD, + * keep going and we'll fail from the PERIOD instead. + * This gives a more clear error message. + */ + Bitmapset *periodatts = get_period_attnos(RelationGetRelid(rel)); + + if (bms_is_member(col.objectSubId, periodatts)) + break; + /* * This must be a reference from the expression of a * generated column elsewhere in the same table. @@ -17158,7 +18120,7 @@ AlterTableMoveAll(AlterTableMoveAllStmt *stmt) EventTriggerAlterTableStart((Node *) stmt); /* OID is set by AlterTableInternal */ - AlterTableInternal(lfirst_oid(l), cmds, false); + AlterTableInternal(lfirst_oid(l), cmds, false, NULL); EventTriggerAlterTableEnd(); } diff --git a/src/backend/commands/trigger.c b/src/backend/commands/trigger.c index 43b9d82e63a6..968a91fd34bd 100644 --- a/src/backend/commands/trigger.c +++ b/src/backend/commands/trigger.c @@ -6143,6 +6143,8 @@ CopyForPortionOfState(ForPortionOfState *src) dst->fp_rangeName = pstrdup(src->fp_rangeName); dst->fp_rangeType = src->fp_rangeType; dst->fp_rangeAttno = src->fp_rangeAttno; + dst->fp_periodStartAttno = src->fp_periodStartAttno; + dst->fp_periodEndAttno = src->fp_periodEndAttno; r = DatumGetRangeTypeP(src->fp_targetRange); typcache = lookup_type_cache(RangeTypeGetOid(r), TYPECACHE_RANGE_INFO); diff --git a/src/backend/commands/view.c b/src/backend/commands/view.c index 6f0301555e0a..c72768362207 100644 --- a/src/backend/commands/view.c +++ b/src/backend/commands/view.c @@ -163,7 +163,7 @@ DefineVirtualRelation(RangeVar *relation, List *tlist, bool replace, } /* EventTriggerAlterTableStart called by ProcessUtilitySlow */ - AlterTableInternal(viewOid, atcmds, true); + AlterTableInternal(viewOid, atcmds, true, NULL); /* Make the new view columns visible */ CommandCounterIncrement(); @@ -195,7 +195,7 @@ DefineVirtualRelation(RangeVar *relation, List *tlist, bool replace, atcmds = list_make1(atcmd); /* EventTriggerAlterTableStart called by ProcessUtilitySlow */ - AlterTableInternal(viewOid, atcmds, true); + AlterTableInternal(viewOid, atcmds, true, NULL); /* * There is very little to do here to update the view's dependencies. diff --git a/src/backend/executor/nodeModifyTable.c b/src/backend/executor/nodeModifyTable.c index 857139ec58b8..8466270c46b5 100644 --- a/src/backend/executor/nodeModifyTable.c +++ b/src/backend/executor/nodeModifyTable.c @@ -1390,6 +1390,7 @@ ExecForPortionOfLeftovers(ModifyTableContext *context, TransitionCaptureState *oldTcs; FmgrInfo flinfo; ReturnSetInfo rsi; + bool hasPeriod = false; bool didInit = false; bool shouldFree = false; @@ -1504,6 +1505,8 @@ ExecForPortionOfLeftovers(ModifyTableContext *context, ExecForceStoreHeapTuple(oldtuple, leftoverSlot, false); } + hasPeriod = forPortionOf->startVar; + /* * Save some mtstate things so we can restore them below. XXX: * Should we create our own ModifyTableState instead? @@ -1515,8 +1518,42 @@ ExecForPortionOfLeftovers(ModifyTableContext *context, didInit = true; } - leftoverSlot->tts_values[forPortionOf->rangeVar->varattno - 1] = leftover; - leftoverSlot->tts_isnull[forPortionOf->rangeVar->varattno - 1] = false; + if (hasPeriod) + { + RangeType *leftoverRange; + RangeBound leftoverLower; + RangeBound leftoverUpper; + bool leftoverEmpty; + AttrNumber startAttno; + AttrNumber endAttno; + + leftoverRange = DatumGetRangeTypeP(leftover); + range_deserialize(typcache, leftoverRange, &leftoverLower, &leftoverUpper, &leftoverEmpty); + + startAttno = forPortionOf->startVar->varattno; + endAttno = forPortionOf->endVar->varattno; + + if (leftoverLower.infinite) + leftoverSlot->tts_isnull[startAttno - 1] = true; + else + { + leftoverSlot->tts_isnull[startAttno - 1] = false; + leftoverSlot->tts_values[startAttno - 1] = leftoverLower.val; + } + + if (leftoverUpper.infinite) + leftoverSlot->tts_isnull[endAttno - 1] = true; + else + { + leftoverSlot->tts_isnull[endAttno - 1] = false; + leftoverSlot->tts_values[endAttno - 1] = leftoverUpper.val; + } + } + else + { + leftoverSlot->tts_values[forPortionOf->rangeVar->varattno - 1] = leftover; + leftoverSlot->tts_isnull[forPortionOf->rangeVar->varattno - 1] = false; + } ExecMaterializeSlot(leftoverSlot); /* diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c index e40e8eecf732..8d2c7db4b27a 100644 --- a/src/backend/nodes/nodeFuncs.c +++ b/src/backend/nodes/nodeFuncs.c @@ -1729,6 +1729,9 @@ exprLocation(const Node *expr) case T_Constraint: loc = ((const Constraint *) expr)->location; break; + case T_PeriodDef: + loc = ((const PeriodDef *) expr)->location; + break; case T_FunctionParameter: loc = ((const FunctionParameter *) expr)->location; break; diff --git a/src/backend/parser/analyze.c b/src/backend/parser/analyze.c index a542c81b45fa..1a087aecae3b 100644 --- a/src/backend/parser/analyze.c +++ b/src/backend/parser/analyze.c @@ -24,10 +24,12 @@ #include "postgres.h" +#include "access/htup_details.h" #include "access/stratnum.h" #include "access/sysattr.h" #include "catalog/pg_am.h" #include "catalog/pg_operator.h" +#include "catalog/pg_period.h" #include "catalog/pg_proc.h" #include "catalog/pg_type.h" #include "commands/defrem.h" @@ -50,6 +52,7 @@ #include "parser/parse_relation.h" #include "parser/parse_target.h" #include "parser/parse_type.h" +#include "parser/parser.h" #include "parser/parsetree.h" #include "utils/backend_status.h" #include "utils/builtins.h" @@ -1321,6 +1324,10 @@ transformForPortionOfClause(ParseState *pstate, char *range_type_namespace = NULL; char *range_type_name = NULL; int range_attno = InvalidAttrNumber; + AttrNumber start_attno = InvalidAttrNumber; + AttrNumber end_attno = InvalidAttrNumber; + char *startcolname = NULL; + char *endcolname = NULL; Form_pg_attribute attr; Oid opclass; Oid opfamily; @@ -1364,6 +1371,54 @@ transformForPortionOfClause(ParseState *pstate, if (!get_typname_and_namespace(attr->atttypid, &range_type_name, &range_type_namespace)) elog(ERROR, "cache lookup failed for type %u", attr->atttypid); + /* + * If we are using a PERIOD, we need the start & end columns. If the + * attribute it not a GENERATED column, we needn't query pg_period. + */ + if (attr->attgenerated == ATTRIBUTE_GENERATED_STORED) + { + HeapTuple perTuple = SearchSysCache2(PERIODNAME, + ObjectIdGetDatum(RelationGetRelid(targetrel)), + PointerGetDatum(range_name)); + + if (HeapTupleIsValid(perTuple)) + { + Form_pg_period per = (Form_pg_period) GETSTRUCT(perTuple); + Form_pg_attribute perattr; + + start_attno = per->perstart; + end_attno = per->perend; + + perattr = TupleDescAttr(targetrel->rd_att, start_attno - 1); + startcolname = NameStr(perattr->attname); + + result->startVar = makeVar( + rtindex, + start_attno, + perattr->atttypid, + perattr->atttypmod, + perattr->attcollation, + 0); + + perattr = TupleDescAttr(targetrel->rd_att, end_attno - 1); + endcolname = NameStr(perattr->attname); + result->endVar = makeVar( + rtindex, + end_attno, + perattr->atttypid, + perattr->atttypmod, + perattr->attcollation, + 0); + + ReleaseSysCache(perTuple); + } + } + + if (start_attno == InvalidAttrNumber) + { + result->startVar = NULL; + result->endVar = NULL; + } if (forPortionOf->target) @@ -1435,7 +1490,10 @@ transformForPortionOfClause(ParseState *pstate, { /* * Now make sure we update the start/end time of the record. For a - * range col (r) this is `r = r * targetRange`. + * range col (r) this is `r = r * targetRange`. For a PERIOD with cols + * (s, e) this is `s = lower(tsrange(s, e) * targetRange)` and `e = + * upper(tsrange(s, e) * targetRange` (of course not necessarily with + * tsrange, but with whatever range type is used there). */ Oid intersectoperoid; List *funcArgs = NIL; @@ -1470,14 +1528,72 @@ transformForPortionOfClause(ParseState *pstate, rangeTLEExpr = makeFuncExpr(funcid, attr->atttypid, funcArgs, InvalidOid, InvalidOid, COERCE_EXPLICIT_CALL); - /* Make a TLE to set the range column */ + /* Make a TLE to set the range column or start/end columns */ result->rangeTargetList = NIL; - tle = makeTargetEntry((Expr *) rangeTLEExpr, range_attno, range_name, false); - result->rangeTargetList = lappend(result->rangeTargetList, tle); - /* Mark the range column as requiring update permissions */ - target_perminfo->updatedCols = bms_add_member(target_perminfo->updatedCols, - range_attno - FirstLowInvalidHeapAttributeNumber); + if (result->startVar) + { + FuncExpr *boundTLEExpr; + Oid arg_types[1] = {ANYRANGEOID}; + FuncDetailCode fdresult; + int fgc_flags; + Oid rettype; + bool retset; + int nvargs; + Oid vatype; + Oid *declared_arg_types; + Oid elemtypid = get_range_subtype(attr->atttypid); + + /* set the start column */ + fdresult = func_get_detail(SystemFuncName("lower"), NIL, NIL, 1, + arg_types, + false, false, false, &fgc_flags, + &funcid, &rettype, &retset, + &nvargs, &vatype, + &declared_arg_types, NULL); + if (fdresult != FUNCDETAIL_NORMAL) + elog(ERROR, "failed to find lower(anyrange) function"); + boundTLEExpr = makeFuncExpr(funcid, + elemtypid, + list_make1(rangeTLEExpr), + InvalidOid, InvalidOid, COERCE_EXPLICIT_CALL); + tle = makeTargetEntry((Expr *) boundTLEExpr, start_attno, startcolname, false); + result->rangeTargetList = lappend(result->rangeTargetList, tle); + + /* set the end column */ + fdresult = func_get_detail(SystemFuncName("upper"), NIL, NIL, 1, + arg_types, + false, false, false, &fgc_flags, + &funcid, &rettype, &retset, + &nvargs, &vatype, + &declared_arg_types, NULL); + if (fdresult != FUNCDETAIL_NORMAL) + elog(ERROR, "failed to find upper(anyrange) function"); + boundTLEExpr = makeFuncExpr(funcid, + elemtypid, + list_make1(rangeTLEExpr), + InvalidOid, InvalidOid, COERCE_EXPLICIT_CALL); + tle = makeTargetEntry((Expr *) boundTLEExpr, end_attno, endcolname, false); + result->rangeTargetList = lappend(result->rangeTargetList, tle); + + /* + * Mark the start/end columns as requiring update permissions. As + * usual, we don't check permissions for the GENERATED column. + */ + target_perminfo->updatedCols = bms_add_member(target_perminfo->updatedCols, + start_attno - FirstLowInvalidHeapAttributeNumber); + target_perminfo->updatedCols = bms_add_member(target_perminfo->updatedCols, + end_attno - FirstLowInvalidHeapAttributeNumber); + } + else + { + tle = makeTargetEntry((Expr *) rangeTLEExpr, range_attno, range_name, false); + result->rangeTargetList = lappend(result->rangeTargetList, tle); + + /* Mark the range column as requiring update permissions */ + target_perminfo->updatedCols = bms_add_member(target_perminfo->updatedCols, + range_attno - FirstLowInvalidHeapAttributeNumber); + } } else result->rangeTargetList = NIL; diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index a1561e774571..669685e40a85 100644 --- a/src/backend/parser/gram.y +++ b/src/backend/parser/gram.y @@ -599,7 +599,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); %type col_name_keyword reserved_keyword %type bare_label_keyword -%type DomainConstraint TableConstraint TableLikeClause +%type DomainConstraint TableConstraint TableLikeClause TablePeriod %type TableLikeOptionList TableLikeOption %type column_compression opt_column_compression column_storage opt_column_storage %type ColQualList @@ -2712,6 +2712,24 @@ alter_table_cmd: n->def = (Node *) $4; $$ = (Node *) n; } + /* ALTER TABLE ADD PERIOD FOR (, ) */ + | ADD_P TablePeriod + { + AlterTableCmd *n = makeNode(AlterTableCmd); + n->subtype = AT_AddPeriod; + n->def = $2; + $$ = (Node *)n; + } + /* ALTER TABLE DROP PERIOD FOR [RESTRICT|CASCADE] */ + | DROP PERIOD FOR name opt_drop_behavior + { + AlterTableCmd *n = makeNode(AlterTableCmd); + n->subtype = AT_DropPeriod; + n->name = $4; + n->behavior = $5; + n->missing_ok = false; + $$ = (Node *)n; + } /* ALTER TABLE ADD CONSTRAINT ... */ | ADD_P TableConstraint { @@ -3874,8 +3892,10 @@ TableElement: columnDef { $$ = $1; } | TableLikeClause { $$ = $1; } | TableConstraint { $$ = $1; } + | TablePeriod { $$ = $1; } ; + TypedTableElement: columnOptions { $$ = $1; } | TableConstraint { $$ = $1; } @@ -4253,6 +4273,19 @@ TableLikeOption: ; +TablePeriod: + PERIOD FOR name '(' name ',' name ')' opt_definition + { + PeriodDef *n = makeNode(PeriodDef); + n->periodname = $3; + n->startcolname = $5; + n->endcolname = $7; + n->options = $9; + n->location = @1; + $$ = (Node *) n; + } + ; + /* ConstraintElem specifies constraint syntax which is not embedded into * a column definition. ColConstraintElem specifies the embedded form. * - thomas 1997-12-03 @@ -7387,6 +7420,14 @@ CommentStmt: n->comment = $9; $$ = (Node *) n; } + | COMMENT ON PERIOD any_name IS comment_text + { + CommentStmt *n = makeNode(CommentStmt); + n->objtype = OBJECT_PERIOD; + n->object = (Node *) $4; + n->comment = $6; + $$ = (Node *) n; + } | COMMENT ON LARGE_P OBJECT_P NumericOnly IS comment_text { CommentStmt *n = makeNode(CommentStmt); @@ -18106,7 +18147,6 @@ unreserved_keyword: | PASSING | PASSWORD | PATH - | PERIOD | PLAN | PLANS | POLICY @@ -18412,6 +18452,7 @@ reserved_keyword: | ONLY | OR | ORDER + | PERIOD | PLACING | PRIMARY | REFERENCES diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c index 3c80bf1b9ce5..eb1d0643b092 100644 --- a/src/backend/parser/parse_relation.c +++ b/src/backend/parser/parse_relation.c @@ -22,6 +22,7 @@ #include "access/table.h" #include "catalog/heap.h" #include "catalog/namespace.h" +#include "catalog/pg_period.h" #include "catalog/pg_type.h" #include "funcapi.h" #include "nodes/makefuncs.h" @@ -3293,6 +3294,7 @@ expandNSItemAttrs(ParseState *pstate, ParseNamespaceItem *nsitem, int sublevels_up, bool require_col_privs, int location) { RangeTblEntry *rte = nsitem->p_rte; + Bitmapset *periodatts = NULL; RTEPermissionInfo *perminfo = nsitem->p_perminfo; List *names, *vars; @@ -3316,12 +3318,20 @@ expandNSItemAttrs(ParseState *pstate, ParseNamespaceItem *nsitem, perminfo->requiredPerms |= ACL_SELECT; } + /* Get PERIOD columns to exclude */ + if (rte->rtekind == RTE_RELATION) + periodatts = get_period_attnos(rte->relid); + forboth(name, names, var, vars) { char *label = strVal(lfirst(name)); Var *varnode = (Var *) lfirst(var); TargetEntry *te; + /* If this column is from a PERIOD, skip it */ + if (bms_is_member(varnode->varattno, periodatts)) + continue; + te = makeTargetEntry((Expr *) varnode, (AttrNumber) pstate->p_next_resno++, label, diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c index e96b38a59d50..67e36ac13837 100644 --- a/src/backend/parser/parse_utilcmd.c +++ b/src/backend/parser/parse_utilcmd.c @@ -37,6 +37,7 @@ #include "catalog/pg_constraint.h" #include "catalog/pg_opclass.h" #include "catalog/pg_operator.h" +#include "catalog/pg_period.h" #include "catalog/pg_statistic_ext.h" #include "catalog/pg_type.h" #include "commands/comment.h" @@ -80,6 +81,7 @@ typedef struct bool isforeign; /* true if CREATE/ALTER FOREIGN TABLE */ bool isalter; /* true if altering existing table */ List *columns; /* ColumnDef items */ + List *periods; /* PeriodDef items */ List *ckconstraints; /* CHECK constraints */ List *nnconstraints; /* NOT NULL constraints */ List *fkconstraints; /* FOREIGN KEY constraints */ @@ -110,6 +112,8 @@ typedef struct static void transformColumnDefinition(CreateStmtContext *cxt, ColumnDef *column); +static void transformTablePeriod(CreateStmtContext *cxt, + PeriodDef *period); static void transformTableConstraint(CreateStmtContext *cxt, Constraint *constraint); static void transformTableLikeClause(CreateStmtContext *cxt, @@ -240,6 +244,7 @@ transformCreateStmt(CreateStmt *stmt, const char *queryString) cxt.inhRelations = stmt->inhRelations; cxt.isalter = false; cxt.columns = NIL; + cxt.periods = NIL; cxt.ckconstraints = NIL; cxt.nnconstraints = NIL; cxt.fkconstraints = NIL; @@ -279,6 +284,10 @@ transformCreateStmt(CreateStmt *stmt, const char *queryString) transformColumnDefinition(&cxt, (ColumnDef *) element); break; + case T_PeriodDef: + transformTablePeriod(&cxt, (PeriodDef *) element); + break; + case T_Constraint: transformTableConstraint(&cxt, (Constraint *) element); break; @@ -367,6 +376,7 @@ transformCreateStmt(CreateStmt *stmt, const char *queryString) * Output results. */ stmt->tableElts = cxt.columns; + stmt->periods = cxt.periods; stmt->constraints = cxt.ckconstraints; stmt->nnconstraints = cxt.nnconstraints; @@ -1027,6 +1037,92 @@ transformColumnDefinition(CreateStmtContext *cxt, ColumnDef *column) } } +void +transformPeriodOptions(PeriodDef *period) +{ + ListCell *option; + DefElem *dconstraintname = NULL; + DefElem *drangetypename = NULL; + DefElem *dcolexists = NULL; + + foreach(option, period->options) + { + DefElem *defel = (DefElem *) lfirst(option); + + if (strcmp(defel->defname, "check_constraint_name") == 0) + { + if (dconstraintname) + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("conflicting or redundant options"))); + dconstraintname = defel; + } + else if (strcmp(defel->defname, "rangetype") == 0) + { + if (drangetypename) + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("conflicting or redundant options"))); + drangetypename = defel; + } + else if (strcmp(defel->defname, "colexists") == 0) + { + if (dcolexists) + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("conflicting or redundant options"))); + dcolexists = defel; + } + else + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("option \"%s\" not recognized", defel->defname))); + } + + if (dconstraintname != NULL) + period->constraintname = defGetString(dconstraintname); + else + period->constraintname = NULL; + + if (drangetypename != NULL) + period->rangetypename = defGetString(drangetypename); + else + period->rangetypename = NULL; + + if (dcolexists != NULL) + period->colexists = defGetBoolean(dcolexists); + else + period->colexists = false; +} + +/* + * transformTablePeriod + * transform a PeriodDef node within CREATE TABLE + */ +static void +transformTablePeriod(CreateStmtContext *cxt, PeriodDef *period) +{ + if (strcmp(period->periodname, "system_time") == 0) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("PERIOD FOR SYSTEM_TIME is not supported"), + parser_errposition(cxt->pstate, + period->location))); + + if (strcmp(period->startcolname, period->endcolname) == 0) + ereport(ERROR, (errmsg("column \"%s\" can't be the start and end column for period \"%s\"", + period->startcolname, period->periodname))); + + /* + * Determine the column info and range type so that + * transformIndexConstraints knows how to create PRIMARY KEY/UNIQUE + * constraints using this PERIOD. + */ + transformPeriodOptions(period); + + cxt->periods = lappend(cxt->periods, period); +} + /* * transformTableConstraint * transform a Constraint node within CREATE TABLE or ALTER TABLE @@ -1128,6 +1224,7 @@ transformTableLikeClause(CreateStmtContext *cxt, TableLikeClause *table_like_cla AttrNumber parent_attno; Relation relation; TupleDesc tupleDesc; + Bitmapset *periodatts; AclResult aclresult; char *comment; ParseCallbackState pcbstate; @@ -1173,6 +1270,7 @@ transformTableLikeClause(CreateStmtContext *cxt, TableLikeClause *table_like_cla } tupleDesc = RelationGetDescr(relation); + periodatts = get_period_attnos(RelationGetRelid(relation)); /* * Insert the copied attributes into the cxt for the new table definition. @@ -1182,10 +1280,18 @@ transformTableLikeClause(CreateStmtContext *cxt, TableLikeClause *table_like_cla for (parent_attno = 1; parent_attno <= tupleDesc->natts; parent_attno++) { - Form_pg_attribute attribute = TupleDescAttr(tupleDesc, - parent_attno - 1); + Form_pg_attribute attribute; ColumnDef *def; + /* + * If this column is from a PERIOD, skip it (since LIKE never copies + * PERIODs). + */ + if (bms_is_member(parent_attno, periodatts)) + continue; + + attribute = TupleDescAttr(tupleDesc, parent_attno - 1); + /* * Ignore dropped columns in the parent. */ @@ -1271,13 +1377,16 @@ transformTableLikeClause(CreateStmtContext *cxt, TableLikeClause *table_like_cla /* * Reproduce not-null constraints, if any, by copying them. We do this * regardless of options given. + * + * Since we skipped PERIODs' GENERATED columns above, we must skip their + * not-null constraints here. */ if (tupleDesc->constr && tupleDesc->constr->has_not_null) { List *lst; lst = RelationGetNotNullConstraints(RelationGetRelid(relation), false, - true); + true, periodatts); cxt->nnconstraints = list_concat(cxt->nnconstraints, lst); /* Copy comments on not-null constraints */ @@ -2609,6 +2718,7 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt) { char *key = strVal(lfirst(lc)); bool found = false; + bool hasperiod = false; ColumnDef *column = NULL; ListCell *columns; IndexElem *iparam; @@ -2627,6 +2737,24 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt) if (!found) column = NULL; + /* If the key is WITHOUT OVERLAPS, a PERIOD will work too. */ + if (!found && constraint->without_overlaps && + lc == list_last_cell(constraint->keys)) + { + PeriodDef *period = NULL; + + foreach(columns, cxt->periods) + { + period = lfirst_node(PeriodDef, columns); + if (strcmp(period->periodname, key) == 0) + { + found = true; + hasperiod = true; + break; + } + } + } + if (found) { /* @@ -2643,24 +2771,37 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt) if (constraint->contype == CONSTR_PRIMARY && !cxt->isalter) { - if (column->is_not_null) + if (column) { - foreach_node(Constraint, nn, cxt->nnconstraints) + if (column->is_not_null) { - if (strcmp(strVal(linitial(nn->keys)), key) == 0) + foreach_node(Constraint, nn, cxt->nnconstraints) { - if (nn->is_no_inherit) - ereport(ERROR, - errcode(ERRCODE_SYNTAX_ERROR), - errmsg("conflicting NO INHERIT declaration for not-null constraint on column \"%s\"", - key)); - break; + if (strcmp(strVal(linitial(nn->keys)), key) == 0) + { + if (nn->is_no_inherit) + ereport(ERROR, + errcode(ERRCODE_SYNTAX_ERROR), + errmsg("conflicting NO INHERIT declaration for not-null constraint on column \"%s\"", + key)); + break; + } } } + else + { + column->is_not_null = true; + cxt->nnconstraints = + lappend(cxt->nnconstraints, + makeNotNullConstraint(makeString(key))); + } } - else + else if (hasperiod) { - column->is_not_null = true; + /* + * If we're using a PERIOD, we better make sure it is + * NOT NULL + */ cxt->nnconstraints = lappend(cxt->nnconstraints, makeNotNullConstraint(makeString(key))); @@ -2787,7 +2928,13 @@ transformIndexConstraint(Constraint *constraint, CreateStmtContext *cxt) } } } - if (found) + + /* + * In CREATE TABLE we don't know PERIODs' rangetype yet, but + * we know it will be a range/multirange. So if we have a + * PERIOD then we're safe. + */ + if (found && !hasperiod) { if (!OidIsValid(typid) && column) typid = typenameTypeId(NULL, column->typeName); @@ -3113,6 +3260,10 @@ transformIndexStmt(Oid relid, IndexStmt *stmt, const char *queryString) } } + /* take care of the period */ + if (stmt->period) + stmt->period->oid = get_period_oid(relid, stmt->period->periodname, false); + /* * Check that only the base rel is mentioned. (This should be dead code * now that add_missing_from is history.) @@ -3570,6 +3721,7 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt, cxt.inhRelations = NIL; cxt.isalter = true; cxt.columns = NIL; + cxt.periods = NIL; cxt.ckconstraints = NIL; cxt.nnconstraints = NIL; cxt.fkconstraints = NIL; diff --git a/src/backend/utils/adt/Makefile b/src/backend/utils/adt/Makefile index cc68ac545a5f..5d8cb353012d 100644 --- a/src/backend/utils/adt/Makefile +++ b/src/backend/utils/adt/Makefile @@ -80,6 +80,7 @@ OBJS = \ oracle_compat.o \ orderedsetaggs.o \ partitionfuncs.o \ + period.o \ pg_locale.o \ pg_locale_builtin.o \ pg_locale_icu.o \ diff --git a/src/backend/utils/adt/period.c b/src/backend/utils/adt/period.c new file mode 100644 index 000000000000..6f899068d03b --- /dev/null +++ b/src/backend/utils/adt/period.c @@ -0,0 +1,58 @@ +/*------------------------------------------------------------------------- + * + * period.c + * Functions to support periods. + * + * + * Portions Copyright (c) 1996-2022, PostgreSQL Global Development Group + * Portions Copyright (c) 1994, Regents of the University of California + * + * + * IDENTIFICATION + * src/backend/utils/adt/period.c + * + *------------------------------------------------------------------------- + */ +#include "postgres.h" + +#include "executor/tuptable.h" +#include "fmgr.h" +#include "nodes/primnodes.h" +#include "utils/fmgrprotos.h" +#include "utils/period.h" +#include "utils/rangetypes.h" + +Datum +period_to_range(TupleTableSlot *slot, int startattno, int endattno, Oid rangetype) +{ + Datum startvalue; + Datum endvalue; + Datum result; + bool startisnull; + bool endisnull; + + LOCAL_FCINFO(fcinfo, 2); + FmgrInfo flinfo; + FuncExpr *f; + + InitFunctionCallInfoData(*fcinfo, &flinfo, 2, InvalidOid, NULL, NULL); + f = makeNode(FuncExpr); + f->funcresulttype = rangetype; + flinfo.fn_expr = (Node *) f; + flinfo.fn_extra = NULL; + + /* compute oldvalue */ + startvalue = slot_getattr(slot, startattno, &startisnull); + endvalue = slot_getattr(slot, endattno, &endisnull); + + fcinfo->args[0].value = startvalue; + fcinfo->args[0].isnull = startisnull; + fcinfo->args[1].value = endvalue; + fcinfo->args[1].isnull = endisnull; + + result = range_constructor2(fcinfo); + if (fcinfo->isnull) + elog(ERROR, "function %u returned NULL", flinfo.fn_oid); + + return result; +} diff --git a/src/backend/utils/cache/lsyscache.c b/src/backend/utils/cache/lsyscache.c index 43158afac150..34c98188b0d4 100644 --- a/src/backend/utils/cache/lsyscache.c +++ b/src/backend/utils/cache/lsyscache.c @@ -33,6 +33,7 @@ #include "catalog/pg_opclass.h" #include "catalog/pg_opfamily.h" #include "catalog/pg_operator.h" +#include "catalog/pg_period.h" #include "catalog/pg_proc.h" #include "catalog/pg_publication.h" #include "catalog/pg_range.h" @@ -1088,6 +1089,68 @@ get_attoptions(Oid relid, int16 attnum) return result; } +/* ---------- PG_PERIOD CACHE ---------- */ + +/* + * get_periodname - given its OID, look up a period + * + * If missing_ok is false, throw an error if the period is not found. + * If true, just return InvalidOid. + */ +char * +get_periodname(Oid periodid, bool missing_ok) +{ + HeapTuple tp; + + tp = SearchSysCache1(PERIODOID, + ObjectIdGetDatum(periodid)); + if (HeapTupleIsValid(tp)) + { + Form_pg_period period_tup = (Form_pg_period) GETSTRUCT(tp); + char *result; + + result = pstrdup(NameStr(period_tup->pername)); + ReleaseSysCache(tp); + return result; + } + + if (!missing_ok) + elog(ERROR, "cache lookup failed for period %d", + periodid); + return NULL; +} + +/* + * get_period_oid - gets its relation and name, look up a period + * + * If missing_ok is false, throw an error if the cast is not found. If + * true, just return InvalidOid. + */ +Oid +get_period_oid(Oid relid, const char *periodname, bool missing_ok) +{ + HeapTuple tp; + + tp = SearchSysCache2(PERIODNAME, + ObjectIdGetDatum(relid), + PointerGetDatum(periodname)); + + if (HeapTupleIsValid(tp)) + { + Form_pg_period period_tup = (Form_pg_period) GETSTRUCT(tp); + Oid result; + + result = period_tup->oid; + ReleaseSysCache(tp); + return result; + } + + if (!missing_ok) + elog(ERROR, "cache lookup failed for period %s", + periodname); + return InvalidOid; +} + /* ---------- PG_CAST CACHE ---------- */ /* @@ -3692,6 +3755,31 @@ get_multirange_range(Oid multirangeOid) return InvalidOid; } +Oid +get_subtype_range(Oid subtypeOid) +{ + CatCList *catlist; + Oid result = InvalidOid; + + catlist = SearchSysCacheList1(RANGESUBTYPE, ObjectIdGetDatum(subtypeOid)); + + if (catlist->n_members == 1) + { + HeapTuple tuple = &catlist->members[0]->tuple; + Form_pg_range rngtup = (Form_pg_range) GETSTRUCT(tuple); + + result = rngtup->rngtypid; + ReleaseCatCacheList(catlist); + } + else if (catlist->n_members > 1) + ereport(ERROR, + (errcode(ERRCODE_INDETERMINATE_DATATYPE), + errmsg("ambiguous range for type %s", + format_type_be(subtypeOid)))); + + return result; +} + /* ---------- PG_INDEX CACHE ---------- */ /* diff --git a/src/bin/pg_dump/pg_backup_archiver.c b/src/bin/pg_dump/pg_backup_archiver.c index 59eaecb4ed71..820e89e4fd54 100644 --- a/src/bin/pg_dump/pg_backup_archiver.c +++ b/src/bin/pg_dump/pg_backup_archiver.c @@ -3873,6 +3873,7 @@ _getObjectDescription(PQExpBuffer buf, const TocEntry *te) strcmp(type, "DATABASE PROPERTIES") == 0 || strcmp(type, "DEFAULT") == 0 || strcmp(type, "FK CONSTRAINT") == 0 || + strcmp(type, "PERIOD") == 0 || strcmp(type, "INDEX") == 0 || strcmp(type, "RULE") == 0 || strcmp(type, "TRIGGER") == 0 || diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c index a00918bacb40..f8eb0f009df1 100644 --- a/src/bin/pg_dump/pg_dump.c +++ b/src/bin/pg_dump/pg_dump.c @@ -7184,6 +7184,7 @@ getTables(Archive *fout, int *numTables) int i_reltype; int i_relowner; int i_relchecks; + int i_nperiod; int i_relhasindex; int i_relhasrules; int i_relpages; @@ -7271,6 +7272,14 @@ getTables(Archive *fout, int *numTables) appendPQExpBufferStr(query, "c.relhasoids, "); + /* In PG19 upwards we have PERIODs. */ + if (fout->remoteVersion >= 190000) + appendPQExpBufferStr(query, + "(SELECT count(*) FROM pg_period WHERE perrelid = c.oid) AS nperiods, "); + else + appendPQExpBufferStr(query, + "0 AS nperiods, "); + if (fout->remoteVersion >= 90300) appendPQExpBufferStr(query, "c.relispopulated, "); @@ -7408,6 +7417,7 @@ getTables(Archive *fout, int *numTables) i_reltype = PQfnumber(res, "reltype"); i_relowner = PQfnumber(res, "relowner"); i_relchecks = PQfnumber(res, "relchecks"); + i_nperiod = PQfnumber(res, "nperiods"); i_relhasindex = PQfnumber(res, "relhasindex"); i_relhasrules = PQfnumber(res, "relhasrules"); i_relpages = PQfnumber(res, "relpages"); @@ -7497,6 +7507,7 @@ getTables(Archive *fout, int *numTables) } tblinfo[i].reltablespace = pg_strdup(PQgetvalue(res, i, i_reltablespace)); tblinfo[i].hasoids = (strcmp(PQgetvalue(res, i, i_relhasoids), "t") == 0); + tblinfo[i].nperiod = atoi(PQgetvalue(res, i, i_nperiod)); tblinfo[i].hastriggers = (strcmp(PQgetvalue(res, i, i_relhastriggers), "t") == 0); tblinfo[i].relpersistence = *(PQgetvalue(res, i, i_relpersistence)); tblinfo[i].relispopulated = (strcmp(PQgetvalue(res, i, i_relispopulated), "t") == 0); @@ -7955,7 +7966,7 @@ getIndexes(Archive *fout, TableInfo tblinfo[], int numTables) appendPQExpBufferStr(query, "false AS indnullsnotdistinct, "); - if (fout->remoteVersion >= 180000) + if (fout->remoteVersion >= 190000) appendPQExpBufferStr(query, "c.conperiod "); else @@ -9212,7 +9223,7 @@ getTransforms(Archive *fout) /* * getTableAttrs - * for each interesting table, read info about its attributes - * (names, types, default values, CHECK constraints, etc) + * (names, types, default values, CHECK constraints, PERIODs, etc) * * modifies tblinfo */ @@ -9267,6 +9278,8 @@ getTableAttrs(Archive *fout, TableInfo *tblinfo, int numTables) for (int i = 0; i < numTables; i++) { TableInfo *tbinfo = &tblinfo[i]; + int ndumpablechecks; /* number of CHECK constraints that do + * not belong to a period */ /* Don't bother to collect info for sequences */ if (tbinfo->relkind == RELKIND_SEQUENCE) @@ -9293,7 +9306,8 @@ getTableAttrs(Archive *fout, TableInfo *tblinfo, int numTables) appendPQExpBufferChar(tbloids, ','); appendPQExpBuffer(tbloids, "%u", tbinfo->dobj.catId.oid); - if (tbinfo->ncheck > 0) + ndumpablechecks = tbinfo->ncheck - tbinfo->nperiod; + if (ndumpablechecks > 0) { /* Also make a list of the ones with check constraints */ if (checkoids->len > 1) /* do we have more than the '{'? */ @@ -9828,15 +9842,36 @@ getTableAttrs(Archive *fout, TableInfo *tblinfo, int numTables) pg_log_info("finding table check constraints"); resetPQExpBuffer(q); - appendPQExpBuffer(q, - "SELECT c.tableoid, c.oid, conrelid, conname, " - "pg_catalog.pg_get_constraintdef(c.oid) AS consrc, " - "conislocal, convalidated " - "FROM unnest('%s'::pg_catalog.oid[]) AS src(tbloid)\n" - "JOIN pg_catalog.pg_constraint c ON (src.tbloid = c.conrelid)\n" - "WHERE contype = 'c' " - "ORDER BY c.conrelid, c.conname", - checkoids->data); + if (fout->remoteVersion >= 190000) + { + /* + * PERIODs were added in v19 and we don't dump CHECK constraints + * for them. + */ + appendPQExpBuffer(q, + "SELECT c.tableoid, c.oid, conrelid, conname, " + "pg_catalog.pg_get_constraintdef(c.oid) AS consrc, " + "conislocal, convalidated " + "FROM unnest('%s'::pg_catalog.oid[]) AS src(tbloid)\n" + "JOIN pg_catalog.pg_constraint c ON (src.tbloid = c.conrelid)\n" + "WHERE contype = 'c' " + " AND NOT EXISTS (SELECT FROM pg_period " + " WHERE (perrelid, perconstraint) = (conrelid, c.oid)) " + "ORDER BY c.conrelid, c.conname", + checkoids->data); + } + else + { + appendPQExpBuffer(q, + "SELECT c.tableoid, c.oid, conrelid, conname, " + "pg_catalog.pg_get_constraintdef(c.oid) AS consrc, " + "conislocal, convalidated " + "FROM unnest('%s'::pg_catalog.oid[]) AS src(tbloid)\n" + "JOIN pg_catalog.pg_constraint c ON (src.tbloid = c.conrelid)\n" + "WHERE contype = 'c' " + "ORDER BY c.conrelid, c.conname", + checkoids->data); + } res = ExecuteSqlQuery(fout, q->data, PGRES_TUPLES_OK); @@ -9858,6 +9893,7 @@ getTableAttrs(Archive *fout, TableInfo *tblinfo, int numTables) Oid conrelid = atooid(PQgetvalue(res, j, i_conrelid)); TableInfo *tbinfo = NULL; int numcons; + int ndumpablechecks; /* Count rows for this table */ for (numcons = 1; numcons < numConstrs - j; numcons++) @@ -9877,12 +9913,13 @@ getTableAttrs(Archive *fout, TableInfo *tblinfo, int numTables) if (curtblindx >= numTables) pg_fatal("unrecognized table OID %u", conrelid); - if (numcons != tbinfo->ncheck) + ndumpablechecks = tbinfo->ncheck - tbinfo->nperiod; + if (numcons != ndumpablechecks) { pg_log_error(ngettext("expected %d check constraint on table \"%s\" but found %d", "expected %d check constraints on table \"%s\" but found %d", - tbinfo->ncheck), - tbinfo->ncheck, tbinfo->dobj.name, numcons); + ndumpablechecks), + ndumpablechecks, tbinfo->dobj.name, numcons); pg_log_error_hint("The system catalogs might be corrupted."); exit_nicely(1); } @@ -9941,6 +9978,80 @@ getTableAttrs(Archive *fout, TableInfo *tblinfo, int numTables) PQclear(res); } + for (int i = 0; i < numTables; i++) + { + TableInfo *tbinfo = &tblinfo[i]; + + /* + * Get info about PERIOD definitions + */ + if (tbinfo->nperiod > 0) + { + PeriodInfo *periods; + int numPeriods; + int j; + + /* We shouldn't have any periods before v19 */ + Assert(fout->remoteVersion >= 190000); + + pg_log_info("finding periods for table \"%s.%s\"", + tbinfo->dobj.namespace->dobj.name, + tbinfo->dobj.name); + + resetPQExpBuffer(q); + appendPQExpBuffer(q, + "SELECT p.tableoid, p.oid, p.pername, " + " sa.attname AS perstart, ea.attname AS perend, " + " r.typname AS rngtype, " + " c.conname AS conname " + "FROM pg_catalog.pg_period AS p " + "JOIN pg_catalog.pg_attribute AS sa ON (sa.attrelid, sa.attnum) = (p.perrelid, p.perstart) " + "JOIN pg_catalog.pg_attribute AS ea ON (ea.attrelid, ea.attnum) = (p.perrelid, p.perend) " + "JOIN pg_catalog.pg_attribute AS ra ON (ra.attrelid, ra.attnum) = (p.perrelid, p.perrange) " + "JOIN pg_catalog.pg_type AS r ON r.oid = ra.atttypid " + "JOIN pg_catalog.pg_constraint AS c ON c.oid = p.perconstraint " + "WHERE p.perrelid = '%u'::pg_catalog.oid " + "ORDER BY p.pername", + tbinfo->dobj.catId.oid); + + res = ExecuteSqlQuery(fout, q->data, PGRES_TUPLES_OK); + + /* + * If we didn't get the number of rows we thought we were going + * to, then those JOINs didn't work. + */ + numPeriods = PQntuples(res); + if (numPeriods != tbinfo->nperiod) + { + pg_log_info(ngettext("expected %d period on table \"%s\" but found %d", + "expected %d periods on table \"%s\" but found %d", + tbinfo->nperiod), + tbinfo->nperiod, tbinfo->dobj.name, numPeriods); + pg_log_info("(The system catalogs might be corrupted.)"); + exit_nicely(1); + } + + periods = (PeriodInfo *) pg_malloc(numPeriods * sizeof(PeriodInfo)); + tbinfo->periods = periods; + + for (j = 0; j < numPeriods; j++) + { + periods[j].dobj.objType = DO_PERIOD; + periods[j].dobj.catId.tableoid = atooid(PQgetvalue(res, j, 0)); + periods[j].dobj.catId.oid = atooid(PQgetvalue(res, j, 1)); + AssignDumpId(&periods[j].dobj); + periods[j].dobj.name = pg_strdup(PQgetvalue(res, j, 2)); + periods[j].dobj.namespace = tbinfo->dobj.namespace; + periods[j].pertable = tbinfo; + periods[j].perstart = pg_strdup(PQgetvalue(res, j, 3)); + periods[j].perend = pg_strdup(PQgetvalue(res, j, 4)); + periods[j].rngtype = pg_strdup(PQgetvalue(res, j, 5)); + periods[j].conname = pg_strdup(PQgetvalue(res, j, 6)); + } + PQclear(res); + } + } + destroyPQExpBuffer(q); destroyPQExpBuffer(tbloids); destroyPQExpBuffer(checkoids); @@ -11731,6 +11842,8 @@ dumpDumpableObject(Archive *fout, DumpableObject *dobj) case DO_FK_CONSTRAINT: dumpConstraint(fout, (const ConstraintInfo *) dobj); break; + case DO_PERIOD: + break; case DO_PROCLANG: dumpProcLang(fout, (const ProcLangInfo *) dobj); break; @@ -17392,6 +17505,36 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo) } } + /* + * Add non-inherited PERIOD definitions, if any. + */ + for (j = 0; j < tbinfo->nperiod; j++) + { + PeriodInfo *period = &(tbinfo->periods[j]); + + char *name = pg_strdup(fmtId(period->dobj.name)); + char *start = pg_strdup(fmtId(period->perstart)); + char *end = pg_strdup(fmtId(period->perend)); + char *rngtype = pg_strdup(fmtId(period->rngtype)); + char *conname = pg_strdup(fmtId(period->conname)); + + if (actual_atts == 0) + appendPQExpBufferStr(q, " (\n "); + else + appendPQExpBufferStr(q, ",\n "); + + /* + * Always say colexists so we can just print the GENERATED + * column + */ + appendPQExpBuffer(q, "PERIOD FOR %s (%s, %s) " + "WITH (rangetype = %s, check_constraint_name = %s, colexists = true)", + name, start, end, + rngtype, conname); + + actual_atts++; + } + /* * Add non-inherited CHECK constraints, if any. * @@ -17400,7 +17543,7 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo) * PARTITION that we'll emit later expects the constraint to be * there. (No need to fix conislocal: ATTACH PARTITION does that) */ - for (j = 0; j < tbinfo->ncheck; j++) + for (j = 0; j < tbinfo->ncheck - tbinfo->nperiod; j++) { ConstraintInfo *constr = &(tbinfo->checkexprs[j]); @@ -17712,7 +17855,7 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo) */ resetPQExpBuffer(extra); firstitem = true; - for (k = 0; k < tbinfo->ncheck; k++) + for (k = 0; k < tbinfo->ncheck - tbinfo->nperiod; k++) { ConstraintInfo *constr = &(tbinfo->checkexprs[k]); @@ -18056,7 +18199,7 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo) } /* Dump comments on inlined table constraints */ - for (j = 0; j < tbinfo->ncheck; j++) + for (j = 0; j < tbinfo->ncheck - tbinfo->nperiod; j++) { ConstraintInfo *constr = &(tbinfo->checkexprs[j]); @@ -20180,6 +20323,7 @@ addBoundaryDependencies(DumpableObject **dobjs, int numObjs, case DO_TRIGGER: case DO_EVENT_TRIGGER: case DO_DEFAULT_ACL: + case DO_PERIOD: case DO_POLICY: case DO_PUBLICATION: case DO_PUBLICATION_REL: diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h index 72a00e1bc202..d376c87cd07a 100644 --- a/src/bin/pg_dump/pg_dump.h +++ b/src/bin/pg_dump/pg_dump.h @@ -60,6 +60,7 @@ typedef enum DO_TRIGGER, DO_CONSTRAINT, DO_FK_CONSTRAINT, /* see note for ConstraintInfo */ + DO_PERIOD, DO_PROCLANG, DO_CAST, DO_TABLE_DATA, @@ -322,12 +323,14 @@ typedef struct _tableInfo bool rowsec; /* is row security enabled? */ bool forcerowsec; /* is row security forced? */ bool hasoids; /* does it have OIDs? */ + bool hasperiods; /* does it have any periods? */ uint32 frozenxid; /* table's relfrozenxid */ uint32 minmxid; /* table's relminmxid */ Oid toast_oid; /* toast table's OID, or 0 if none */ uint32 toast_frozenxid; /* toast table's relfrozenxid, if any */ uint32 toast_minmxid; /* toast table's relminmxid */ int ncheck; /* # of CHECK expressions */ + int nperiod; /* # of PERIOD definitions */ Oid reltype; /* OID of table's composite type, if any */ Oid reloftype; /* underlying type for typed table */ Oid foreign_server; /* foreign server oid, if applicable */ @@ -358,6 +361,7 @@ typedef struct _tableInfo char *attstorage; /* attribute storage scheme */ char *typstorage; /* type storage scheme */ bool *attisdropped; /* true if attr is dropped; don't dump it */ + bool *attisperiod; /* true if attr is a PERIOD; don't dump it */ char *attidentity; char *attgenerated; int *attlen; /* attribute length, used by binary_upgrade */ @@ -379,6 +383,7 @@ typedef struct _tableInfo struct _attrDefInfo **attrdefs; /* DEFAULT expressions */ struct _constraintInfo *checkexprs; /* CHECK constraints */ struct _relStatsInfo *stats; /* only set for matviews */ + struct _periodInfo *periods; /* PERIOD definitions */ bool needs_override; /* has GENERATED ALWAYS AS IDENTITY */ char *amname; /* relation access method */ @@ -528,6 +533,16 @@ typedef struct _constraintInfo bool separate; /* true if must dump as separate item */ } ConstraintInfo; +typedef struct _periodInfo +{ + DumpableObject dobj; + TableInfo *pertable; + char *perstart; /* the name of the start column */ + char *perend; /* the name of the end column */ + char *rngtype; /* the name of the range type */ + char *conname; /* the name of the CHECK constraint */ +} PeriodInfo; + typedef struct _procLangInfo { DumpableObject dobj; diff --git a/src/bin/pg_dump/pg_dump_sort.c b/src/bin/pg_dump/pg_dump_sort.c index 164c76e08640..ebc20a226c7f 100644 --- a/src/bin/pg_dump/pg_dump_sort.c +++ b/src/bin/pg_dump/pg_dump_sort.c @@ -86,6 +86,7 @@ enum dbObjectTypePriorities PRIO_CONSTRAINT, PRIO_INDEX, PRIO_INDEX_ATTACH, + PRIO_PERIOD, PRIO_STATSEXT, PRIO_RULE, PRIO_TRIGGER, @@ -121,6 +122,7 @@ static const int dbObjectTypePriority[] = [DO_ATTRDEF] = PRIO_ATTRDEF, [DO_INDEX] = PRIO_INDEX, [DO_INDEX_ATTACH] = PRIO_INDEX_ATTACH, + [DO_PERIOD] = PRIO_PERIOD, [DO_STATSEXT] = PRIO_STATSEXT, [DO_RULE] = PRIO_RULE, [DO_TRIGGER] = PRIO_TRIGGER, @@ -454,6 +456,23 @@ DOTypeNameCompare(const void *p1, const void *p2) if (cmpval != 0) return cmpval; } + else if (obj1->objType == DO_PERIOD) + { + PeriodInfo *pobj1 = *(PeriodInfo *const *) p1; + PeriodInfo *pobj2 = *(PeriodInfo *const *) p2; + + /* Sort by table namespace . . . */ + cmpval = strcmp(pobj1->pertable->dobj.namespace->dobj.name, + pobj2->pertable->dobj.namespace->dobj.name); + if (cmpval != 0) + return cmpval; + + /* . . . and table name */ + cmpval = strcmp(pobj1->pertable->dobj.name, + pobj2->pertable->dobj.name); + if (cmpval != 0) + return cmpval; + } /* * Shouldn't get here except after catalog corruption, but if we do, sort @@ -1626,6 +1645,11 @@ describeDumpableObject(DumpableObject *obj, char *buf, int bufsize) "FK CONSTRAINT %s (ID %d OID %u)", obj->name, obj->dumpId, obj->catId.oid); return; + case DO_PERIOD: + snprintf(buf, bufsize, + "PERIOD %s (ID %d OID %u)", + obj->name, obj->dumpId, obj->catId.oid); + return; case DO_PROCLANG: snprintf(buf, bufsize, "PROCEDURAL LANGUAGE %s (ID %d OID %u)", diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c index 36f245028429..f35b0a9e3676 100644 --- a/src/bin/psql/describe.c +++ b/src/bin/psql/describe.c @@ -2024,6 +2024,8 @@ describeOneTableDetails(const char *schemaname, appendPQExpBufferStr(&buf, "\nFROM pg_catalog.pg_attribute a"); appendPQExpBuffer(&buf, "\nWHERE a.attrelid = '%s' AND a.attnum > 0 AND NOT a.attisdropped", oid); + if (pset.sversion >= 180000) + appendPQExpBuffer(&buf, "\nAND NOT EXISTS (SELECT 1 FROM pg_catalog.pg_period p WHERE p.perrelid = a.attrelid AND p.perrange = a.attnum)"); appendPQExpBufferStr(&buf, "\nORDER BY a.attnum;"); res = PSQLexec(buf.data); @@ -2452,6 +2454,40 @@ describeOneTableDetails(const char *schemaname, PGresult *result = NULL; int tuples = 0; + /* print periods */ + if (pset.sversion >= 180000) + { + printfPQExpBuffer(&buf, + "SELECT quote_ident(p.pername), quote_ident(s.attname) AS startatt, quote_ident(e.attname) AS endatt\n" + "FROM pg_period AS p\n" + "JOIN pg_attribute AS s ON (s.attrelid, s.attnum) = (p.perrelid, p.perstart)\n" + "JOIN pg_attribute AS e ON (e.attrelid, e.attnum) = (p.perrelid, p.perend)\n" + "WHERE p.perrelid = '%s'\n" + "ORDER BY 1;", + oid); + result = PSQLexec(buf.data); + if (!result) + goto error_return; + else + tuples = PQntuples(result); + + if (tuples > 0) + { + printTableAddFooter(&cont, _("Periods:")); + for (i = 0; i < tuples; i++) + { + /* untranslated constraint name and def */ + printfPQExpBuffer(&buf, " %s (%s, %s)", + PQgetvalue(result, i, 0), + PQgetvalue(result, i, 1), + PQgetvalue(result, i, 2)); + + printTableAddFooter(&cont, buf.data); + } + } + PQclear(result); + } + /* print indexes */ if (tableinfo.hasindex) { diff --git a/src/include/catalog/Makefile b/src/include/catalog/Makefile index 2bbc7805fe37..b9aee2ca49e5 100644 --- a/src/include/catalog/Makefile +++ b/src/include/catalog/Makefile @@ -65,6 +65,7 @@ CATALOG_HEADERS := \ pg_foreign_server.h \ pg_user_mapping.h \ pg_foreign_table.h \ + pg_period.h \ pg_policy.h \ pg_replication_origin.h \ pg_default_acl.h \ diff --git a/src/include/catalog/heap.h b/src/include/catalog/heap.h index dbd339e9df4f..3ec5a583d785 100644 --- a/src/include/catalog/heap.h +++ b/src/include/catalog/heap.h @@ -125,6 +125,10 @@ extern void StoreAttrMissingVal(Relation rel, AttrNumber attnum, Datum missingval); extern void SetAttrMissing(Oid relid, char *attname, char *value); +extern Oid StorePeriod(Relation rel, const char *period, + AttrNumber startnum, AttrNumber endnum, + AttrNumber rangenum, Oid conoid); + extern Node *cookDefault(ParseState *pstate, Node *raw_default, Oid atttypid, diff --git a/src/include/catalog/meson.build b/src/include/catalog/meson.build index ec1cf467f6fa..87cb4ce3300e 100644 --- a/src/include/catalog/meson.build +++ b/src/include/catalog/meson.build @@ -61,6 +61,7 @@ catalog_headers = [ 'pg_collation.h', 'pg_parameter_acl.h', 'pg_partitioned_table.h', + 'pg_period.h', 'pg_range.h', 'pg_transform.h', 'pg_sequence.h', diff --git a/src/include/catalog/pg_constraint.h b/src/include/catalog/pg_constraint.h index f8a01d896179..2f7f9a54c2e5 100644 --- a/src/include/catalog/pg_constraint.h +++ b/src/include/catalog/pg_constraint.h @@ -266,7 +266,8 @@ extern AttrNumber extractNotNullColumn(HeapTuple constrTup); extern bool AdjustNotNullInheritance(Oid relid, AttrNumber attnum, bool is_local, bool is_no_inherit, bool is_notvalid); extern List *RelationGetNotNullConstraints(Oid relid, bool cooked, - bool include_noinh); + bool include_noinh, + Bitmapset *excludes); extern void RemoveConstraintById(Oid conId); extern void RenameConstraintById(Oid conId, const char *newname); diff --git a/src/include/catalog/pg_index.h b/src/include/catalog/pg_index.h index 731d3938169e..890ff551176c 100644 --- a/src/include/catalog/pg_index.h +++ b/src/include/catalog/pg_index.h @@ -48,7 +48,6 @@ CATALOG(pg_index,2610,IndexRelationId) BKI_SCHEMA_MACRO /* variable-length fields start here, but we allow direct access to indkey */ int2vector indkey BKI_FORCE_NOT_NULL; /* column numbers of indexed cols, * or 0 */ - #ifdef CATALOG_VARLEN oidvector indcollation BKI_LOOKUP_OPT(pg_collation) BKI_FORCE_NOT_NULL; /* collation identifiers */ oidvector indclass BKI_LOOKUP(pg_opclass) BKI_FORCE_NOT_NULL; /* opclass identifiers */ diff --git a/src/include/catalog/pg_period.h b/src/include/catalog/pg_period.h new file mode 100644 index 000000000000..65a74dfa18bb --- /dev/null +++ b/src/include/catalog/pg_period.h @@ -0,0 +1,58 @@ +/*------------------------------------------------------------------------- + * + * pg_period.h + * definition of the "period" system catalog (pg_period) + * + * + * Portions Copyright (c) 1996-2021, PostgreSQL Global Development Group + * + * src/include/catalog/pg_period.h + * + * NOTES + * The Catalog.pm module reads this file and derives schema + * information. + * + *------------------------------------------------------------------------- + */ +#ifndef PG_PERIOD_H +#define PG_PERIOD_H + +#include "catalog/genbki.h" +#include "catalog/pg_period_d.h" +#include "nodes/bitmapset.h" + +/* ---------------- + * pg_period definition. cpp turns this into + * typedef struct FormData_pg_period + * ---------------- + */ +CATALOG(pg_period,8000,PeriodRelationId) +{ + Oid oid; /* OID of the period */ + NameData pername; /* name of period */ + Oid perrelid; /* OID of relation containing this period */ + int16 perstart; /* column for start value */ + int16 perend; /* column for end value */ + int16 perrange; /* column for range value */ + Oid perconstraint; /* OID of (start < end) constraint */ +} FormData_pg_period; + +/* ---------------- + * Form_pg_period corresponds to a pointer to a tuple with + * the format of pg_period relation. + * ---------------- + */ +typedef FormData_pg_period *Form_pg_period; + +DECLARE_UNIQUE_INDEX_PKEY(pg_period_oid_index, 8001, PeriodObjectIndexId, pg_period, btree(oid oid_ops)); +DECLARE_UNIQUE_INDEX(pg_period_perrelid_pername_index, 8002, PeriodRelidNameIndexId, pg_period, btree(perrelid oid_ops, pername name_ops)); + +MAKE_SYSCACHE(PERIODOID, pg_period_oid_index, 32); +MAKE_SYSCACHE(PERIODNAME, pg_period_perrelid_pername_index, 32); + +extern void RemovePeriodById(Oid periodId); + +extern Oid get_relation_period_oid(Oid relid, const char *pername, bool missing_ok); +extern Bitmapset *get_period_attnos(Oid relid); + +#endif /* PG_PERIOD_H */ diff --git a/src/include/catalog/pg_range.h b/src/include/catalog/pg_range.h index 3bba61627821..89e60d6cbf18 100644 --- a/src/include/catalog/pg_range.h +++ b/src/include/catalog/pg_range.h @@ -59,8 +59,10 @@ typedef FormData_pg_range *Form_pg_range; DECLARE_UNIQUE_INDEX_PKEY(pg_range_rngtypid_index, 3542, RangeTypidIndexId, pg_range, btree(rngtypid oid_ops)); DECLARE_UNIQUE_INDEX(pg_range_rngmultitypid_index, 2228, RangeMultirangeTypidIndexId, pg_range, btree(rngmultitypid oid_ops)); +DECLARE_UNIQUE_INDEX(pg_range_rngsubtype_rngtypid_index, 8003, RangeSubTypidTypidIndexId, pg_range, btree(rngsubtype oid_ops, rngtypid oid_ops)); MAKE_SYSCACHE(RANGETYPE, pg_range_rngtypid_index, 4); +MAKE_SYSCACHE(RANGESUBTYPE, pg_range_rngsubtype_rngtypid_index, 4); MAKE_SYSCACHE(RANGEMULTIRANGE, pg_range_rngmultitypid_index, 4); /* diff --git a/src/include/commands/tablecmds.h b/src/include/commands/tablecmds.h index e9b0fab0767b..bf8d6e331833 100644 --- a/src/include/commands/tablecmds.h +++ b/src/include/commands/tablecmds.h @@ -41,7 +41,8 @@ extern LOCKMODE AlterTableGetLockLevel(List *cmds); extern void ATExecChangeOwner(Oid relationOid, Oid newOwnerId, bool recursing, LOCKMODE lockmode); -extern void AlterTableInternal(Oid relid, List *cmds, bool recurse); +extern void AlterTableInternal(Oid relid, List *cmds, bool recurse, + struct AlterTableUtilityContext *context); extern Oid AlterTableMoveAll(AlterTableMoveAllStmt *stmt); @@ -107,5 +108,6 @@ extern void RangeVarCallbackOwnsRelation(const RangeVar *relation, Oid relId, Oid oldRelId, void *arg); extern bool PartConstraintImpliedByRelConstraint(Relation scanrel, List *partConstraint); +extern Oid choose_rangetype_for_period(PeriodDef *period); #endif /* TABLECMDS_H */ diff --git a/src/include/nodes/execnodes.h b/src/include/nodes/execnodes.h index acb3d5458a26..d3a598fbce30 100644 --- a/src/include/nodes/execnodes.h +++ b/src/include/nodes/execnodes.h @@ -465,6 +465,10 @@ typedef struct ForPortionOfState char *fp_rangeName; /* the column named in FOR PORTION OF */ Oid fp_rangeType; /* the type of the FOR PORTION OF expression */ int fp_rangeAttno; /* the attno of the range column */ + int fp_periodStartAttno; /* the attno of the PERIOD start + * column (or 0 for a range) */ + int fp_periodEndAttno; /* the attno of the PERIOD end column (or + * 0 for a range) */ Datum fp_targetRange; /* the range/multirange from FOR PORTION OF */ TypeCacheEntry *fp_leftoverstypcache; /* type cache entry of the range */ TupleTableSlot *fp_Existing; /* slot to store old tuple */ diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h index a09e9d9ba6ac..3785be6f85d7 100644 --- a/src/include/nodes/parsenodes.h +++ b/src/include/nodes/parsenodes.h @@ -2370,6 +2370,7 @@ typedef enum ObjectType OBJECT_OPERATOR, OBJECT_OPFAMILY, OBJECT_PARAMETER_ACL, + OBJECT_PERIOD, OBJECT_POLICY, OBJECT_PROCEDURE, OBJECT_PUBLICATION, @@ -2457,6 +2458,8 @@ typedef enum AlterTableType AT_ValidateConstraint, /* validate constraint */ AT_AddIndexConstraint, /* add constraint using existing index */ AT_DropConstraint, /* drop constraint */ + AT_AddPeriod, /* ADD PERIOD */ + AT_DropPeriod, /* DROP PERIOD */ AT_ReAddComment, /* internal to commands/tablecmds.c */ AT_AlterColumnType, /* alter column type */ AT_AlterColumnGenericOptions, /* alter column OPTIONS (...) */ @@ -2756,11 +2759,12 @@ typedef struct VariableShowStmt /* ---------------------- * Create Table Statement * - * NOTE: in the raw gram.y output, ColumnDef and Constraint nodes are - * intermixed in tableElts, and constraints and nnconstraints are NIL. After + * NOTE: in the raw gram.y output, ColumnDef, PeriodDef, and Constraint nodes are + * intermixed in tableElts; constraints, nnconstraints, and periods are NIL. After * parse analysis, tableElts contains just ColumnDefs, nnconstraints contains - * Constraint nodes of CONSTR_NOTNULL type from various sources, and - * constraints contains just CONSTR_CHECK Constraint nodes. + * Constraint nodes of CONSTR_NOTNULL type from various sources, constraints + * contains just CONSTR_CHECK Constraint nodes, and periods contains just + * PeriodDefs. * ---------------------- */ @@ -2769,6 +2773,7 @@ typedef struct CreateStmt NodeTag type; RangeVar *relation; /* relation to create */ List *tableElts; /* column definitions (list of ColumnDef) */ + List *periods; /* periods (list of PeriodDef nodes) */ List *inhRelations; /* relations to inherit from (list of * RangeVar) */ PartitionBoundSpec *partbound; /* FOR VALUES clause */ @@ -2783,6 +2788,31 @@ typedef struct CreateStmt bool if_not_exists; /* just do nothing if it already exists? */ } CreateStmt; + +/* ---------- + * Definitions for periods in CreateStmt + * ---------- + */ + +typedef struct PeriodDef +{ + NodeTag type; + Oid oid; /* period oid, once it's transformed */ + char *periodname; /* period name */ + char *startcolname; /* name of start column */ + char *endcolname; /* name of end column */ + AttrNumber startattnum; /* attnum of the start column */ + AttrNumber endattnum; /* attnum of the end column */ + AttrNumber rngattnum; /* attnum of the GENERATED range column */ + List *options; /* options from WITH clause */ + char *constraintname; /* name of the CHECK constraint */ + char *rangetypename; /* name of the range type */ + Oid coltypid; /* the start/end col type */ + Oid rngtypid; /* the range type to use */ + bool colexists; /* use an existing GENERATED column */ + int location; /* token location, or -1 if unknown */ +} PeriodDef; + /* ---------- * Definitions for constraints in CreateStmt * @@ -3509,6 +3539,7 @@ typedef struct IndexStmt List *indexParams; /* columns to index: a list of IndexElem */ List *indexIncludingParams; /* additional columns to index: a list * of IndexElem */ + PeriodDef *period; /* The period included in the index */ List *options; /* WITH clause options: a list of DefElem */ Node *whereClause; /* qualification (partial-index predicate) */ List *excludeOpNames; /* exclusion operator names, or NIL if none */ diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h index fbbcd77dd843..93d06efe0cea 100644 --- a/src/include/nodes/primnodes.h +++ b/src/include/nodes/primnodes.h @@ -2403,6 +2403,8 @@ typedef struct ForPortionOfExpr { NodeTag type; Var *rangeVar; /* Range column */ + Var *startVar; /* Start column if PERIOD */ + Var *endVar; /* End column if PERIOD */ char *range_name; /* Range name */ Node *targetRange; /* FOR PORTION OF bounds as a range */ Oid rangeType; /* type of targetRange */ diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h index a8def3a386c1..cfc2f68ca8ae 100644 --- a/src/include/parser/kwlist.h +++ b/src/include/parser/kwlist.h @@ -341,7 +341,7 @@ PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL) -PG_KEYWORD("period", PERIOD, UNRESERVED_KEYWORD, BARE_LABEL) +PG_KEYWORD("period", PERIOD, RESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL) diff --git a/src/include/parser/parse_utilcmd.h b/src/include/parser/parse_utilcmd.h index 4965fac4495e..d0d23af3d41b 100644 --- a/src/include/parser/parse_utilcmd.h +++ b/src/include/parser/parse_utilcmd.h @@ -40,5 +40,6 @@ extern IndexStmt *generateClonedIndexStmt(RangeVar *heapRel, Relation source_idx, const AttrMap *attmap, Oid *constraintOid); +extern void transformPeriodOptions(PeriodDef *period); #endif /* PARSE_UTILCMD_H */ diff --git a/src/include/utils/lsyscache.h b/src/include/utils/lsyscache.h index 5b50ef230ab1..eddca997efb2 100644 --- a/src/include/utils/lsyscache.h +++ b/src/include/utils/lsyscache.h @@ -98,6 +98,8 @@ extern Oid get_atttype(Oid relid, AttrNumber attnum); extern void get_atttypetypmodcoll(Oid relid, AttrNumber attnum, Oid *typid, int32 *typmod, Oid *collid); extern Datum get_attoptions(Oid relid, int16 attnum); +extern char *get_periodname(Oid periodid, bool missing_ok); +extern Oid get_period_oid(Oid relid, const char *periodname, bool missing_ok); extern Oid get_cast_oid(Oid sourcetypeid, Oid targettypeid, bool missing_ok); extern char *get_collation_name(Oid colloid); extern bool get_collation_isdeterministic(Oid colloid); @@ -203,6 +205,7 @@ extern Oid get_range_subtype(Oid rangeOid); extern Oid get_range_collation(Oid rangeOid); extern Oid get_range_multirange(Oid rangeOid); extern Oid get_multirange_range(Oid multirangeOid); +extern Oid get_subtype_range(Oid subtypeOid); extern Oid get_index_column_opclass(Oid index_oid, int attno); extern bool get_index_isreplident(Oid index_oid); extern bool get_index_isvalid(Oid index_oid); diff --git a/src/include/utils/period.h b/src/include/utils/period.h new file mode 100644 index 000000000000..d02c17036fd0 --- /dev/null +++ b/src/include/utils/period.h @@ -0,0 +1,21 @@ +/*------------------------------------------------------------------------- + * + * period.h + * support for Postgres periods. + * + * + * Portions Copyright (c) 1996-2022, PostgreSQL Global Development Group + * Portions Copyright (c) 1994, Regents of the University of California + * + * src/include/utils/period.h + * + *------------------------------------------------------------------------- + */ +#ifndef PERIOD_H +#define PERIOD_H + +#include "executor/tuptable.h" + +extern Datum period_to_range(TupleTableSlot *slot, int startattno, int endattno, Oid rangetype); + +#endif /* PERIOD_H */ diff --git a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c index 193669f2bc1e..9ed429fdadd9 100644 --- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c +++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c @@ -179,6 +179,12 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS) case AT_DropConstraint: strtype = "DROP CONSTRAINT"; break; + case AT_AddPeriod: + strtype = "ADD PERIOD"; + break; + case AT_DropPeriod: + strtype = "DROP PERIOD"; + break; case AT_ReAddComment: strtype = "(re) ADD COMMENT"; break; diff --git a/src/test/regress/expected/for_portion_of.out b/src/test/regress/expected/for_portion_of.out index 52fb044d2e58..c0d0de7e8101 100644 --- a/src/test/regress/expected/for_portion_of.out +++ b/src/test/regress/expected/for_portion_of.out @@ -1100,6 +1100,64 @@ SELECT * FROM for_portion_of_test2 ORDER BY id, valid_at; [3,4) | {[2018-01-01,)} | three (6 rows) +DROP TABLE for_portion_of_test2; +-- Test with PERIODs +CREATE TABLE for_portion_of_test2 ( + id int4range NOT NULL, + valid_from date, + valid_til date, + name text NOT NULL, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT for_portion_of_test2_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +INSERT INTO for_portion_of_test2 +VALUES +('[1,2)', '2018-01-02', '2018-02-03', 'one'), +('[1,2)', '2018-02-04', '2018-03-03', 'one'), +('[1,2)', '2018-03-03', '2018-04-04', 'one'), +('[2,3)', '2018-01-01', '2018-05-01', 'two'), +('[3,4)', '2018-01-01', null, 'three'); +; +UPDATE for_portion_of_test2 +FOR PORTION OF valid_at FROM '2018-01-10' TO '2018-02-10' +SET name = 'one^1' +WHERE id = '[1,2)'; +DELETE FROM for_portion_of_test2 +FOR PORTION OF valid_at FROM '2018-01-15' TO '2018-02-15' +WHERE id = '[2,3)'; +-- Setting the start column fails: +UPDATE for_portion_of_test2 +FOR PORTION OF valid_at FROM '2018-01-10' TO '2018-02-10' +SET valid_from = '2018-02-01' +WHERE id = '[1,2)'; +ERROR: multiple assignments to same column "valid_from" +-- Setting the end column fails: +UPDATE for_portion_of_test2 +FOR PORTION OF valid_at FROM '2018-01-10' TO '2018-02-10' +SET valid_til = '2018-02-01' +WHERE id = '[1,2)'; +ERROR: multiple assignments to same column "valid_til" +-- Setting the generated column fails: +UPDATE for_portion_of_test2 +FOR PORTION OF valid_at FROM '2018-01-10' TO '2018-02-10' +SET valid_at = '[2018-02-01,2018-02-03)' +WHERE id = '[1,2)'; +ERROR: can't directly assign to "valid_at" in a FOR PORTION OF update +LINE 3: SET valid_at = '[2018-02-01,2018-02-03)' + ^ +SELECT * FROM for_portion_of_test2 ORDER BY id, valid_at; + id | valid_from | valid_til | name +-------+------------+------------+------- + [1,2) | 2018-01-02 | 2018-01-10 | one + [1,2) | 2018-01-10 | 2018-02-03 | one^1 + [1,2) | 2018-02-04 | 2018-02-10 | one^1 + [1,2) | 2018-02-10 | 2018-03-03 | one + [1,2) | 2018-03-03 | 2018-04-04 | one + [2,3) | 2018-01-01 | 2018-01-15 | two + [2,3) | 2018-02-15 | 2018-05-01 | two + [3,4) | 2018-01-01 | | three +(8 rows) + DROP TABLE for_portion_of_test2; -- Test with a custom range type CREATE TYPE mydaterange AS range(subtype=date); diff --git a/src/test/regress/expected/periods.out b/src/test/regress/expected/periods.out new file mode 100644 index 000000000000..d429097600a5 --- /dev/null +++ b/src/test/regress/expected/periods.out @@ -0,0 +1,318 @@ +/* System periods are not implemented */ +create table pt (id integer, ds date, de date, period for system_time (ds, de)); +ERROR: PERIOD FOR SYSTEM_TIME is not supported +LINE 2: create table pt (id integer, ds date, de date, period for sy... + ^ +/* Periods must specify actual columns */ +create table pt (id integer, ds date, de date, period for p (bogus, de)); +ERROR: column "bogus" of relation "pt" does not exist +create table pt (id integer, ds date, de date, period for p (ds, bogus)); +ERROR: column "bogus" of relation "pt" does not exist +/* Data types must match exactly */ +create table pt (id integer, ds date, de timestamp, period for p (ds, de)); +ERROR: start and end columns of period must be of same type +create table pt (id integer, ds text collate "C", de text collate "POSIX", period for p (ds, de)); +ERROR: start and end columns of period must have same collation +/* Periods must have a default BTree operator class */ +create table pt (id integer, ds xml, de xml, period for p (ds, de)); +ERROR: no range type for xml found for period p +HINT: You can define a custom range type with CREATE TYPE +/* Period and column names are in the same namespace */ +create table pt (id integer, ds date, de date, period for ctid (ds, de)); +ERROR: period name "ctid" conflicts with a system column name +create table pt (id integer, ds date, de date, period for id (ds, de)); +ERROR: period name "id" conflicts with a column name +/* Period name can't be given more than once */ +create table pt (id integer, ds date, de date, period for p (ds, de), period for p (ds, de)); +ERROR: period name "p" specified more than once +/* Period can't use the same colum for start and end*/ +create table pt (id integer, ds date, de date, period for p (ds, ds)); +ERROR: column "ds" can't be the start and end column for period "p" +/* Now make one that works */ +create table pt (id integer, ds date, de date, period for p (ds, de)); +/* Its generated column looks good */ +select attname, atttypid::regtype, attnotnull, attgenerated from pg_attribute where attrelid = 'pt'::regclass and attname = 'p'; + attname | atttypid | attnotnull | attgenerated +---------+-----------+------------+-------------- + p | daterange | t | s +(1 row) + +select conname, contype from pg_constraint where conrelid = 'pt'::regclass order by conname; + conname | contype +---------------+--------- + pt_p_check | c + pt_p_not_null | n +(2 rows) + +/* It appears in the information_schema */ +select * from information_schema.periods; + table_catalog | table_schema | table_name | period_name | start_column_name | end_column_name +---------------+--------------+------------+-------------+-------------------+----------------- + regression | public | pt | p | ds | de +(1 row) + +/* SELECT * excludes the PERIOD */ +insert into pt values (1, '2000-01-01', '2001-01-01'); +select * from pt; + id | ds | de +----+------------+------------ + 1 | 01-01-2000 | 01-01-2001 +(1 row) + +/* You can get it if you want */ +select *, p from pt; + id | ds | de | p +----+------------+------------+------------------------- + 1 | 01-01-2000 | 01-01-2001 | [01-01-2000,01-01-2001) +(1 row) + +/* You can comment on it */ +comment on period pt.p is 'test comment'; +select obj_description((select oid from pg_period where perrelid = 'pt'::regclass and pername = 'p'), 'pg_period'); + obj_description +----------------- + test comment +(1 row) + +/* Two are okay */ +create table pt2 (id integer, ds date, de date, period for p1 (ds, de), period for p2 (ds, de)); +drop table pt2; +/* Skip creating GENERATED column: works */ +create table pt2 (id integer, ds date, de date, p daterange not null generated always as (daterange(ds, de)) stored, period for p (ds, de) with (colexists = true)); +\d pt2 + Table "public.pt2" + Column | Type | Collation | Nullable | Default +--------+---------+-----------+----------+--------- + id | integer | | | + ds | date | | | + de | date | | | +Periods: + p (ds, de) +Check constraints: + "pt2_p_check" CHECK (ds < de) + +drop table pt2; +/* Skip creating GENERATED column: fails because the col isn't there */ +create table pt2 (id integer, ds date, de date, period for p (ds, de) with (colexists = true)); +ERROR: No column found with name p +/* Skip creating GENERATED column: fails because the option has an invalid value */ +create table pt2 (id integer, ds date, de date, period for p (ds, de) with (colexists = 'whatever')); +ERROR: colexists requires a Boolean value +/* Skip creating GENERATED column: fails because the column is not NOT NULL */ +create table pt2 (id integer, ds date, de date, p daterange generated always as (daterange(ds, de)) stored, period for p (ds, de) with (colexists = true)); +ERROR: Period p uses a generated column that allows nulls +/* Skip creating GENERATED column: fails because the column is not GENERATED */ +create table pt2 (id integer, ds date, de date, p daterange not null, period for p (ds, de) with (colexists = true)); +ERROR: Period p uses a non-generated column +/* Skip creating GENERATED column: fails because the column is GENERATED but with the wrong expression */ +-- TODO: +-- create table pt2 (id integer, ds date, de date, p daterange not null generated always as (daterange(de, ds)) stored, period for p (ds, de) with (colexists = true)); +/* Skip creating GENERATED column: fails because the column is the wrong type */ +create table pt2 (id integer, ds date, de date, p tsrange not null generated always as (tsrange(ds, de)) stored, period for p (ds, de) with (colexists = true)); +ERROR: Period p uses a generated column with the wrong type +/* Skip creating GENERATED column: fails because the column is inherited */ +create table pt2parent (id integer, ds date, de date, p daterange not null generated always as (daterange(ds, de)) stored); +create table pt2 (period for p (ds, de) with (colexists = true)) inherits (pt2parent); +ERROR: Inheriting is not supported when a table has a PERIOD +drop table pt2parent; +/* + * ALTER TABLE tests + */ +alter table pt drop period for p; +alter table pt add period for system_time (ds, de); +ERROR: PERIOD FOR SYSTEM_TIME is not supported +alter table pt add period for p (ds, de); +/* Its generated column looks good */ +select attname, atttypid::regtype, attnotnull, attgenerated from pg_attribute where attrelid = 'pt'::regclass and attname = 'p'; + attname | atttypid | attnotnull | attgenerated +---------+-----------+------------+-------------- + p | daterange | t | s +(1 row) + +select conname, contype from pg_constraint where conrelid = 'pt'::regclass order by conname; + conname | contype +---------------+--------- + pt_p_check | c + pt_p_not_null | n +(2 rows) + +/* Adding a second one */ +create table pt2 (id integer, ds date, de date, period for p1 (ds, de)); +alter table pt2 add period for p2 (ds, de); +drop table pt2; +/* Can't drop its columns */ +alter table pt drop column ds; +ERROR: cannot drop column ds of table pt because other objects depend on it +DETAIL: period p on table pt depends on column ds of table pt +HINT: Use DROP ... CASCADE to drop the dependent objects too. +alter table pt drop column de; +ERROR: cannot drop column de of table pt because other objects depend on it +DETAIL: period p on table pt depends on column de of table pt +HINT: Use DROP ... CASCADE to drop the dependent objects too. +/* Can't change the data types */ +alter table pt alter column ds type timestamp; +ERROR: cannot alter type of a column used by a period +DETAIL: period p on table pt depends on column "ds" +alter table pt alter column ds type timestamp; +ERROR: cannot alter type of a column used by a period +DETAIL: period p on table pt depends on column "ds" +/* column/period namespace conflicts */ +alter table pt add column p integer; +ERROR: column name "p" conflicts with a period name +alter table pt rename column id to p; +ERROR: column name "p" conflicts with a period name +alter table pt add period for tableoid (ds, de); +ERROR: period name "tableoid" conflicts with a system column name +alter table pt add period for "........pg.dropped.4........" (ds, de); +ERROR: period name "........pg.dropped.4........" conflicts with a column name +/* adding columns and the period at the same time */ +create table pt2 (id integer); +alter table pt2 add column ds date, add column de date, add period for p (ds, de); +drop table pt2; +/* Ambiguous range types raise an error */ +create type mydaterange as range(subtype=date); +create table pt2 (id int, ds date, de date, period for p (ds, de)); +ERROR: ambiguous range for type date +/* You can give an explicit range type */ +create table pt2 (id int, ds date, de date, period for p (ds, de) with (rangetype = 'mydaterange')); +drop type mydaterange; +ERROR: cannot drop type mydaterange because other objects depend on it +DETAIL: period p on table pt2 depends on type mydaterange +HINT: Use DROP ... CASCADE to drop the dependent objects too. +drop type mydaterange cascade; +NOTICE: drop cascades to period p on table pt2 +drop table pt2; +create table pt2 (id int, ds date, de date, period for p (ds, de) with (rangetype = 'daterange')); +/* Range type is not found */ +create table pt3 (id int, ds date, de date, period for p (ds, de) with (rangetype = 'notarange')); +ERROR: Range type notarange not found +/* Range type is the wrong type */ +create table pt3 (id int, ds date, de date, period for p (ds, de) with (rangetype = 'tstzrange')); +ERROR: Range type tstzrange does not match column type date +drop table pt2; +/* Period can't use the same colum for start and end*/ +create table pt2 (id integer, ds date, de date); +alter table pt2 add period for p (ds, ds); +ERROR: column "ds" can't be the start and end column for period "p" +drop table pt2; +/* Skip creating GENERATED column: works */ +create table pt2 (id integer, ds date, de date, p daterange not null generated always as (daterange(ds, de)) stored); +alter table pt2 add period for p (ds, de) with (colexists = true); +\d pt2 + Table "public.pt2" + Column | Type | Collation | Nullable | Default +--------+---------+-----------+----------+--------- + id | integer | | | + ds | date | | | + de | date | | | +Periods: + p (ds, de) +Check constraints: + "pt2_p_check" CHECK (ds < de) + +drop table pt2; +/* Skip creating GENERATED column: fails because the col isn't there */ +create table pt2 (id integer, ds date, de date); +alter table pt2 add period for p (ds, de) with (colexists = true); +ERROR: column "p" of relation "pt2" does not exist +drop table pt2; +/* Skip creating GENERATED column: fails because the option has an invalid value */ +create table pt2 (id integer, ds date, de date, p daterange not null generated always as (daterange(ds, de)) stored); +alter table pt2 add period for p (ds, de) with (colexists = 'whatever'); +ERROR: colexists requires a Boolean value +drop table pt2; +/* Skip creating GENERATED column: fails because the column is not NOT NULL */ +create table pt2 (id integer, ds date, de date, p daterange generated always as (daterange(ds, de)) stored); +alter table pt2 add period for p (ds, de) with (colexists = true); +ERROR: Period p uses a generated column that allows nulls +drop table pt2; +/* Skip creating GENERATED column: fails because the column is not GENERATED */ +create table pt2 (id integer, ds date, de date, p daterange not null); +alter table pt2 add period for p (ds, de) with (colexists = true); +ERROR: Period p uses a non-generated column +drop table pt2; +/* Skip creating GENERATED column: fails because the column is GENERATED but with the wrong expression */ +-- TODO: +-- create table pt2 (id integer, ds date, de date, p daterange not null generated always as (daterange(de, ds)) stored); +-- alter table pt2 add period for p (ds, de) with (colexists = true); +/* Skip creating GENERATED column: fails because the column is the wrong type */ +create table pt2 (id integer, ds date, de date, p tsrange not null generated always as (tsrange(ds, de)) stored); +alter table pt2 add period for p (ds, de) with (colexists = true); +ERROR: Period p uses a generated column with the wrong type +drop table pt2; +/* Skip creating GENERATED column: fails because the column is inherited */ +create table pt2parent (id integer, ds date, de date, p daterange not null generated always as (daterange(ds, de)) stored); +create table pt2 () inherits (pt2parent); +alter table pt2 add period for p (ds, de) with (colexists = true); +ERROR: Period p uses a generated column that is inherited +drop table pt2; +drop table pt2parent; +/* CREATE TABLE (LIKE ...) */ +/* Periods are not copied by LIKE, so their columns aren't either */ +create table pt2 (like pt); +\d pt2 + Table "public.pt2" + Column | Type | Collation | Nullable | Default +--------+---------+-----------+----------+--------- + id | integer | | | + ds | date | | | + de | date | | | + +drop table pt2; +/* Can add a period referring to LIKE'd columns */ +create table not_p (id integer, ds date, de date); +create table pt2 (like not_p, period for p (ds, de)); +\d pt2 + Table "public.pt2" + Column | Type | Collation | Nullable | Default +--------+---------+-----------+----------+--------- + id | integer | | | + ds | date | | | + de | date | | | +Periods: + p (ds, de) +Check constraints: + "pt2_p_check" CHECK (ds < de) + +drop table pt2; +/* Can add a period with the same name */ +create table pt2 (like pt, period for p (ds, de)); +\d pt2 + Table "public.pt2" + Column | Type | Collation | Nullable | Default +--------+---------+-----------+----------+--------- + id | integer | | | + ds | date | | | + de | date | | | +Periods: + p (ds, de) +Check constraints: + "pt2_p_check" CHECK (ds < de) + +drop table pt2; +/* Can add a period with a different name */ +create table pt2 (like pt, period for p2 (ds, de)); +\d pt2 + Table "public.pt2" + Column | Type | Collation | Nullable | Default +--------+---------+-----------+----------+--------- + id | integer | | | + ds | date | | | + de | date | | | +Periods: + p2 (ds, de) +Check constraints: + "pt2_p2_check" CHECK (ds < de) + +drop table pt2; +/* Can't add a period whose name conflicts with a LIKE'd column */ +create table pt2 (like pt, period for id (ds, de)); +ERROR: period name "id" conflicts with a column name +/* CREATE TALBE INHERITS */ +/* Can't inherit from a table with a period */ +create table pt2 (name text) inherits (pt); +ERROR: Inheriting from a table with a PERIOD is not supported +/* Can't inherit with a period */ +create table pt2 (d2s date, d2e date, period for p (d2s, d2e)) inherits (not_p); +ERROR: Inheriting is not supported when a table has a PERIOD +drop table not_p; diff --git a/src/test/regress/expected/privileges.out b/src/test/regress/expected/privileges.out index 9ff8e7fb363d..4f577218cdfd 100644 --- a/src/test/regress/expected/privileges.out +++ b/src/test/regress/expected/privileges.out @@ -1137,6 +1137,35 @@ SET SESSION AUTHORIZATION regress_priv_user3; UPDATE t1 FOR PORTION OF valid_at FROM '2000-01-01' TO '2001-01-01' SET c1 = '[2,3)'; SET SESSION AUTHORIZATION regress_priv_user1; DROP TABLE t1; +-- test column-level privileges on the PERIOD used in FOR PORTION OF +SET SESSION AUTHORIZATION regress_priv_user1; +CREATE TABLE t1 ( + c1 int4range, + valid_from timestamp, + valid_til timestamp, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT t1pk PRIMARY KEY (c1, valid_at WITHOUT OVERLAPS) +); +GRANT SELECT ON t1 TO regress_priv_user2; +GRANT SELECT ON t1 TO regress_priv_user3; +GRANT SELECT ON t1 TO regress_priv_user4; +GRANT SELECT ON t1 TO regress_priv_user5; +GRANT UPDATE (c1) ON t1 TO regress_priv_user2; +GRANT UPDATE (c1, valid_at) ON t1 TO regress_priv_user3; +GRANT UPDATE (c1, valid_from, valid_til) ON t1 TO regress_priv_user4; +GRANT UPDATE (c1, valid_from, valid_til, valid_at) ON t1 TO regress_priv_user5; +SET SESSION AUTHORIZATION regress_priv_user2; +UPDATE t1 FOR PORTION OF valid_at FROM '2000-01-01' TO '2001-01-01' SET c1 = '[2,3)'; +ERROR: permission denied for table t1 +SET SESSION AUTHORIZATION regress_priv_user3; +UPDATE t1 FOR PORTION OF valid_at FROM '2000-01-01' TO '2001-01-01' SET c1 = '[2,3)'; +ERROR: permission denied for table t1 +SET SESSION AUTHORIZATION regress_priv_user4; +UPDATE t1 FOR PORTION OF valid_at FROM '2000-01-01' TO '2001-01-01' SET c1 = '[2,3)'; +SET SESSION AUTHORIZATION regress_priv_user5; +UPDATE t1 FOR PORTION OF valid_at FROM '2000-01-01' TO '2001-01-01' SET c1 = '[2,3)'; +SET SESSION AUTHORIZATION regress_priv_user1; +DROP TABLE t1; -- test column-level privileges when involved with DELETE SET SESSION AUTHORIZATION regress_priv_user1; ALTER TABLE atest6 ADD COLUMN three integer; diff --git a/src/test/regress/expected/without_overlaps.out b/src/test/regress/expected/without_overlaps.out index 4d9f25ac405a..e545d0e33d4e 100644 --- a/src/test/regress/expected/without_overlaps.out +++ b/src/test/regress/expected/without_overlaps.out @@ -153,6 +153,76 @@ SELECT pg_get_indexdef(conindid, 0, true) FROM pg_constraint WHERE conname = 'te CREATE UNIQUE INDEX temporal_rng2_pk ON temporal_rng2 USING gist (id1, id2, valid_at) (1 row) +-- PK with one column plus a PERIOD: +CREATE TABLE temporal_per ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +\d temporal_per + Table "public.temporal_per" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | not null | + valid_from | date | | | + valid_til | date | | | +Periods: + valid_at (valid_from, valid_til) +Indexes: + "temporal_per_pk" PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +Check constraints: + "temporal_per_valid_at_check" CHECK (valid_from < valid_til) + +SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_per_pk'; + pg_get_constraintdef +--------------------------------------------- + PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +(1 row) + +SELECT pg_get_indexdef(conindid, 0, true) FROM pg_constraint WHERE conname = 'temporal_per_pk'; + pg_get_indexdef +------------------------------------------------------------------------------- + CREATE UNIQUE INDEX temporal_per_pk ON temporal_per USING gist (id, valid_at) +(1 row) + +-- PK with two columns plus a PERIOD: +CREATE TABLE temporal_per2 ( + id1 int4range, + id2 int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_per2_pk PRIMARY KEY (id1, id2, valid_at WITHOUT OVERLAPS) +); +\d temporal_per2 + Table "public.temporal_per2" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id1 | int4range | | not null | + id2 | int4range | | not null | + valid_from | date | | | + valid_til | date | | | +Periods: + valid_at (valid_from, valid_til) +Indexes: + "temporal_per2_pk" PRIMARY KEY (id1, id2, valid_at WITHOUT OVERLAPS) +Check constraints: + "temporal_per2_valid_at_check" CHECK (valid_from < valid_til) + +SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_per2_pk'; + pg_get_constraintdef +--------------------------------------------------- + PRIMARY KEY (id1, id2, valid_at WITHOUT OVERLAPS) +(1 row) + +SELECT pg_get_indexdef(conindid, 0, true) FROM pg_constraint WHERE conname = 'temporal_per2_pk'; + pg_get_indexdef +--------------------------------------------------------------------------------------- + CREATE UNIQUE INDEX temporal_per2_pk ON temporal_per2 USING gist (id1, id2, valid_at) +(1 row) + -- PK with a custom range type: CREATE TYPE textrange2 AS range (subtype=text, collation="C"); CREATE TABLE temporal_rng3 ( @@ -300,6 +370,78 @@ SELECT pg_get_indexdef(conindid, 0, true) FROM pg_constraint WHERE conname = 'te (1 row) DROP TABLE temporal_rng3; +-- UNIQUE with one column plus a PERIOD: +CREATE TABLE temporal_per3 ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_per3_uq UNIQUE (id, valid_at WITHOUT OVERLAPS) +); +\d temporal_per3 + Table "public.temporal_per3" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | | + valid_from | date | | | + valid_til | date | | | +Periods: + valid_at (valid_from, valid_til) +Indexes: + "temporal_per3_uq" UNIQUE (id, valid_at WITHOUT OVERLAPS) +Check constraints: + "temporal_per3_valid_at_check" CHECK (valid_from < valid_til) + +SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_per3_uq'; + pg_get_constraintdef +---------------------------------------- + UNIQUE (id, valid_at WITHOUT OVERLAPS) +(1 row) + +SELECT pg_get_indexdef(conindid, 0, true) FROM pg_constraint WHERE conname = 'temporal_per3_uq'; + pg_get_indexdef +--------------------------------------------------------------------------------- + CREATE UNIQUE INDEX temporal_per3_uq ON temporal_per3 USING gist (id, valid_at) +(1 row) + +DROP TABLE temporal_per3; +-- UNIQUE with two columns plus a PERIOD: +CREATE TABLE temporal_per3 ( + id1 int4range, + id2 int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_per3_uq UNIQUE (id1, id2, valid_at WITHOUT OVERLAPS) +); +\d temporal_per3 + Table "public.temporal_per3" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id1 | int4range | | | + id2 | int4range | | | + valid_from | date | | | + valid_til | date | | | +Periods: + valid_at (valid_from, valid_til) +Indexes: + "temporal_per3_uq" UNIQUE (id1, id2, valid_at WITHOUT OVERLAPS) +Check constraints: + "temporal_per3_valid_at_check" CHECK (valid_from < valid_til) + +SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_per3_uq'; + pg_get_constraintdef +---------------------------------------------- + UNIQUE (id1, id2, valid_at WITHOUT OVERLAPS) +(1 row) + +SELECT pg_get_indexdef(conindid, 0, true) FROM pg_constraint WHERE conname = 'temporal_per3_uq'; + pg_get_indexdef +--------------------------------------------------------------------------------------- + CREATE UNIQUE INDEX temporal_per3_uq ON temporal_per3 USING gist (id1, id2, valid_at) +(1 row) + +DROP TABLE temporal_per3; -- UNIQUE with a custom range type: CREATE TYPE textrange2 AS range (subtype=text, collation="C"); CREATE TABLE temporal_rng3 ( @@ -377,6 +519,106 @@ ALTER TABLE temporal3 ADD CONSTRAINT temporal3_uq UNIQUE (id, valid_at WITHOUT OVERLAPS); DROP TABLE temporal3; +-- PRIMARY KEY with PERIOD already there +CREATE TABLE temporal3 ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til) +); +ALTER TABLE temporal3 + ADD CONSTRAINT temporal3_pk + PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); +\d temporal3 + Table "public.temporal3" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | not null | + valid_from | date | | | + valid_til | date | | | +Periods: + valid_at (valid_from, valid_til) +Indexes: + "temporal3_pk" PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +Check constraints: + "temporal3_valid_at_check" CHECK (valid_from < valid_til) + +DROP TABLE temporal3; +-- PRIMARY KEY with PERIOD too +CREATE TABLE temporal3 ( + id int4range, + valid_from date, + valid_til date +); +ALTER TABLE temporal3 + ADD PERIOD FOR valid_at (valid_from, valid_til), + ADD CONSTRAINT temporal3_pk + PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); +\d temporal3 + Table "public.temporal3" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | not null | + valid_from | date | | | + valid_til | date | | | +Periods: + valid_at (valid_from, valid_til) +Indexes: + "temporal3_pk" PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +Check constraints: + "temporal3_valid_at_check" CHECK (valid_from < valid_til) + +DROP TABLE temporal3; +-- UNIQUE with PERIOD already there +CREATE TABLE temporal3 ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til) +); +ALTER TABLE temporal3 + ADD CONSTRAINT temporal3_uq + UNIQUE (id, valid_at WITHOUT OVERLAPS); +\d temporal3 + Table "public.temporal3" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | | + valid_from | date | | | + valid_til | date | | | +Periods: + valid_at (valid_from, valid_til) +Indexes: + "temporal3_uq" UNIQUE (id, valid_at WITHOUT OVERLAPS) +Check constraints: + "temporal3_valid_at_check" CHECK (valid_from < valid_til) + +DROP TABLE temporal3; +-- UNIQUE with PERIOD too +CREATE TABLE temporal3 ( + id int4range, + valid_from date, + valid_til date +); +ALTER TABLE temporal3 + ADD PERIOD FOR valid_at (valid_from, valid_til), + ADD CONSTRAINT temporal3_uq + UNIQUE (id, valid_at WITHOUT OVERLAPS); +\d temporal3 + Table "public.temporal3" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | | + valid_from | date | | | + valid_til | date | | | +Periods: + valid_at (valid_from, valid_til) +Indexes: + "temporal3_uq" UNIQUE (id, valid_at WITHOUT OVERLAPS) +Check constraints: + "temporal3_valid_at_check" CHECK (valid_from < valid_til) + +DROP TABLE temporal3; -- -- range PK: test with existing rows -- @@ -874,6 +1116,284 @@ SELECT * FROM temporal_mltrng3 ORDER BY id, valid_at; DROP TABLE temporal_mltrng3; -- +-- PERIOD PK: test with existing rows +-- +ALTER TABLE temporal_per DROP CONSTRAINT temporal_per_pk; +-- okay: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2018-01-02', '2018-02-03'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2018-03-03', '2018-04-04'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[2,3)', '2018-01-01', '2018-01-05'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[3,4)', '2018-01-01', NULL); +ALTER TABLE temporal_per ADD CONSTRAINT temporal_per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); +ALTER TABLE temporal_per DROP CONSTRAINT temporal_per_pk; +-- should fail: +BEGIN; + INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2018-01-01', '2018-01-05'); + ALTER TABLE temporal_per ADD CONSTRAINT temporal_per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); +ERROR: could not create exclusion constraint "temporal_per_pk" +DETAIL: Key (id, valid_at)=([1,2), [2018-01-02,2018-02-03)) conflicts with key (id, valid_at)=([1,2), [2018-01-01,2018-01-05)). +ROLLBACK; +-- rejects empty: +BEGIN; + ALTER TABLE temporal_per DROP PERIOD FOR valid_at; + INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[3,4)', '2020-01-01', '2020-01-01'); + ALTER TABLE temporal_per ADD PERIOD FOR valid_at (valid_from, valid_til); +ERROR: check constraint "temporal_per_valid_at_check" of relation "temporal_per" is violated by some row +ROLLBACK; +ALTER TABLE temporal_per ADD CONSTRAINT temporal_per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); +DELETE FROM temporal_per; +-- +-- PERIOD PK: test inserts +-- +-- okay: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2018-01-02', '2018-02-03'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2018-03-03', '2018-04-04'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[2,3)', '2018-01-01', '2018-01-05'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[3,4)', '2018-01-01', NULL); +-- should fail: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2018-01-01', '2018-01-05'); +ERROR: conflicting key value violates exclusion constraint "temporal_per_pk" +DETAIL: Key (id, valid_at)=([1,2), [2018-01-01,2018-01-05)) conflicts with existing key (id, valid_at)=([1,2), [2018-01-02,2018-02-03)). +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES (NULL, '2018-01-01', '2018-01-05'); +ERROR: null value in column "id" of relation "temporal_per" violates not-null constraint +DETAIL: Failing row contains (null, 2018-01-01, 2018-01-05, [2018-01-01,2018-01-05)). +-- rejects empty: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[3,4)', '2020-01-01', '2020-01-01'); +ERROR: new row for relation "temporal_per" violates check constraint "temporal_per_valid_at_check" +DETAIL: Failing row contains ([3,4), 2020-01-01, 2020-01-01, empty). +SELECT * FROM temporal_per ORDER BY id, valid_at; + id | valid_from | valid_til +-------+------------+------------ + [1,2) | 2018-01-02 | 2018-02-03 + [1,2) | 2018-03-03 | 2018-04-04 + [2,3) | 2018-01-01 | 2018-01-05 + [3,4) | 2018-01-01 | +(4 rows) + +-- +-- PERIOD PK: test updates +-- +-- update the scalar part +UPDATE temporal_per +SET id = '[11,12)' +WHERE id = '[1,2)' +AND valid_at @> '2018-01-15'::date; +-- update the PERIOD bounds +UPDATE temporal_per +SET valid_from = '2020-01-01', + valid_til = '2021-01-01' +WHERE id = '[11,12)' +AND valid_at @> '2018-01-15'::date; +-- update both at once +UPDATE temporal_per +SET id = '[21,22)', + valid_from = '2018-01-02', + valid_til = '2018-02-03' +WHERE id = '[11,12)' +AND valid_at @> '2020-01-15'::date; +SELECT * FROM temporal_per ORDER BY id, valid_at; + id | valid_from | valid_til +---------+------------+------------ + [1,2) | 2018-03-03 | 2018-04-04 + [2,3) | 2018-01-01 | 2018-01-05 + [3,4) | 2018-01-01 | + [21,22) | 2018-01-02 | 2018-02-03 +(4 rows) + +-- should fail: +UPDATE temporal_per +SET id = '[1,2)', + valid_from = '2018-03-05', + valid_til = '2018-05-05' +WHERE id = '[21,22)'; +ERROR: conflicting key value violates exclusion constraint "temporal_per_pk" +DETAIL: Key (id, valid_at)=([1,2), [2018-03-05,2018-05-05)) conflicts with existing key (id, valid_at)=([1,2), [2018-03-03,2018-04-04)). +-- set the scalar part to NULL +UPDATE temporal_per +SET id = NULL, + valid_from = '2018-03-05', + valid_til = '2018-05-05' +WHERE id = '[21,22)'; +ERROR: null value in column "id" of relation "temporal_per" violates not-null constraint +DETAIL: Failing row contains (null, 2018-03-05, 2018-05-05, [2018-03-05,2018-05-05)). +-- set a PERIOD bound to NULL (okay) +UPDATE temporal_per +SET id = '[1,2)', + valid_from = '2018-04-04', + valid_til = NULL +WHERE id = '[21,22)'; +-- rejects empty: +UPDATE temporal_per +SET id = '[21,22)', + valid_from = '2020-01-01', + valid_til = '2020-01-01' +WHERE id = '[1,2)'; +ERROR: new row for relation "temporal_per" violates check constraint "temporal_per_valid_at_check" +DETAIL: Failing row contains ([21,22), 2020-01-01, 2020-01-01, empty). +SELECT * FROM temporal_per ORDER BY id, valid_at; + id | valid_from | valid_til +-------+------------+------------ + [1,2) | 2018-03-03 | 2018-04-04 + [1,2) | 2018-04-04 | + [2,3) | 2018-01-01 | 2018-01-05 + [3,4) | 2018-01-01 | +(4 rows) + +-- +-- PERIOD UQ: test with existing rows +-- +CREATE TABLE temporal_per3 ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til) +); +-- okay: +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2018-01-02', '2018-02-03'); +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2018-03-03', '2018-04-04'); +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[2,3)', '2018-01-01', '2018-01-05'); +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[3,4)', '2018-01-01', NULL); +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES (NULL, '2018-01-01', '2018-01-05'); +ALTER TABLE temporal_per3 ADD CONSTRAINT temporal_per3_uq UNIQUE (id, valid_at WITHOUT OVERLAPS); +ALTER TABLE temporal_per3 DROP CONSTRAINT temporal_per3_uq; +-- should fail: +BEGIN; + INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2018-01-01', '2018-01-05'); + ALTER TABLE temporal_per3 ADD CONSTRAINT temporal_per3_uq UNIQUE (id, valid_at WITHOUT OVERLAPS); +ERROR: could not create exclusion constraint "temporal_per3_uq" +DETAIL: Key (id, valid_at)=([1,2), [2018-01-02,2018-02-03)) conflicts with key (id, valid_at)=([1,2), [2018-01-01,2018-01-05)). +ROLLBACK; +-- rejects empty: +BEGIN; + ALTER TABLE temporal_per3 DROP PERIOD FOR valid_at; + INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[3,4)', '2020-01-01', '2020-01-01'); + ALTER TABLE temporal_per3 ADD PERIOD FOR valid_at (valid_from, valid_til); +ERROR: check constraint "temporal_per3_valid_at_check" of relation "temporal_per3" is violated by some row +ROLLBACK; +ALTER TABLE temporal_per3 ADD CONSTRAINT temporal_per3_uq UNIQUE (id, valid_at WITHOUT OVERLAPS); +DELETE FROM temporal_per3; +-- +-- PERIOD UQ: test inserts +-- +-- okay: +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2018-01-02', '2018-02-03'); +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2018-03-03', '2018-04-04'); +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[2,3)', '2018-01-01', '2018-01-05'); +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[3,4)', '2018-01-01', NULL); +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES (NULL, '2018-01-01', '2018-01-05'); +-- should fail: +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2018-01-01', '2018-01-05'); +ERROR: conflicting key value violates exclusion constraint "temporal_per3_uq" +DETAIL: Key (id, valid_at)=([1,2), [2018-01-01,2018-01-05)) conflicts with existing key (id, valid_at)=([1,2), [2018-01-02,2018-02-03)). +-- rejects empty: +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[3,4)', '2020-01-01', '2020-01-01'); +ERROR: new row for relation "temporal_per3" violates check constraint "temporal_per3_valid_at_check" +DETAIL: Failing row contains ([3,4), 2020-01-01, 2020-01-01, empty). +SELECT * FROM temporal_per3 ORDER BY id, valid_at; + id | valid_from | valid_til +-------+------------+------------ + [1,2) | 2018-01-02 | 2018-02-03 + [1,2) | 2018-03-03 | 2018-04-04 + [2,3) | 2018-01-01 | 2018-01-05 + [3,4) | 2018-01-01 | + | 2018-01-01 | 2018-01-05 +(5 rows) + +-- +-- PERIOD UQ: test updates +-- +-- update the scalar part +UPDATE temporal_per3 +SET id = '[11,12)' +WHERE id = '[1,2)' +AND valid_at @> '2018-01-15'::date; +-- update the PERIOD bounds +UPDATE temporal_per3 +SET valid_from = '2020-01-01', + valid_til = '2021-01-01' +WHERE id = '[11,12)' +AND valid_at @> '2018-01-15'::date; +-- update both at once +UPDATE temporal_per3 +SET id = '[21,22)', + valid_from = '2018-01-02', + valid_til = '2018-02-03' +WHERE id = '[11,12)' +AND valid_at @> '2020-01-15'::date; +SELECT * FROM temporal_per3 ORDER BY id, valid_at; + id | valid_from | valid_til +---------+------------+------------ + [1,2) | 2018-03-03 | 2018-04-04 + [2,3) | 2018-01-01 | 2018-01-05 + [3,4) | 2018-01-01 | + [21,22) | 2018-01-02 | 2018-02-03 + | 2018-01-01 | 2018-01-05 +(5 rows) + +-- should fail: +UPDATE temporal_per3 +SET id = '[1,2)', + valid_from = '2018-03-05', + valid_til = '2018-05-05' +WHERE id = '[21,22)'; +ERROR: conflicting key value violates exclusion constraint "temporal_per3_uq" +DETAIL: Key (id, valid_at)=([1,2), [2018-03-05,2018-05-05)) conflicts with existing key (id, valid_at)=([1,2), [2018-03-03,2018-04-04)). +-- set the scalar part to NULL (okay) +UPDATE temporal_per3 +SET id = NULL, + valid_from = '2020-01-01', + valid_til = '2021-01-01' +WHERE id = '[21,22)'; +-- set a PERIOD bound to NULL (okay) +UPDATE temporal_per3 +SET id = '[1,2)', + valid_from = '2018-04-04', + valid_til = NULL +WHERE id IS NULL AND valid_at @> '2020-06-01'::date; +SELECT * FROM temporal_per3 ORDER BY id, valid_at; + id | valid_from | valid_til +-------+------------+------------ + [1,2) | 2018-03-03 | 2018-04-04 + [1,2) | 2018-04-04 | + [2,3) | 2018-01-01 | 2018-01-05 + [3,4) | 2018-01-01 | + | 2018-01-01 | 2018-01-05 +(5 rows) + +-- should fail: +UPDATE temporal_per3 +SET valid_from = '2018-03-01', + valid_til = '2018-05-05' +WHERE id = '[1,2)' AND valid_til IS NULL; +ERROR: conflicting key value violates exclusion constraint "temporal_per3_uq" +DETAIL: Key (id, valid_at)=([1,2), [2018-03-01,2018-05-05)) conflicts with existing key (id, valid_at)=([1,2), [2018-03-03,2018-04-04)). +-- rejects empty: +UPDATE temporal_per3 +SET valid_from = '2020-01-01', + valid_til = '2020-01-01' +WHERE id = '[1,2)' AND valid_til IS NULL; +ERROR: new row for relation "temporal_per3" violates check constraint "temporal_per3_valid_at_check" +DETAIL: Failing row contains ([1,2), 2020-01-01, 2020-01-01, empty). +-- still rejects empty when scalar part is NULL: +UPDATE temporal_per3 +SET id = NULL, + valid_from = '2020-01-01', + valid_til = '2020-01-01' +WHERE id = '[1,2)' AND valid_til IS NULL; +ERROR: new row for relation "temporal_per3" violates check constraint "temporal_per3_valid_at_check" +DETAIL: Failing row contains (null, 2020-01-01, 2020-01-01, empty). +SELECT * FROM temporal_per3 ORDER BY id, valid_at; + id | valid_from | valid_til +-------+------------+------------ + [1,2) | 2018-03-03 | 2018-04-04 + [1,2) | 2018-04-04 | + [2,3) | 2018-01-01 | 2018-01-05 + [3,4) | 2018-01-01 | + | 2018-01-01 | 2018-01-05 +(5 rows) + +DROP TABLE temporal_per3; +-- -- test a range with both a PK and a UNIQUE constraint -- CREATE TABLE temporal3 ( @@ -933,6 +1453,91 @@ ERROR: column "valid_at" is in a primary key ALTER TABLE temporal3 ALTER COLUMN valid_at TYPE tstzrange USING tstzrange(lower(valid_at), upper(valid_at)); ALTER TABLE temporal3 RENAME COLUMN valid_at TO valid_thru; ALTER TABLE temporal3 DROP COLUMN valid_thru; +\d temporal3 + Table "public.temporal3" + Column | Type | Collation | Nullable | Default +--------+-----------+-----------+----------+--------- + id | int4range | | not null | + +DROP TABLE temporal3; +CREATE TABLE temporal3 ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal3_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +\d temporal3 + Table "public.temporal3" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | not null | + valid_from | date | | | + valid_til | date | | | +Periods: + valid_at (valid_from, valid_til) +Indexes: + "temporal3_pk" PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +Check constraints: + "temporal3_valid_at_check" CHECK (valid_from < valid_til) + +SELECT attnotnull FROM pg_attribute WHERE attrelid = 'temporal3'::regclass AND attname = 'valid_at'; + attnotnull +------------ + t +(1 row) + +ALTER TABLE temporal3 ALTER COLUMN valid_at DROP NOT NULL; +ERROR: column "valid_at" is in a primary key +ALTER TABLE temporal3 ALTER COLUMN valid_at TYPE tstzrange USING tstzrange(lower(valid_at), upper(valid_at)); +ERROR: cannot specify USING when altering type of generated column +LINE 1: ALTER TABLE temporal3 ALTER COLUMN valid_at TYPE tstzrange U... + ^ +DETAIL: Column "valid_at" is a generated column. +ALTER TABLE temporal3 DROP COLUMN valid_at; +ERROR: cannot drop column valid_at of table temporal3 because period valid_at on table temporal3 requires it +HINT: You can drop period valid_at on table temporal3 instead. +ALTER TABLE temporal3 DROP PERIOD FOR valid_at; +\d temporal3 + Table "public.temporal3" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | not null | + valid_from | date | | | + valid_til | date | | | + +DROP TABLE temporal3; +-- Same results if we add the PERIOD and PK from ALTER TABLE: +CREATE TABLE temporal3 ( + id int4range, + valid_from date, + valid_til date +); +ALTER TABLE temporal3 + ADD PERIOD FOR valid_at (valid_from, valid_til), + ADD CONSTRAINT temporal3_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); +\d temporal3 + Table "public.temporal3" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | not null | + valid_from | date | | | + valid_til | date | | | +Periods: + valid_at (valid_from, valid_til) +Indexes: + "temporal3_pk" PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +Check constraints: + "temporal3_valid_at_check" CHECK (valid_from < valid_til) + +SELECT attnotnull FROM pg_attribute WHERE attrelid = 'temporal3'::regclass AND attname = 'valid_at'; + attnotnull +------------ + t +(1 row) + +ALTER TABLE temporal3 ALTER COLUMN valid_at DROP NOT NULL; +ERROR: column "valid_at" is in a primary key DROP TABLE temporal3; -- -- test PARTITION BY for ranges @@ -1414,32 +2019,236 @@ SELECT * FROM temporal_mltrng3 ORDER BY id, valid_at; DROP TABLE temporal_mltrng3; -- --- test FK dependencies --- --- can't drop a range referenced by an FK, unless with CASCADE -CREATE TABLE temporal3 ( - id int4range, - valid_at daterange, - CONSTRAINT temporal3_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) -); -CREATE TABLE temporal_fk_rng2rng ( - id int4range, - valid_at daterange, - parent_id int4range, - CONSTRAINT temporal_fk_rng2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), - CONSTRAINT temporal_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) - REFERENCES temporal3 (id, PERIOD valid_at) -); -ALTER TABLE temporal3 DROP COLUMN valid_at; -ERROR: cannot drop column valid_at of table temporal3 because other objects depend on it -DETAIL: constraint temporal_fk_rng2rng_fk on table temporal_fk_rng2rng depends on column valid_at of table temporal3 -HINT: Use DROP ... CASCADE to drop the dependent objects too. -ALTER TABLE temporal3 DROP COLUMN valid_at CASCADE; -NOTICE: drop cascades to constraint temporal_fk_rng2rng_fk on table temporal_fk_rng2rng -DROP TABLE temporal_fk_rng2rng; -DROP TABLE temporal3; +-- ON CONFLICT: PERIODs -- --- test FOREIGN KEY, range references range +TRUNCATE temporal_per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT DO NOTHING; +-- id matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT DO NOTHING; +-- date matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT DO NOTHING; +SELECT * FROM temporal_per ORDER BY id, valid_from, valid_til; + id | valid_from | valid_til +-------+------------+------------ + [1,2) | 2000-01-01 | 2010-01-01 + [1,2) | 2010-01-01 | 2020-01-01 + [2,3) | 2005-01-01 | 2006-01-01 +(3 rows) + +TRUNCATE temporal_per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT (id, valid_at) DO NOTHING; +ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification +-- id matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT (id, valid_at) DO NOTHING; +ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification +-- date matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT (id, valid_at) DO NOTHING; +ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification +SELECT * FROM temporal_per ORDER BY id, valid_from, valid_til; + id | valid_from | valid_til +-------+------------+------------ + [1,2) | 2000-01-01 | 2010-01-01 +(1 row) + +TRUNCATE temporal_per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT ON CONSTRAINT temporal_per_pk DO NOTHING; +-- id matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT ON CONSTRAINT temporal_per_pk DO NOTHING; +-- date matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT ON CONSTRAINT temporal_per_pk DO NOTHING; +SELECT * FROM temporal_per ORDER BY id, valid_from, valid_til; + id | valid_from | valid_til +-------+------------+------------ + [1,2) | 2000-01-01 | 2010-01-01 + [1,2) | 2010-01-01 | 2020-01-01 + [2,3) | 2005-01-01 | 2006-01-01 +(3 rows) + +TRUNCATE temporal_per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT (id, valid_at) DO UPDATE SET id = EXCLUDED.id + '[2,3)'; +ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification +-- id matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT (id, valid_at) DO UPDATE SET id = EXCLUDED.id + '[3,4)'; +ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification +-- date matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT (id, valid_at) DO UPDATE SET id = EXCLUDED.id + '[4,5)'; +ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification +SELECT * FROM temporal_per ORDER BY id, valid_from, valid_til; + id | valid_from | valid_til +-------+------------+------------ + [1,2) | 2000-01-01 | 2010-01-01 +(1 row) + +TRUNCATE temporal_per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT ON CONSTRAINT temporal_per_pk DO UPDATE SET id = EXCLUDED.id + '[2,3)'; +ERROR: ON CONFLICT DO UPDATE not supported with exclusion constraints +-- id matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT ON CONSTRAINT temporal_per_pk DO UPDATE SET id = EXCLUDED.id + '[3,4)'; +ERROR: ON CONFLICT DO UPDATE not supported with exclusion constraints +-- date matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT ON CONSTRAINT temporal_per_pk DO UPDATE SET id = EXCLUDED.id + '[4,5)'; +ERROR: ON CONFLICT DO UPDATE not supported with exclusion constraints +SELECT * FROM temporal_per ORDER BY id, valid_from, valid_til; + id | valid_from | valid_til +-------+------------+------------ + [1,2) | 2000-01-01 | 2010-01-01 +(1 row) + +-- with a UNIQUE constraint: +CREATE TABLE temporal_per3 ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_per3_uq UNIQUE (id, valid_at WITHOUT OVERLAPS) +); +TRUNCATE temporal_per3; +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT DO NOTHING; +-- id matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT DO NOTHING; +-- date matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT DO NOTHING; +SELECT * FROM temporal_per3 ORDER BY id, valid_from, valid_til; + id | valid_from | valid_til +-------+------------+------------ + [1,2) | 2000-01-01 | 2010-01-01 + [1,2) | 2010-01-01 | 2020-01-01 + [2,3) | 2005-01-01 | 2006-01-01 +(3 rows) + +TRUNCATE temporal_per3; +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT (id, valid_at) DO NOTHING; +ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification +-- id matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT (id, valid_at) DO NOTHING; +ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification +-- date matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT (id, valid_at) DO NOTHING; +ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification +SELECT * FROM temporal_per3 ORDER BY id, valid_from, valid_til; + id | valid_from | valid_til +-------+------------+------------ + [1,2) | 2000-01-01 | 2010-01-01 +(1 row) + +TRUNCATE temporal_per3; +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT ON CONSTRAINT temporal_per3_uq DO NOTHING; +-- id matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT ON CONSTRAINT temporal_per3_uq DO NOTHING; +-- date matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT ON CONSTRAINT temporal_per3_uq DO NOTHING; +SELECT * FROM temporal_per3 ORDER BY id, valid_from, valid_til; + id | valid_from | valid_til +-------+------------+------------ + [1,2) | 2000-01-01 | 2010-01-01 + [1,2) | 2010-01-01 | 2020-01-01 + [2,3) | 2005-01-01 | 2006-01-01 +(3 rows) + +TRUNCATE temporal_per3; +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT (id, valid_at) DO UPDATE SET id = EXCLUDED.id + '[2,3)'; +ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification +-- id matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT (id, valid_at) DO UPDATE SET id = EXCLUDED.id + '[3,4)'; +ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification +-- date matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT (id, valid_at) DO UPDATE SET id = EXCLUDED.id + '[4,5)'; +ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification +SELECT * FROM temporal_per3 ORDER BY id, valid_from, valid_til; + id | valid_from | valid_til +-------+------------+------------ + [1,2) | 2000-01-01 | 2010-01-01 +(1 row) + +TRUNCATE temporal_per3; +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT ON CONSTRAINT temporal_per3_uq DO UPDATE SET id = EXCLUDED.id + '[2,3)'; +ERROR: ON CONFLICT DO UPDATE not supported with exclusion constraints +-- id matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT ON CONSTRAINT temporal_per3_uq DO UPDATE SET id = EXCLUDED.id + '[3,4)'; +ERROR: ON CONFLICT DO UPDATE not supported with exclusion constraints +-- date matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT ON CONSTRAINT temporal_per3_uq DO UPDATE SET id = EXCLUDED.id + '[4,5)'; +ERROR: ON CONFLICT DO UPDATE not supported with exclusion constraints +SELECT * FROM temporal_per3 ORDER BY id, valid_from, valid_til; + id | valid_from | valid_til +-------+------------+------------ + [1,2) | 2000-01-01 | 2010-01-01 +(1 row) + +DROP TABLE temporal_per3; +-- +-- test FK dependencies +-- +-- can't drop a range referenced by an FK, unless with CASCADE +CREATE TABLE temporal3 ( + id int4range, + valid_at daterange, + CONSTRAINT temporal3_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +CREATE TABLE temporal_fk_rng2rng ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal3 (id, PERIOD valid_at) +); +ALTER TABLE temporal3 DROP COLUMN valid_at; +ERROR: cannot drop column valid_at of table temporal3 because other objects depend on it +DETAIL: constraint temporal_fk_rng2rng_fk on table temporal_fk_rng2rng depends on column valid_at of table temporal3 +HINT: Use DROP ... CASCADE to drop the dependent objects too. +ALTER TABLE temporal3 DROP COLUMN valid_at CASCADE; +NOTICE: drop cascades to constraint temporal_fk_rng2rng_fk on table temporal_fk_rng2rng +DROP TABLE temporal_fk_rng2rng; +DROP TABLE temporal3; +-- can't drop a PERIOD referenced by an FK, unless with CASCADE +CREATE TABLE temporal3 ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal3_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal3 (id, PERIOD valid_at) +); +ALTER TABLE temporal3 DROP PERIOD FOR valid_at; +ERROR: cannot drop period valid_at on table temporal3 because other objects depend on it +DETAIL: constraint temporal_fk_per2per_fk on table temporal_fk_per2per depends on column valid_at of table temporal3 +HINT: Use DROP ... CASCADE to drop the dependent objects too. +ALTER TABLE temporal3 DROP PERIOD FOR valid_at CASCADE; +NOTICE: drop cascades to constraint temporal_fk_per2per_fk on table temporal_fk_per2per +DROP TABLE temporal_fk_per2per; +DROP TABLE temporal3; +-- +-- test FOREIGN KEY, range references range -- -- test table setup DROP TABLE temporal_rng; @@ -1467,6 +2276,18 @@ CREATE TABLE temporal_fk_rng2rng ( CONSTRAINT temporal_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_rng (id, PERIOD valid_at) ); +\d temporal_fk_rng2rng + Table "public.temporal_fk_rng2rng" + Column | Type | Collation | Nullable | Default +-----------+-----------+-----------+----------+--------- + id | int4range | | not null | + valid_at | daterange | | not null | + parent_id | int4range | | | +Indexes: + "temporal_fk_rng2rng_pk" PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +Foreign-key constraints: + "temporal_fk_rng2rng_fk" FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_rng(id, PERIOD valid_at) + DROP TABLE temporal_fk_rng2rng; -- with mismatched PERIOD columns: -- (parent_id, PERIOD valid_at) REFERENCES (id, valid_at) @@ -3585,83 +4406,3566 @@ SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, val [200,201) | {[2020-01-01,2021-01-01)} | [8,9) | [8,9) (2 rows) --- FK with a custom range type -CREATE TYPE mydaterange AS range(subtype=date); -CREATE TABLE temporal_rng3 ( +-- +-- test FOREIGN KEY, PERIOD references PERIOD +-- +-- test table setup +DROP TABLE temporal_per; +CREATE TABLE temporal_per ( id int4range, - valid_at mydaterange, - CONSTRAINT temporal_rng3_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til) ); -CREATE TABLE temporal_fk3_rng2rng ( +ALTER TABLE temporal_per + ADD CONSTRAINT temporal_per_pk + PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); +-- Can't create a FK with a mismatched range type +CREATE TABLE temporal_fk_per2per ( id int4range, - valid_at mydaterange, + valid_from int, + valid_til int, parent_id int4range, - CONSTRAINT temporal_fk3_rng2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), - CONSTRAINT temporal_fk3_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) - REFERENCES temporal_rng3 (id, PERIOD valid_at) ON DELETE CASCADE + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id, PERIOD valid_at) ); -INSERT INTO temporal_rng3 (id, valid_at) VALUES ('[8,9)', mydaterange('2018-01-01', '2021-01-01')); -INSERT INTO temporal_fk3_rng2rng (id, valid_at, parent_id) VALUES ('[5,6)', mydaterange('2018-01-01', '2021-01-01'), '[8,9)'); -DELETE FROM temporal_rng3 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[8,9)'; -SELECT * FROM temporal_fk3_rng2rng WHERE id = '[5,6)'; - id | valid_at | parent_id --------+-------------------------+----------- - [5,6) | [2018-01-01,2019-01-01) | [8,9) - [5,6) | [2020-01-01,2021-01-01) | [8,9) -(2 rows) +ERROR: foreign key constraint "temporal_fk_per2per_fk" cannot be implemented +DETAIL: Key columns "valid_at" of the referencing table and "valid_at" of the referenced table are of incompatible types: int4range and daterange. +-- works: PERIOD for both referenced and referencing +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id, PERIOD valid_at) +); +\d temporal_fk_per2per + Table "public.temporal_fk_per2per" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | not null | + valid_from | date | | | + valid_til | date | | | + parent_id | int4range | | | +Periods: + valid_at (valid_from, valid_til) +Indexes: + "temporal_fk_per2per_pk" PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +Check constraints: + "temporal_fk_per2per_valid_at_check" CHECK (valid_from < valid_til) +Foreign-key constraints: + "temporal_fk_per2per_fk" FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_per(id, PERIOD valid_at) -DROP TABLE temporal_fk3_rng2rng; -DROP TABLE temporal_rng3; -DROP TYPE mydaterange; --- --- FK between partitioned tables: ranges --- -CREATE TABLE temporal_partitioned_rng ( +DROP TABLE temporal_fk_per2per; +-- with mismatched PERIOD columns: +-- (parent_id, PERIOD valid_at) REFERENCES (id, valid_at) +-- REFERENCES part should specify PERIOD +CREATE TABLE temporal_fk_per2per ( id int4range, - valid_at daterange, - name text, - CONSTRAINT temporal_paritioned_rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) -) PARTITION BY LIST (id); -CREATE TABLE tp1 PARTITION OF temporal_partitioned_rng FOR VALUES IN ('[1,2)', '[3,4)', '[5,6)', '[7,8)', '[9,10)', '[11,12)', '[13,14)', '[15,16)', '[17,18)', '[19,20)', '[21,22)', '[23,24)'); -CREATE TABLE tp2 PARTITION OF temporal_partitioned_rng FOR VALUES IN ('[0,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)'); -INSERT INTO temporal_partitioned_rng (id, valid_at, name) VALUES - ('[1,2)', daterange('2000-01-01', '2000-02-01'), 'one'), - ('[1,2)', daterange('2000-02-01', '2000-03-01'), 'one'), - ('[2,3)', daterange('2000-01-01', '2010-01-01'), 'two'); -CREATE TABLE temporal_partitioned_fk_rng2rng ( + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id, valid_at) +); +ERROR: foreign key uses PERIOD on the referencing table but not the referenced table +-- (parent_id, valid_at) REFERENCES (id, valid_at) +-- both should specify PERIOD: +CREATE TABLE temporal_fk_per2per ( id int4range, - valid_at daterange, + valid_from date, + valid_til date, parent_id int4range, - CONSTRAINT temporal_partitioned_fk_rng2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), - CONSTRAINT temporal_partitioned_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) - REFERENCES temporal_partitioned_rng (id, PERIOD valid_at) -) PARTITION BY LIST (id); -CREATE TABLE tfkp1 PARTITION OF temporal_partitioned_fk_rng2rng FOR VALUES IN ('[1,2)', '[3,4)', '[5,6)', '[7,8)', '[9,10)', '[11,12)', '[13,14)', '[15,16)', '[17,18)', '[19,20)', '[21,22)', '[23,24)'); -CREATE TABLE tfkp2 PARTITION OF temporal_partitioned_fk_rng2rng FOR VALUES IN ('[0,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)'); --- --- partitioned FK referencing inserts --- -INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES - ('[1,2)', daterange('2000-01-01', '2000-02-15'), '[1,2)'), - ('[1,2)', daterange('2001-01-01', '2002-01-01'), '[2,3)'), - ('[2,3)', daterange('2000-01-01', '2000-02-15'), '[1,2)'); --- should fail: -INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES - ('[3,4)', daterange('2010-01-01', '2010-02-15'), '[1,2)'); -ERROR: insert or update on table "tfkp1" violates foreign key constraint "temporal_partitioned_fk_rng2rng_fk" -DETAIL: Key (parent_id, valid_at)=([1,2), [2010-01-01,2010-02-15)) is not present in table "temporal_partitioned_rng". -INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES - ('[3,4)', daterange('2000-01-01', '2000-02-15'), '[3,4)'); -ERROR: insert or update on table "tfkp1" violates foreign key constraint "temporal_partitioned_fk_rng2rng_fk" -DETAIL: Key (parent_id, valid_at)=([3,4), [2000-01-01,2000-02-15)) is not present in table "temporal_partitioned_rng". + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_per (id, valid_at) +); +ERROR: foreign key must use PERIOD when referencing a primary key using WITHOUT OVERLAPS +-- (parent_id, valid_at) REFERENCES (id, PERIOD valid_at) +-- FOREIGN KEY part should specify PERIOD +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_per (id, PERIOD valid_at) +); +ERROR: foreign key uses PERIOD on the referenced table but not the referencing table +-- (parent_id, valid_at) REFERENCES [implicit] +-- FOREIGN KEY part should specify PERIOD +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_per +); +ERROR: foreign key uses PERIOD on the referenced table but not the referencing table +-- (parent_id, PERIOD valid_at) REFERENCES (id) +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id) +); +ERROR: foreign key uses PERIOD on the referencing table but not the referenced table +-- (parent_id) REFERENCES (id, PERIOD valid_at) +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id) + REFERENCES temporal_per (id, PERIOD valid_at) +); +ERROR: foreign key uses PERIOD on the referenced table but not the referencing table +-- with inferred PK on the referenced table: +-- (parent_id, PERIOD valid_at) REFERENCES [implicit] +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per +); +DROP TABLE temporal_fk_per2per; +-- (parent_id) REFERENCES [implicit] +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id) + REFERENCES temporal_per +); +ERROR: foreign key uses PERIOD on the referenced table but not the referencing table +-- should fail because of duplicate referenced columns: +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, PERIOD parent_id) + REFERENCES temporal_per (id, PERIOD id) +); +ERROR: foreign key referenced-columns list must not contain duplicates +-- Two scalar columns +DROP TABLE temporal_per2; +CREATE TABLE temporal_per2 ( + id1 int4range, + id2 int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_per2_pk PRIMARY KEY (id1, id2, valid_at WITHOUT OVERLAPS) +); +CREATE TABLE temporal_fk2_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id1 int4range, + parent_id2 int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk2_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk2_per2per_fk FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 (id1, id2, PERIOD valid_at) +); +\d temporal_fk2_per2per + Table "public.temporal_fk2_per2per" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | not null | + valid_from | date | | | + valid_til | date | | | + parent_id1 | int4range | | | + parent_id2 | int4range | | | +Periods: + valid_at (valid_from, valid_til) +Indexes: + "temporal_fk2_per2per_pk" PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +Check constraints: + "temporal_fk2_per2per_valid_at_check" CHECK (valid_from < valid_til) +Foreign-key constraints: + "temporal_fk2_per2per_fk" FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) REFERENCES temporal_per2(id1, id2, PERIOD valid_at) + +DROP TABLE temporal_fk2_per2per; -- --- partitioned FK referencing updates +-- test ALTER TABLE ADD CONSTRAINT -- -UPDATE temporal_partitioned_fk_rng2rng SET valid_at = daterange('2000-01-01', '2000-02-13') WHERE id = '[2,3)'; --- move a row from the first partition to the second -UPDATE temporal_partitioned_fk_rng2rng SET id = '[4,5)' WHERE id = '[1,2)'; --- move a row from the second partition to the first -UPDATE temporal_partitioned_fk_rng2rng SET id = '[1,2)' WHERE id = '[4,5)'; +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id, PERIOD valid_at); +-- Two scalar columns: +CREATE TABLE temporal_fk2_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id1 int4range, + parent_id2 int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk2_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +ALTER TABLE temporal_fk2_per2per + ADD CONSTRAINT temporal_fk2_per2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 (id1, id2, PERIOD valid_at); +\d temporal_fk2_per2per + Table "public.temporal_fk2_per2per" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | not null | + valid_from | date | | | + valid_til | date | | | + parent_id1 | int4range | | | + parent_id2 | int4range | | | +Periods: + valid_at (valid_from, valid_til) +Indexes: + "temporal_fk2_per2per_pk" PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +Check constraints: + "temporal_fk2_per2per_valid_at_check" CHECK (valid_from < valid_til) +Foreign-key constraints: + "temporal_fk2_per2per_fk" FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) REFERENCES temporal_per2(id1, id2, PERIOD valid_at) + +-- with inferred PK on the referenced table, and wrong column type: +ALTER TABLE temporal_fk_per2per + DROP CONSTRAINT temporal_fk_per2per_fk, + DROP PERIOD FOR valid_at, + ALTER COLUMN valid_from TYPE timestamp, + ALTER COLUMN valid_til TYPE timestamp, + ADD PERIOD FOR valid_at (valid_from, valid_til); +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +ERROR: foreign key constraint "temporal_fk_per2per_fk" cannot be implemented +DETAIL: Key columns "valid_at" of the referencing table and "valid_at" of the referenced table are of incompatible types: tsrange and daterange. +ALTER TABLE temporal_fk_per2per + DROP PERIOD FOR valid_at, + ALTER COLUMN valid_from TYPE date, + ALTER COLUMN valid_til TYPE date, + ADD PERIOD FOR valid_at (valid_from, valid_til); +-- with inferred PK on the referenced table: +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +-- should fail because of duplicate referenced columns: +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk2 + FOREIGN KEY (parent_id, PERIOD parent_id) + REFERENCES temporal_per (id, PERIOD id); +ERROR: foreign key referenced-columns list must not contain duplicates +-- +-- test with rows already +-- +DELETE FROM temporal_fk_per2per; +DELETE FROM temporal_per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[1,2)', '2018-01-02', '2018-02-03'), + ('[1,2)', '2018-03-03', '2018-04-04'), + ('[2,3)', '2018-01-01', '2018-01-05'), + ('[3,4)', '2018-01-01', NULL); +ALTER TABLE temporal_fk_per2per + DROP CONSTRAINT temporal_fk_per2per_fk; +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[1,2)', '2018-01-02', '2018-02-01', '[1,2)'); +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +ALTER TABLE temporal_fk_per2per + DROP CONSTRAINT temporal_fk_per2per_fk; +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[2,3)', '2018-01-02', '2018-04-01', '[1,2)'); +-- should fail: +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +ERROR: insert or update on table "temporal_fk_per2per" violates foreign key constraint "temporal_fk_per2per_fk" +DETAIL: Key (parent_id, valid_at)=([1,2), [2018-01-02,2018-04-01)) is not present in table "temporal_per". +-- okay again: +DELETE FROM temporal_fk_per2per; +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +-- +-- test pg_get_constraintdef +-- +SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_fk_per2per_fk'; + pg_get_constraintdef +--------------------------------------------------------------------------------------- + FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_per(id, PERIOD valid_at) +(1 row) + +-- +-- test FK referencing inserts +-- +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[1,2)', '2018-01-02', '2018-02-01', '[1,2)'); +-- should fail: +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[2,3)', '2018-01-02', '2018-04-01', '[1,2)'); +ERROR: insert or update on table "temporal_fk_per2per" violates foreign key constraint "temporal_fk_per2per_fk" +DETAIL: Key (parent_id, valid_at)=([1,2), [2018-01-02,2018-04-01)) is not present in table "temporal_per". +-- now it should work: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2018-02-03', '2018-03-03'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[2,3)', '2018-01-02', '2018-04-01', '[1,2)'); +-- +-- test FK referencing updates +-- +-- slide the edge across a referenced transition: +UPDATE temporal_fk_per2per SET valid_from = '2018-01-02', valid_til = '2018-02-20' WHERE id = '[1,2)'; +-- should fail: +UPDATE temporal_fk_per2per SET valid_from = '2018-01-02', valid_til = '2018-05-01' WHERE id = '[1,2)'; +ERROR: insert or update on table "temporal_fk_per2per" violates foreign key constraint "temporal_fk_per2per_fk" +DETAIL: Key (parent_id, valid_at)=([1,2), [2018-01-02,2018-05-01)) is not present in table "temporal_per". +UPDATE temporal_fk_per2per SET parent_id = '[8,9)' WHERE id = '[1,2)'; +ERROR: insert or update on table "temporal_fk_per2per" violates foreign key constraint "temporal_fk_per2per_fk" +DETAIL: Key (parent_id, valid_at)=([8,9), [2018-01-02,2018-02-20)) is not present in table "temporal_per". +-- ALTER FK DEFERRABLE +BEGIN; + INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[5,6)', '2018-01-01', '2018-02-01'), + ('[5,6)', '2018-02-01', '2018-03-01'); + INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES + ('[3,4)', '2018-01-05', '2018-01-10', '[5,6)'); + ALTER TABLE temporal_fk_per2per + ALTER CONSTRAINT temporal_fk_per2per_fk + DEFERRABLE INITIALLY DEFERRED; + DELETE FROM temporal_per WHERE id = '[5,6)'; --should not fail yet. +COMMIT; -- should fail here. +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_per2per_fk" on table "temporal_fk_per2per" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_per2per". +-- +-- test FK referenced updates NO ACTION +-- +TRUNCATE temporal_per, temporal_fk_per2per; +ALTER TABLE temporal_fk_per2per + DROP CONSTRAINT temporal_fk_per2per_fk; +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON UPDATE NO ACTION; +-- a PK update that succeeds because the numeric id isn't referenced: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[5,6)', '2018-01-01', '2018-02-01'); +UPDATE temporal_per SET valid_from = '2016-01-01', valid_til = '2016-02-01' WHERE id = '[5,6)'; +-- a PK update that succeeds even though the numeric id is referenced because the range isn't: +DELETE FROM temporal_per WHERE id = '[5,6)'; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[5,6)', '2018-01-01', '2018-02-01'), + ('[5,6)', '2018-02-01', '2018-03-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES + ('[3,4)', '2018-01-05', '2018-01-10', '[5,6)'); +UPDATE temporal_per SET valid_from = '2016-02-01', valid_til = '2016-03-01' +WHERE id = '[5,6)' AND valid_from = '2018-02-01' AND valid_til = '2018-03-01'; +-- A PK update sliding the edge between two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[6,7)', '2018-01-01', '2018-02-01'), + ('[6,7)', '2018-02-01', '2018-03-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES + ('[4,5)', '2018-01-15', '2018-02-15', '[6,7)'); +UPDATE temporal_per +SET valid_from = CASE WHEN valid_from = '2018-01-01' THEN '2018-01-01' + WHEN valid_from = '2018-02-01' THEN '2018-01-05' END::date, + valid_til = CASE WHEN valid_from = '2018-01-01' THEN '2018-01-05' + WHEN valid_from = '2018-02-01' THEN '2018-03-01' END::date +WHERE id = '[6,7)'; +-- a PK update shrinking the referenced range but still valid: +-- There are two references: one fulfilled by the first pk row, +-- the other fulfilled by both pk rows combined. +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[1,2)', '2018-01-01', '2018-03-01'), + ('[1,2)', '2018-03-01', '2018-06-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES + ('[1,2)', '2018-01-15', '2018-02-01', '[1,2)'), + ('[2,3)', '2018-01-15', '2018-05-01', '[1,2)'); +UPDATE temporal_per SET valid_from = '2018-01-15', valid_til = '2018-03-01' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +-- a PK update growing the referenced range is fine: +UPDATE temporal_per SET valid_from = '2018-01-01', valid_til = '2018-03-01' +WHERE id = '[1,2)' AND valid_at @> '2018-01-25'::date; +-- a PK update shrinking the referenced range and changing the id invalidates the whole range: +UPDATE temporal_per SET id = '[2,3)', valid_from = '2018-01-15', valid_til = '2018-03-01' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_per2per_fk" on table "temporal_fk_per2per" +DETAIL: Key (id, valid_at)=([1,2), [2018-01-01,2018-03-01)) is still referenced from table "temporal_fk_per2per". +-- a PK update changing only the id invalidates the whole range: +UPDATE temporal_per SET id = '[2,3)' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_per2per_fk" on table "temporal_fk_per2per" +DETAIL: Key (id, valid_at)=([1,2), [2018-01-01,2018-03-01)) is still referenced from table "temporal_fk_per2per". +-- a PK update that loses time from both ends, but is still valid: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[2,3)', '2018-01-01', '2018-03-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES + ('[5,6)', '2018-01-15', '2018-02-01', '[2,3)'); +UPDATE temporal_per SET valid_from = '2018-01-15', valid_til = '2018-02-15' +WHERE id = '[2,3)'; +-- a PK update that fails because both are referenced: +UPDATE temporal_per SET valid_from = '2016-01-01', valid_til = '2016-02-01' +WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_per2per_fk" on table "temporal_fk_per2per" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_per2per". +-- a PK update that fails because both are referenced, but not 'til commit: +BEGIN; + ALTER TABLE temporal_fk_per2per + ALTER CONSTRAINT temporal_fk_per2per_fk + DEFERRABLE INITIALLY DEFERRED; + UPDATE temporal_per SET valid_from = '2016-01-01', valid_til = '2016-02-01' + WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); +COMMIT; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_per2per_fk" on table "temporal_fk_per2per" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_per2per". +-- changing the scalar part fails: +UPDATE temporal_per SET id = '[7,8)' +WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_per2per_fk" on table "temporal_fk_per2per" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_per2per". +-- changing an unreferenced part is okay: +UPDATE temporal_per +FOR PORTION OF valid_at FROM '2018-01-02' TO '2018-01-03' +SET id = '[7,8)' +WHERE id = '[5,6)'; +-- changing just a part fails: +UPDATE temporal_per +FOR PORTION OF valid_at FROM '2018-01-05' TO '2018-01-10' +SET id = '[7,8)' +WHERE id = '[5,6)'; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_per2per_fk" on table "temporal_fk_per2per" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-03,2018-02-01)) is still referenced from table "temporal_fk_per2per". +SELECT * FROM temporal_per WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; + id | valid_from | valid_til +-------+------------+------------ + [5,6) | 2016-02-01 | 2016-03-01 + [5,6) | 2018-01-01 | 2018-01-02 + [5,6) | 2018-01-03 | 2018-02-01 + [7,8) | 2018-01-02 | 2018-01-03 +(4 rows) + +SELECT * FROM temporal_fk_per2per WHERE id in ('[3,4)') ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-------+------------+------------+----------- + [3,4) | 2018-01-05 | 2018-01-10 | [5,6) +(1 row) + +-- then delete the objecting FK record and the same PK update succeeds: +DELETE FROM temporal_fk_per2per WHERE id = '[3,4)'; +UPDATE temporal_per SET valid_from = '2016-01-01', valid_til = '2016-02-01' +WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; +-- +-- test FK referenced updates RESTRICT +-- +TRUNCATE temporal_per, temporal_fk_per2per; +ALTER TABLE temporal_fk_per2per + DROP CONSTRAINT temporal_fk_per2per_fk; +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON UPDATE RESTRICT; +ERROR: unsupported ON UPDATE action for foreign key constraint using PERIOD +-- +-- test FK referenced deletes NO ACTION +-- +TRUNCATE temporal_per, temporal_fk_per2per; +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +-- a PK delete that succeeds because the numeric id isn't referenced: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[5,6)', '2018-01-01', '2018-02-01'); +DELETE FROM temporal_per WHERE id = '[5,6)'; +-- a PK delete that succeeds even though the numeric id is referenced because the range isn't: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[5,6)', '2018-01-01', '2018-02-01'), + ('[5,6)', '2018-02-01', '2018-03-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[3,4)', '2018-01-05', '2018-01-10', '[5,6)'); +DELETE FROM temporal_per WHERE id = '[5,6)' AND valid_from = '2018-02-01' AND valid_til = '2018-03-01'; +-- a PK delete that fails because both are referenced: +DELETE FROM temporal_per WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_per2per_fk" on table "temporal_fk_per2per" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_per2per". +-- a PK delete that fails because both are referenced, but not 'til commit: +BEGIN; + ALTER TABLE temporal_fk_per2per + ALTER CONSTRAINT temporal_fk_per2per_fk + DEFERRABLE INITIALLY DEFERRED; + DELETE FROM temporal_per WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); +COMMIT; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_per2per_fk" on table "temporal_fk_per2per" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_per2per". +-- deleting an unreferenced part is okay: +DELETE FROM temporal_per +FOR PORTION OF valid_at FROM '2018-01-02' TO '2018-01-03' +WHERE id = '[5,6)'; +-- deleting just a part fails: +DELETE FROM temporal_per +FOR PORTION OF valid_at FROM '2018-01-05' TO '2018-01-10' +WHERE id = '[5,6)'; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_per2per_fk" on table "temporal_fk_per2per" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-03,2018-02-01)) is still referenced from table "temporal_fk_per2per". +SELECT * FROM temporal_per WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; + id | valid_from | valid_til +-------+------------+------------ + [5,6) | 2018-01-01 | 2018-01-02 + [5,6) | 2018-01-03 | 2018-02-01 +(2 rows) + +SELECT * FROM temporal_fk_per2per WHERE id in ('[3,4)') ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-------+------------+------------+----------- + [3,4) | 2018-01-05 | 2018-01-10 | [5,6) +(1 row) + +-- then delete the objecting FK record and the same PK delete succeeds: +DELETE FROM temporal_fk_per2per WHERE id = '[3,4)'; +DELETE FROM temporal_per WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; +-- +-- test FK referenced deletes RESTRICT +-- +TRUNCATE temporal_per, temporal_fk_per2per; +ALTER TABLE temporal_fk_per2per + DROP CONSTRAINT temporal_fk_per2per_fk; +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON DELETE RESTRICT; +ERROR: unsupported ON DELETE action for foreign key constraint using PERIOD +-- +-- per2per test ON UPDATE/DELETE options +-- +-- TOC: +-- referenced updates CASCADE +-- referenced deletes CASCADE +-- referenced updates SET NULL +-- referenced deletes SET NULL +-- referenced updates SET DEFAULT +-- referenced deletes SET DEFAULT +-- referenced updates CASCADE (two scalar cols) +-- referenced deletes CASCADE (two scalar cols) +-- referenced updates SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- referenced updates SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) +-- +-- test FK referenced updates CASCADE +-- +TRUNCATE temporal_per, temporal_fk_per2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [7,8) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_per SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [7,8) + [100,101) | 2019-01-01 | 2020-01-01 | [7,8) + [100,101) | 2020-01-01 | 2021-01-01 | [7,8) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +UPDATE temporal_per SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [200,201) | 2018-01-01 | 2020-01-01 | [9,10) + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) +(2 rows) + +-- +-- test FK referenced deletes CASCADE +-- +TRUNCATE temporal_per, temporal_fk_per2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) +(2 rows) + +-- non-FPO delete: +DELETE FROM temporal_per WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +----+------------+-----------+----------- +(0 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +DELETE FROM temporal_per WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) +(1 row) + +-- +-- test FK referenced updates SET NULL +-- +TRUNCATE temporal_per, temporal_fk_per2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +ALTER TABLE temporal_fk_per2per + DROP CONSTRAINT temporal_fk_per2per_fk, + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_per SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | + [100,101) | 2019-01-01 | 2020-01-01 | + [100,101) | 2020-01-01 | 2021-01-01 | +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +UPDATE temporal_per SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [200,201) | 2018-01-01 | 2020-01-01 | + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET NULL +-- +TRUNCATE temporal_per, temporal_fk_per2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) +(3 rows) + +-- non-FPO delete: +DELETE FROM temporal_per WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | + [100,101) | 2019-01-01 | 2020-01-01 | + [100,101) | 2020-01-01 | 2021-01-01 | +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +DELETE FROM temporal_per WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [200,201) | 2018-01-01 | 2020-01-01 | + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) +(2 rows) + +-- +-- test FK referenced updates SET DEFAULT +-- +TRUNCATE temporal_per, temporal_fk_per2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[-1,-1]', null, null); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +ALTER TABLE temporal_fk_per2per + ALTER COLUMN parent_id SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk_per2per_fk, + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_per SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [-1,0) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) + [100,101) | 2020-01-01 | 2021-01-01 | [-1,0) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +UPDATE temporal_per SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [200,201) | 2018-01-01 | 2020-01-01 | [-1,0) + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET DEFAULT +-- +TRUNCATE temporal_per, temporal_fk_per2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[-1,-1]', null, null); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) +(3 rows) + +-- non-FPO update: +DELETE FROM temporal_per WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [-1,0) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) + [100,101) | 2020-01-01 | 2021-01-01 | [-1,0) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +DELETE FROM temporal_per WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [200,201) | 2018-01-01 | 2020-01-01 | [-1,0) + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) +(2 rows) + +-- +-- test FK referenced updates CASCADE (two scalar cols) +-- +TRUNCATE temporal_per2, temporal_fk2_per2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_per2per + DROP CONSTRAINT temporal_fk2_per2per_fk, + ADD CONSTRAINT temporal_fk2_per2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [7,8) | [6,7) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_per2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [7,8) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [7,8) | [6,7) + [100,101) | 2020-01-01 | 2021-01-01 | [7,8) | [6,7) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +UPDATE temporal_per2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [200,201) | 2018-01-01 | 2020-01-01 | [9,10) | [8,9) + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes CASCADE (two scalar cols) +-- +TRUNCATE temporal_per2, temporal_fk2_per2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) | [6,7) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) | [6,7) +(2 rows) + +-- non-FPO delete: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +----+------------+-----------+------------+------------ +(0 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) | [8,9) +(1 row) + +-- +-- test FK referenced updates SET NULL (two scalar cols) +-- +TRUNCATE temporal_per2, temporal_fk2_per2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_per2per + DROP CONSTRAINT temporal_fk2_per2per_fk, + ADD CONSTRAINT temporal_fk2_per2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | | + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_per2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | | + [100,101) | 2019-01-01 | 2020-01-01 | | + [100,101) | 2020-01-01 | 2021-01-01 | | +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +UPDATE temporal_per2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [200,201) | 2018-01-01 | 2020-01-01 | | + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET NULL (two scalar cols) +-- +TRUNCATE temporal_per2, temporal_fk2_per2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | | + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) | [6,7) +(3 rows) + +-- non-FPO delete: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | | + [100,101) | 2019-01-01 | 2020-01-01 | | + [100,101) | 2020-01-01 | 2021-01-01 | | +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [200,201) | 2018-01-01 | 2020-01-01 | | + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- +TRUNCATE temporal_per2, temporal_fk2_per2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_per2per + DROP CONSTRAINT temporal_fk2_per2per_fk, + ADD CONSTRAINT temporal_fk2_per2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET NULL (valid_at) ON UPDATE SET NULL; +ERROR: column "valid_at" referenced in ON DELETE SET action cannot be PERIOD +-- ok: +ALTER TABLE temporal_fk2_per2per + DROP CONSTRAINT temporal_fk2_per2per_fk, + ADD CONSTRAINT temporal_fk2_per2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET NULL (parent_id1) ON UPDATE SET NULL; +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | | [6,7) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) | [6,7) +(3 rows) + +-- non-FPO delete: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | | [6,7) + [100,101) | 2020-01-01 | 2021-01-01 | | [6,7) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [200,201) | 2018-01-01 | 2020-01-01 | | [8,9) + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced updates SET DEFAULT (two scalar cols) +-- +TRUNCATE temporal_per2, temporal_fk2_per2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[-1,-1]', '[-1,-1]', null, null); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_per2per + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + ALTER COLUMN parent_id2 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_per2per_fk, + ADD CONSTRAINT temporal_fk2_per2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) | [-1,0) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_per2 SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [-1,0) | [-1,0) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) | [-1,0) + [100,101) | 2020-01-01 | 2021-01-01 | [-1,0) | [-1,0) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +UPDATE temporal_per2 SET id1 = '[9,10)', id2 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [200,201) | 2018-01-01 | 2020-01-01 | [-1,0) | [-1,0) + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols) +-- +TRUNCATE temporal_per2, temporal_fk2_per2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[-1,-1]', '[-1,-1]', null, null); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) | [-1,0) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [-1,0) | [-1,0) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) | [-1,0) + [100,101) | 2020-01-01 | 2021-01-01 | [-1,0) | [-1,0) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [200,201) | 2018-01-01 | 2020-01-01 | [-1,0) | [-1,0) + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) +-- +TRUNCATE temporal_per2, temporal_fk2_per2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[-1,-1]', '[6,7)', null, null); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_per2per + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_per2per_fk, + ADD CONSTRAINT temporal_fk2_per2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET DEFAULT (valid_at) ON UPDATE SET DEFAULT; +ERROR: column "valid_at" referenced in ON DELETE SET action cannot be PERIOD +-- ok: +ALTER TABLE temporal_fk2_per2per + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_per2per_fk, + ADD CONSTRAINT temporal_fk2_per2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET DEFAULT (parent_id1) ON UPDATE SET DEFAULT; +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) | [6,7) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [-1,0) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) | [6,7) + [100,101) | 2020-01-01 | 2021-01-01 | [-1,0) | [6,7) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[-1,-1]', '[8,9)', null, null); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [200,201) | 2018-01-01 | 2020-01-01 | [-1,0) | [8,9) + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) | [8,9) +(2 rows) + +-- +-- test FOREIGN KEY, range references PERIOD +-- +-- test table setup +DROP TABLE temporal_per CASCADE; +NOTICE: drop cascades to constraint temporal_fk_per2per_fk on table temporal_fk_per2per +CREATE TABLE temporal_per ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til) +); +ALTER TABLE temporal_per + ADD CONSTRAINT temporal_per_pk + PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); +-- Can't create a FK with a mismatched range type +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at int4range, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id, PERIOD valid_at) +); +ERROR: foreign key constraint "temporal_fk_rng2per_fk" cannot be implemented +DETAIL: Key columns "valid_at" of the referencing table and "valid_at" of the referenced table are of incompatible types: int4range and daterange. +-- works: PERIOD for referenced, range for referencing +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id, PERIOD valid_at) +); +\d temporal_fk_rng2per + Table "public.temporal_fk_rng2per" + Column | Type | Collation | Nullable | Default +-----------+-----------+-----------+----------+--------- + id | int4range | | not null | + valid_at | daterange | | not null | + parent_id | int4range | | | +Indexes: + "temporal_fk_rng2per_pk" PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +Foreign-key constraints: + "temporal_fk_rng2per_fk" FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_per(id, PERIOD valid_at) + +DROP TABLE temporal_fk_rng2per; +-- with mismatched PERIOD columns: +-- (parent_id, PERIOD valid_at) REFERENCES (id, valid_at) +-- REFERENCES part should specify PERIOD +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id, valid_at) +); +ERROR: foreign key uses PERIOD on the referencing table but not the referenced table +-- (parent_id, valid_at) REFERENCES (id, valid_at) +-- both should specify PERIOD: +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_per (id, valid_at) +); +ERROR: foreign key must use PERIOD when referencing a primary key using WITHOUT OVERLAPS +-- (parent_id, valid_at) REFERENCES (id, PERIOD valid_at) +-- FOREIGN KEY part should specify PERIOD +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_per (id, PERIOD valid_at) +); +ERROR: foreign key uses PERIOD on the referenced table but not the referencing table +-- (parent_id, valid_at) REFERENCES [implicit] +-- FOREIGN KEY part should specify PERIOD +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_per +); +ERROR: foreign key uses PERIOD on the referenced table but not the referencing table +-- (parent_id, PERIOD valid_at) REFERENCES (id) +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id) +); +ERROR: foreign key uses PERIOD on the referencing table but not the referenced table +-- (parent_id) REFERENCES (id, PERIOD valid_at) +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id) + REFERENCES temporal_per (id, PERIOD valid_at) +); +ERROR: foreign key uses PERIOD on the referenced table but not the referencing table +-- with inferred PK on the referenced table: +-- (parent_id, PERIOD valid_at) REFERENCES [implicit] +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per +); +DROP TABLE temporal_fk_rng2per; +-- (parent_id) REFERENCES [implicit] +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id) + REFERENCES temporal_per +); +ERROR: foreign key uses PERIOD on the referenced table but not the referencing table +-- should fail because of duplicate referenced columns: +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, PERIOD parent_id) + REFERENCES temporal_per (id, PERIOD id) +); +ERROR: foreign key referenced-columns list must not contain duplicates +-- Two scalar columns +DROP TABLE temporal_per2 CASCADE; +NOTICE: drop cascades to constraint temporal_fk2_per2per_fk on table temporal_fk2_per2per +CREATE TABLE temporal_per2 ( + id1 int4range, + id2 int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_per2_pk PRIMARY KEY (id1, id2, valid_at WITHOUT OVERLAPS) +); +CREATE TABLE temporal_fk2_rng2per ( + id int4range, + valid_at daterange, + parent_id1 int4range, + parent_id2 int4range, + CONSTRAINT temporal_fk2_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk2_rng2per_fk FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 (id1, id2, PERIOD valid_at) +); +\d temporal_fk2_rng2per + Table "public.temporal_fk2_rng2per" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | not null | + valid_at | daterange | | not null | + parent_id1 | int4range | | | + parent_id2 | int4range | | | +Indexes: + "temporal_fk2_rng2per_pk" PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +Foreign-key constraints: + "temporal_fk2_rng2per_fk" FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) REFERENCES temporal_per2(id1, id2, PERIOD valid_at) + +DROP TABLE temporal_fk2_rng2per; +-- +-- test ALTER TABLE ADD CONSTRAINT +-- +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id, PERIOD valid_at); +-- Two scalar columns: +CREATE TABLE temporal_fk2_rng2per ( + id int4range, + valid_at daterange, + parent_id1 int4range, + parent_id2 int4range, + CONSTRAINT temporal_fk2_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +ALTER TABLE temporal_fk2_rng2per + ADD CONSTRAINT temporal_fk2_rng2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 (id1, id2, PERIOD valid_at); +\d temporal_fk2_rng2per + Table "public.temporal_fk2_rng2per" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | not null | + valid_at | daterange | | not null | + parent_id1 | int4range | | | + parent_id2 | int4range | | | +Indexes: + "temporal_fk2_rng2per_pk" PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +Foreign-key constraints: + "temporal_fk2_rng2per_fk" FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) REFERENCES temporal_per2(id1, id2, PERIOD valid_at) + +-- with inferred PK on the referenced table, and wrong column type: +ALTER TABLE temporal_fk_rng2per + DROP CONSTRAINT temporal_fk_rng2per_fk, + ALTER COLUMN valid_at TYPE tsrange USING tsrange(lower(valid_at), upper(valid_at)); +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +ERROR: foreign key constraint "temporal_fk_rng2per_fk" cannot be implemented +DETAIL: Key columns "valid_at" of the referencing table and "valid_at" of the referenced table are of incompatible types: tsrange and daterange. +ALTER TABLE temporal_fk_rng2per + ALTER COLUMN valid_at TYPE daterange USING daterange(lower(valid_at)::date, upper(valid_at)::date); +-- with inferred PK on the referenced table: +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +-- should fail because of duplicate referenced columns: +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk2 + FOREIGN KEY (parent_id, PERIOD parent_id) + REFERENCES temporal_per (id, PERIOD id); +ERROR: foreign key referenced-columns list must not contain duplicates +-- +-- test with rows already +-- +DELETE FROM temporal_fk_rng2per; +DELETE FROM temporal_per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[1,2)', '2018-01-02', '2018-02-03'), + ('[1,2)', '2018-03-03', '2018-04-04'), + ('[2,3)', '2018-01-01', '2018-01-05'), + ('[3,4)', '2018-01-01', NULL); +ALTER TABLE temporal_fk_rng2per + DROP CONSTRAINT temporal_fk_rng2per_fk; +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[1,2)', '[2018-01-02,2018-02-01)', '[1,2)'); +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +ALTER TABLE temporal_fk_rng2per + DROP CONSTRAINT temporal_fk_rng2per_fk; +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[2,3)', '[2018-01-02,2018-04-01)', '[1,2)'); +-- should fail: +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +ERROR: insert or update on table "temporal_fk_rng2per" violates foreign key constraint "temporal_fk_rng2per_fk" +DETAIL: Key (parent_id, valid_at)=([1,2), [2018-01-02,2018-04-01)) is not present in table "temporal_per". +-- okay again: +DELETE FROM temporal_fk_rng2per; +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +-- +-- test pg_get_constraintdef +-- +SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_fk_rng2per_fk'; + pg_get_constraintdef +--------------------------------------------------------------------------------------- + FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_per(id, PERIOD valid_at) +(1 row) + +-- +-- test FK referencing inserts +-- +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[1,2)', '[2018-01-02,2018-02-01)', '[1,2)'); +-- should fail: +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[2,3)', '[2018-01-02,2018-04-01)', '[1,2)'); +ERROR: insert or update on table "temporal_fk_rng2per" violates foreign key constraint "temporal_fk_rng2per_fk" +DETAIL: Key (parent_id, valid_at)=([1,2), [2018-01-02,2018-04-01)) is not present in table "temporal_per". +-- now it should work: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2018-02-03', '2018-03-03'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[2,3)', '[2018-01-02,2018-04-01)', '[1,2)'); +-- +-- test FK referencing updates +-- +-- slide the edge across a referenced transition: +UPDATE temporal_fk_rng2per SET valid_at = '[2018-01-02,2018-02-20)' WHERE id = '[1,2)'; +-- should fail: +UPDATE temporal_fk_rng2per SET valid_at = '[2018-01-02,2018-05-01)' WHERE id = '[1,2)'; +ERROR: insert or update on table "temporal_fk_rng2per" violates foreign key constraint "temporal_fk_rng2per_fk" +DETAIL: Key (parent_id, valid_at)=([1,2), [2018-01-02,2018-05-01)) is not present in table "temporal_per". +UPDATE temporal_fk_rng2per SET parent_id = '[8,9)' WHERE id = '[1,2)'; +ERROR: insert or update on table "temporal_fk_rng2per" violates foreign key constraint "temporal_fk_rng2per_fk" +DETAIL: Key (parent_id, valid_at)=([8,9), [2018-01-02,2018-02-20)) is not present in table "temporal_per". +-- ALTER FK DEFERRABLE +BEGIN; + INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[5,6)', '2018-01-01', '2018-02-01'), + ('[5,6)', '2018-02-01', '2018-03-01'); + INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES + ('[3,4)', '[2018-01-05,2018-01-10)', '[5,6)'); + ALTER TABLE temporal_fk_rng2per + ALTER CONSTRAINT temporal_fk_rng2per_fk + DEFERRABLE INITIALLY DEFERRED; + DELETE FROM temporal_per WHERE id = '[5,6)'; --should not fail yet. +COMMIT; -- should fail here. +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_rng2per_fk" on table "temporal_fk_rng2per" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_rng2per". +-- +-- test FK referenced updates NO ACTION +-- +TRUNCATE temporal_per, temporal_fk_rng2per; +ALTER TABLE temporal_fk_rng2per + DROP CONSTRAINT temporal_fk_rng2per_fk; +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON UPDATE NO ACTION; +-- a PK update that succeeds because the numeric id isn't referenced: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[5,6)', '2018-01-01', '2018-02-01'); +UPDATE temporal_per SET valid_from = '2016-01-01', valid_til = '2016-02-01' WHERE id = '[5,6)'; +-- a PK update that succeeds even though the numeric id is referenced because the range isn't: +DELETE FROM temporal_per WHERE id = '[5,6)'; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[5,6)', '2018-01-01', '2018-02-01'), + ('[5,6)', '2018-02-01', '2018-03-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES + ('[3,4)', '[2018-01-05,2018-01-10)', '[5,6)'); +UPDATE temporal_per SET valid_from = '2016-02-01', valid_til = '2016-03-01' +WHERE id = '[5,6)' AND valid_from = '2018-02-01' AND valid_til = '2018-03-01'; +-- A PK update sliding the edge between two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[6,7)', '2018-01-01', '2018-02-01'), + ('[6,7)', '2018-02-01', '2018-03-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES + ('[4,5)', '[2018-01-15,2018-02-15)', '[6,7)'); +UPDATE temporal_per +SET valid_from = CASE WHEN valid_from = '2018-01-01' THEN '2018-01-01' + WHEN valid_from = '2018-02-01' THEN '2018-01-05' END::date, + valid_til = CASE WHEN valid_from = '2018-01-01' THEN '2018-01-05' + WHEN valid_from = '2018-02-01' THEN '2018-03-01' END::date +WHERE id = '[6,7)'; +-- a PK update shrinking the referenced range but still valid: +-- There are two references: one fulfilled by the first pk row, +-- the other fulfilled by both pk rows combined. +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[1,2)', '2018-01-01', '2018-03-01'), + ('[1,2)', '2018-03-01', '2018-06-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES + ('[1,2)', '[2018-01-15,2018-02-01)', '[1,2)'), + ('[2,3)', '[2018-01-15,2018-05-01)', '[1,2)'); +UPDATE temporal_per SET valid_from = '2018-01-15', valid_til = '2018-03-01' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +-- a PK update growing the referenced range is fine: +UPDATE temporal_per SET valid_from = '2018-01-01', valid_til = '2018-03-01' +WHERE id = '[1,2)' AND valid_at @> '2018-01-25'::date; +-- a PK update shrinking the referenced range and changing the id invalidates the whole range: +UPDATE temporal_per SET id = '[2,3)', valid_from = '2018-01-15', valid_til = '2018-03-01' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_rng2per_fk" on table "temporal_fk_rng2per" +DETAIL: Key (id, valid_at)=([1,2), [2018-01-01,2018-03-01)) is still referenced from table "temporal_fk_rng2per". +-- a PK update changing only the id invalidates the whole range: +UPDATE temporal_per SET id = '[2,3)' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_rng2per_fk" on table "temporal_fk_rng2per" +DETAIL: Key (id, valid_at)=([1,2), [2018-01-01,2018-03-01)) is still referenced from table "temporal_fk_rng2per". +-- a PK update that loses time from both ends, but is still valid: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[2,3)', '2018-01-01', '2018-03-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES + ('[5,6)', '[2018-01-15,2018-02-01)', '[2,3)'); +UPDATE temporal_per SET valid_from = '2018-01-15', valid_til = '2018-02-15' +WHERE id = '[2,3)'; +-- a PK update that fails because both are referenced: +UPDATE temporal_per SET valid_from = '2016-01-01', valid_til = '2016-02-01' +WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_rng2per_fk" on table "temporal_fk_rng2per" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_rng2per". +-- a PK update that fails because both are referenced, but not 'til commit: +BEGIN; + ALTER TABLE temporal_fk_rng2per + ALTER CONSTRAINT temporal_fk_rng2per_fk + DEFERRABLE INITIALLY DEFERRED; + UPDATE temporal_per SET valid_from = '2016-01-01', valid_til = '2016-02-01' + WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); +COMMIT; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_rng2per_fk" on table "temporal_fk_rng2per" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_rng2per". +-- changing the scalar part fails: +UPDATE temporal_per SET id = '[7,8)' +WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_rng2per_fk" on table "temporal_fk_rng2per" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_rng2per". +-- changing an unreferenced part is okay: +UPDATE temporal_per +FOR PORTION OF valid_at FROM '2018-01-02' TO '2018-01-03' +SET id = '[7,8)' +WHERE id = '[5,6)'; +-- changing just a part fails: +UPDATE temporal_per +FOR PORTION OF valid_at FROM '2018-01-05' TO '2018-01-10' +SET id = '[7,8)' +WHERE id = '[5,6)'; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_rng2per_fk" on table "temporal_fk_rng2per" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-03,2018-02-01)) is still referenced from table "temporal_fk_rng2per". +SELECT * FROM temporal_per WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; + id | valid_from | valid_til +-------+------------+------------ + [5,6) | 2016-02-01 | 2016-03-01 + [5,6) | 2018-01-01 | 2018-01-02 + [5,6) | 2018-01-03 | 2018-02-01 + [7,8) | 2018-01-02 | 2018-01-03 +(4 rows) + +SELECT * FROM temporal_fk_rng2per WHERE id in ('[3,4)') ORDER BY id, valid_at; + id | valid_at | parent_id +-------+-------------------------+----------- + [3,4) | [2018-01-05,2018-01-10) | [5,6) +(1 row) + +-- then delete the objecting FK record and the same PK update succeeds: +DELETE FROM temporal_fk_rng2per WHERE id = '[3,4)'; +UPDATE temporal_per SET valid_from = '2016-01-01', valid_til = '2016-02-01' +WHERE id = '[5,6)' AND valid_at = '[2018-01-01,2018-02-01)'; +-- +-- test FK referenced updates RESTRICT +-- +TRUNCATE temporal_per, temporal_fk_rng2per; +ALTER TABLE temporal_fk_rng2per + DROP CONSTRAINT temporal_fk_rng2per_fk; +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON UPDATE RESTRICT; +ERROR: unsupported ON UPDATE action for foreign key constraint using PERIOD +-- +-- test FK referenced deletes NO ACTION +-- +TRUNCATE temporal_per, temporal_fk_rng2per; +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +-- a PK delete that succeeds because the numeric id isn't referenced: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[5,6)', '2018-01-01', '2018-02-01'); +DELETE FROM temporal_per WHERE id = '[5,6)'; +-- a PK delete that succeeds even though the numeric id is referenced because the range isn't: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[5,6)', '2018-01-01', '2018-02-01'), + ('[5,6)', '2018-02-01', '2018-03-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[3,4)', '[2018-01-05,2018-01-10)', '[5,6)'); +DELETE FROM temporal_per WHERE id = '[5,6)' AND valid_from = '2018-02-01' AND valid_til = '2018-03-01'; +-- a PK delete that fails because both are referenced: +DELETE FROM temporal_per WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_rng2per_fk" on table "temporal_fk_rng2per" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_rng2per". +-- a PK delete that fails because both are referenced, but not 'til commit: +BEGIN; + ALTER TABLE temporal_fk_rng2per + ALTER CONSTRAINT temporal_fk_rng2per_fk + DEFERRABLE INITIALLY DEFERRED; + DELETE FROM temporal_per WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); +COMMIT; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_rng2per_fk" on table "temporal_fk_rng2per" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_rng2per". +-- deleting an unreferenced part is okay: +DELETE FROM temporal_per +FOR PORTION OF valid_at FROM '2018-01-02' TO '2018-01-03' +WHERE id = '[5,6)'; +-- deleting just a part fails: +DELETE FROM temporal_per +FOR PORTION OF valid_at FROM '2018-01-05' TO '2018-01-10' +WHERE id = '[5,6)'; +ERROR: update or delete on table "temporal_per" violates foreign key constraint "temporal_fk_rng2per_fk" on table "temporal_fk_rng2per" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-03,2018-02-01)) is still referenced from table "temporal_fk_rng2per". +SELECT * FROM temporal_per WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; + id | valid_from | valid_til +-------+------------+------------ + [5,6) | 2018-01-01 | 2018-01-02 + [5,6) | 2018-01-03 | 2018-02-01 +(2 rows) + +SELECT * FROM temporal_fk_rng2per WHERE id in ('[3,4)') ORDER BY id, valid_at; + id | valid_at | parent_id +-------+-------------------------+----------- + [3,4) | [2018-01-05,2018-01-10) | [5,6) +(1 row) + +-- then delete the objecting FK record and the same PK delete succeeds: +DELETE FROM temporal_fk_rng2per WHERE id = '[3,4)'; +DELETE FROM temporal_per WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; +-- +-- test FK referenced deletes RESTRICT +-- +TRUNCATE temporal_per, temporal_fk_rng2per; +ALTER TABLE temporal_fk_rng2per + DROP CONSTRAINT temporal_fk_rng2per_fk; +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON DELETE RESTRICT; +ERROR: unsupported ON DELETE action for foreign key constraint using PERIOD +-- +-- rng2per test ON UPDATE/DELETE options +-- +-- TOC: +-- referenced updates CASCADE +-- referenced deletes CASCADE +-- referenced updates SET NULL +-- referenced deletes SET NULL +-- referenced updates SET DEFAULT +-- referenced deletes SET DEFAULT +-- referenced updates CASCADE (two scalar cols) +-- referenced deletes CASCADE (two scalar cols) +-- referenced updates SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- referenced updates SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) +-- +-- test FK referenced updates CASCADE +-- +TRUNCATE temporal_per, temporal_fk_rng2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)'); +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [7,8) + [100,101) | [2020-01-01,2021-01-01) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_per SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [7,8) + [100,101) | [2019-01-01,2020-01-01) | [7,8) + [100,101) | [2020-01-01,2021-01-01) | [7,8) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)'); +UPDATE temporal_per SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [200,201) | [2018-01-01,2020-01-01) | [9,10) + [200,201) | [2020-01-01,2021-01-01) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes CASCADE +-- +TRUNCATE temporal_per, temporal_fk_rng2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [6,7) + [100,101) | [2020-01-01,2021-01-01) | [6,7) +(2 rows) + +-- non-FPO delete: +DELETE FROM temporal_per WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id +----+----------+----------- +(0 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)'); +DELETE FROM temporal_per WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [200,201) | [2020-01-01,2021-01-01) | [8,9) +(1 row) + +-- +-- test FK referenced updates SET NULL +-- +TRUNCATE temporal_per, temporal_fk_rng2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)'); +ALTER TABLE temporal_fk_rng2per + DROP CONSTRAINT temporal_fk_rng2per_fk, + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | + [100,101) | [2020-01-01,2021-01-01) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_per SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | + [100,101) | [2019-01-01,2020-01-01) | + [100,101) | [2020-01-01,2021-01-01) | +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)'); +UPDATE temporal_per SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [200,201) | [2018-01-01,2020-01-01) | + [200,201) | [2020-01-01,2021-01-01) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET NULL +-- +TRUNCATE temporal_per, temporal_fk_rng2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | + [100,101) | [2020-01-01,2021-01-01) | [6,7) +(3 rows) + +-- non-FPO delete: +DELETE FROM temporal_per WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | + [100,101) | [2019-01-01,2020-01-01) | + [100,101) | [2020-01-01,2021-01-01) | +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)'); +DELETE FROM temporal_per WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [200,201) | [2018-01-01,2020-01-01) | + [200,201) | [2020-01-01,2021-01-01) | [8,9) +(2 rows) + +-- +-- test FK referenced updates SET DEFAULT +-- +TRUNCATE temporal_per, temporal_fk_rng2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[-1,-1]', null, null); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)'); +ALTER TABLE temporal_fk_rng2per + ALTER COLUMN parent_id SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk_rng2per_fk, + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) + [100,101) | [2020-01-01,2021-01-01) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_per SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [-1,0) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) + [100,101) | [2020-01-01,2021-01-01) | [-1,0) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)'); +UPDATE temporal_per SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [200,201) | [2018-01-01,2020-01-01) | [-1,0) + [200,201) | [2020-01-01,2021-01-01) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET DEFAULT +-- +TRUNCATE temporal_per, temporal_fk_rng2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[-1,-1]', null, null); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) + [100,101) | [2020-01-01,2021-01-01) | [6,7) +(3 rows) + +-- non-FPO update: +DELETE FROM temporal_per WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [100,101) | [2018-01-01,2019-01-01) | [-1,0) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) + [100,101) | [2020-01-01,2021-01-01) | [-1,0) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)'); +DELETE FROM temporal_per WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_at | parent_id +-----------+-------------------------+----------- + [200,201) | [2018-01-01,2020-01-01) | [-1,0) + [200,201) | [2020-01-01,2021-01-01) | [8,9) +(2 rows) + +-- +-- test FK referenced updates CASCADE (two scalar cols) +-- +TRUNCATE temporal_per2, temporal_fk2_rng2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_rng2per + DROP CONSTRAINT temporal_fk2_rng2per_fk, + ADD CONSTRAINT temporal_fk2_rng2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [6,7) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [7,8) | [6,7) + [100,101) | [2020-01-01,2021-01-01) | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_per2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [7,8) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [7,8) | [6,7) + [100,101) | [2020-01-01,2021-01-01) | [7,8) | [6,7) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)', '[8,9)'); +UPDATE temporal_per2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [200,201) | [2018-01-01,2020-01-01) | [9,10) | [8,9) + [200,201) | [2020-01-01,2021-01-01) | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes CASCADE (two scalar cols) +-- +TRUNCATE temporal_per2, temporal_fk2_rng2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [6,7) | [6,7) + [100,101) | [2020-01-01,2021-01-01) | [6,7) | [6,7) +(2 rows) + +-- non-FPO delete: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +----+----------+------------+------------ +(0 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [200,201) | [2020-01-01,2021-01-01) | [8,9) | [8,9) +(1 row) + +-- +-- test FK referenced updates SET NULL (two scalar cols) +-- +TRUNCATE temporal_per2, temporal_fk2_rng2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_rng2per + DROP CONSTRAINT temporal_fk2_rng2per_fk, + ADD CONSTRAINT temporal_fk2_rng2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [6,7) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | | + [100,101) | [2020-01-01,2021-01-01) | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_per2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | | + [100,101) | [2019-01-01,2020-01-01) | | + [100,101) | [2020-01-01,2021-01-01) | | +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)', '[8,9)'); +UPDATE temporal_per2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [200,201) | [2018-01-01,2020-01-01) | | + [200,201) | [2020-01-01,2021-01-01) | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET NULL (two scalar cols) +-- +TRUNCATE temporal_per2, temporal_fk2_rng2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [6,7) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | | + [100,101) | [2020-01-01,2021-01-01) | [6,7) | [6,7) +(3 rows) + +-- non-FPO delete: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | | + [100,101) | [2019-01-01,2020-01-01) | | + [100,101) | [2020-01-01,2021-01-01) | | +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [200,201) | [2018-01-01,2020-01-01) | | + [200,201) | [2020-01-01,2021-01-01) | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- +TRUNCATE temporal_per2, temporal_fk2_rng2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_rng2per + DROP CONSTRAINT temporal_fk2_rng2per_fk, + ADD CONSTRAINT temporal_fk2_rng2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET NULL (valid_at) ON UPDATE SET NULL; +ERROR: column "valid_at" referenced in ON DELETE SET action cannot be PERIOD +-- ok: +ALTER TABLE temporal_fk2_rng2per + DROP CONSTRAINT temporal_fk2_rng2per_fk, + ADD CONSTRAINT temporal_fk2_rng2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET NULL (parent_id1) ON UPDATE SET NULL; +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [6,7) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | | [6,7) + [100,101) | [2020-01-01,2021-01-01) | [6,7) | [6,7) +(3 rows) + +-- non-FPO delete: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | | [6,7) + [100,101) | [2019-01-01,2020-01-01) | | [6,7) + [100,101) | [2020-01-01,2021-01-01) | | [6,7) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [200,201) | [2018-01-01,2020-01-01) | | [8,9) + [200,201) | [2020-01-01,2021-01-01) | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced updates SET DEFAULT (two scalar cols) +-- +TRUNCATE temporal_per2, temporal_fk2_rng2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[-1,-1]', '[-1,-1]', null, null); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_rng2per + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + ALTER COLUMN parent_id2 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_rng2per_fk, + ADD CONSTRAINT temporal_fk2_rng2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [6,7) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) | [-1,0) + [100,101) | [2020-01-01,2021-01-01) | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_per2 SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [-1,0) | [-1,0) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) | [-1,0) + [100,101) | [2020-01-01,2021-01-01) | [-1,0) | [-1,0) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)', '[8,9)'); +UPDATE temporal_per2 SET id1 = '[9,10)', id2 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [200,201) | [2018-01-01,2020-01-01) | [-1,0) | [-1,0) + [200,201) | [2020-01-01,2021-01-01) | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols) +-- +TRUNCATE temporal_per2, temporal_fk2_rng2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[-1,-1]', '[-1,-1]', null, null); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [6,7) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) | [-1,0) + [100,101) | [2020-01-01,2021-01-01) | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [-1,0) | [-1,0) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) | [-1,0) + [100,101) | [2020-01-01,2021-01-01) | [-1,0) | [-1,0) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [200,201) | [2018-01-01,2020-01-01) | [-1,0) | [-1,0) + [200,201) | [2020-01-01,2021-01-01) | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) +-- +TRUNCATE temporal_per2, temporal_fk2_rng2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[-1,-1]', '[6,7)', null, null); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_rng2per + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_rng2per_fk, + ADD CONSTRAINT temporal_fk2_rng2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET DEFAULT (valid_at) ON UPDATE SET DEFAULT; +ERROR: column "valid_at" referenced in ON DELETE SET action cannot be PERIOD +-- ok: +ALTER TABLE temporal_fk2_rng2per + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_rng2per_fk, + ADD CONSTRAINT temporal_fk2_rng2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET DEFAULT (parent_id1) ON UPDATE SET DEFAULT; +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [6,7) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) | [6,7) + [100,101) | [2020-01-01,2021-01-01) | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [100,101) | [2018-01-01,2019-01-01) | [-1,0) | [6,7) + [100,101) | [2019-01-01,2020-01-01) | [-1,0) | [6,7) + [100,101) | [2020-01-01,2021-01-01) | [-1,0) | [6,7) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[-1,-1]', '[8,9)', null, null); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_at | parent_id1 | parent_id2 +-----------+-------------------------+------------+------------ + [200,201) | [2018-01-01,2020-01-01) | [-1,0) | [8,9) + [200,201) | [2020-01-01,2021-01-01) | [8,9) | [8,9) +(2 rows) + +-- +-- test FOREIGN KEY, PERIOD references range +-- +-- test table setup +DROP TABLE temporal_rng CASCADE; +NOTICE: drop cascades to constraint temporal_fk_rng2rng_fk on table temporal_fk_rng2rng +CREATE TABLE temporal_rng ( + id int4range, + valid_at daterange +); +ALTER TABLE temporal_rng + ADD CONSTRAINT temporal_rng_pk + PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); +-- Can't create a FK with a mismatched range type +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from int, + valid_til int, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng (id, PERIOD valid_at) +); +ERROR: foreign key constraint "temporal_fk_per2rng_fk" cannot be implemented +DETAIL: Key columns "valid_at" of the referencing table and "valid_at" of the referenced table are of incompatible types: int4range and daterange. +-- works: range for referenced, PERIOD for referencing +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng (id, PERIOD valid_at) +); +\d temporal_fk_per2rng + Table "public.temporal_fk_per2rng" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | not null | + valid_from | date | | | + valid_til | date | | | + parent_id | int4range | | | +Periods: + valid_at (valid_from, valid_til) +Indexes: + "temporal_fk_per2rng_pk" PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +Check constraints: + "temporal_fk_per2rng_valid_at_check" CHECK (valid_from < valid_til) +Foreign-key constraints: + "temporal_fk_per2rng_fk" FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_rng(id, PERIOD valid_at) + +DROP TABLE temporal_fk_per2rng; +-- with mismatched PERIOD columns: +-- (parent_id, PERIOD valid_at) REFERENCES (id, valid_at) +-- REFERENCES part should specify PERIOD +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng (id, valid_at) +); +ERROR: foreign key uses PERIOD on the referencing table but not the referenced table +-- (parent_id, valid_at) REFERENCES (id, valid_at) +-- both should specify PERIOD: +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_rng (id, valid_at) +); +ERROR: foreign key must use PERIOD when referencing a primary key using WITHOUT OVERLAPS +-- (parent_id, valid_at) REFERENCES (id, PERIOD valid_at) +-- FOREIGN KEY part should specify PERIOD +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_rng (id, PERIOD valid_at) +); +ERROR: foreign key uses PERIOD on the referenced table but not the referencing table +-- (parent_id, valid_at) REFERENCES [implicit] +-- FOREIGN KEY part should specify PERIOD +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_rng +); +ERROR: foreign key uses PERIOD on the referenced table but not the referencing table +-- (parent_id, PERIOD valid_at) REFERENCES (id) +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng (id) +); +ERROR: foreign key uses PERIOD on the referencing table but not the referenced table +-- (parent_id) REFERENCES (id, PERIOD valid_at) +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id) + REFERENCES temporal_rng (id, PERIOD valid_at) +); +ERROR: foreign key uses PERIOD on the referenced table but not the referencing table +-- with inferred PK on the referenced table: +-- (parent_id, PERIOD valid_at) REFERENCES [implicit] +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng +); +DROP TABLE temporal_fk_per2rng; +-- (parent_id) REFERENCES [implicit] +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id) + REFERENCES temporal_rng +); +ERROR: foreign key uses PERIOD on the referenced table but not the referencing table +-- should fail because of duplicate referenced columns: +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, PERIOD parent_id) + REFERENCES temporal_rng (id, PERIOD id) +); +ERROR: foreign key referenced-columns list must not contain duplicates +-- Two scalar columns +DROP TABLE temporal_rng2 CASCADE; +NOTICE: drop cascades to constraint temporal_fk2_rng2rng_fk on table temporal_fk2_rng2rng +CREATE TABLE temporal_rng2 ( + id1 int4range, + id2 int4range, + valid_at daterange, + CONSTRAINT temporal_rng2_pk PRIMARY KEY (id1, id2, valid_at WITHOUT OVERLAPS) +); +CREATE TABLE temporal_fk2_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id1 int4range, + parent_id2 int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk2_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk2_per2rng_fk FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 (id1, id2, PERIOD valid_at) +); +\d temporal_fk2_per2rng + Table "public.temporal_fk2_per2rng" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | not null | + valid_from | date | | | + valid_til | date | | | + parent_id1 | int4range | | | + parent_id2 | int4range | | | +Periods: + valid_at (valid_from, valid_til) +Indexes: + "temporal_fk2_per2rng_pk" PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +Check constraints: + "temporal_fk2_per2rng_valid_at_check" CHECK (valid_from < valid_til) +Foreign-key constraints: + "temporal_fk2_per2rng_fk" FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) REFERENCES temporal_rng2(id1, id2, PERIOD valid_at) + +DROP TABLE temporal_fk2_per2rng; +-- +-- test ALTER TABLE ADD CONSTRAINT +-- +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng (id, PERIOD valid_at); +-- Two scalar columns: +CREATE TABLE temporal_fk2_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id1 int4range, + parent_id2 int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk2_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +ALTER TABLE temporal_fk2_per2rng + ADD CONSTRAINT temporal_fk2_per2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 (id1, id2, PERIOD valid_at); +\d temporal_fk2_per2rng + Table "public.temporal_fk2_per2rng" + Column | Type | Collation | Nullable | Default +------------+-----------+-----------+----------+--------- + id | int4range | | not null | + valid_from | date | | | + valid_til | date | | | + parent_id1 | int4range | | | + parent_id2 | int4range | | | +Periods: + valid_at (valid_from, valid_til) +Indexes: + "temporal_fk2_per2rng_pk" PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +Check constraints: + "temporal_fk2_per2rng_valid_at_check" CHECK (valid_from < valid_til) +Foreign-key constraints: + "temporal_fk2_per2rng_fk" FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) REFERENCES temporal_rng2(id1, id2, PERIOD valid_at) + +-- with inferred PK on the referenced table, and wrong column type: +ALTER TABLE temporal_fk_per2rng + DROP CONSTRAINT temporal_fk_per2rng_fk, + DROP PERIOD FOR valid_at, + ALTER COLUMN valid_from TYPE timestamp, + ALTER COLUMN valid_til TYPE timestamp, + ADD PERIOD FOR valid_at (valid_from, valid_til); +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng; +ERROR: foreign key constraint "temporal_fk_per2rng_fk" cannot be implemented +DETAIL: Key columns "valid_at" of the referencing table and "valid_at" of the referenced table are of incompatible types: tsrange and daterange. +ALTER TABLE temporal_fk_per2rng + DROP PERIOD FOR valid_at, + ALTER COLUMN valid_from TYPE date, + ALTER COLUMN valid_til TYPE date, + ADD PERIOD FOR valid_at (valid_from, valid_til); +-- with inferred PK on the referenced table: +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng; +-- should fail because of duplicate referenced columns: +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk2 + FOREIGN KEY (parent_id, PERIOD parent_id) + REFERENCES temporal_rng (id, PERIOD id); +ERROR: foreign key referenced-columns list must not contain duplicates +-- +-- test with rows already +-- +DELETE FROM temporal_fk_per2rng; +DELETE FROM temporal_rng; +INSERT INTO temporal_rng (id, valid_at) VALUES + ('[1,2)', '[2018-01-02,2018-02-03)'), + ('[1,2)', '[2018-03-03,2018-04-04)'), + ('[2,3)', '[2018-01-01,2018-01-05)'), + ('[3,4)', '[2018-01-01,)'); +ALTER TABLE temporal_fk_per2rng + DROP CONSTRAINT temporal_fk_per2rng_fk; +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[1,2)', '2018-01-02', '2018-02-01', '[1,2)'); +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng; +ALTER TABLE temporal_fk_per2rng + DROP CONSTRAINT temporal_fk_per2rng_fk; +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[2,3)', '2018-01-02', '2018-04-01', '[1,2)'); +-- should fail: +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng; +ERROR: insert or update on table "temporal_fk_per2rng" violates foreign key constraint "temporal_fk_per2rng_fk" +DETAIL: Key (parent_id, valid_at)=([1,2), [2018-01-02,2018-04-01)) is not present in table "temporal_rng". +-- okay again: +DELETE FROM temporal_fk_per2rng; +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng; +-- +-- test pg_get_constraintdef +-- +SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_fk_per2rng_fk'; + pg_get_constraintdef +--------------------------------------------------------------------------------------- + FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_rng(id, PERIOD valid_at) +(1 row) + +-- +-- test FK referencing inserts +-- +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[1,2)', '2018-01-02', '2018-02-01', '[1,2)'); +-- should fail: +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[2,3)', '2018-01-02', '2018-04-01', '[1,2)'); +ERROR: insert or update on table "temporal_fk_per2rng" violates foreign key constraint "temporal_fk_per2rng_fk" +DETAIL: Key (parent_id, valid_at)=([1,2), [2018-01-02,2018-04-01)) is not present in table "temporal_rng". +-- now it should work: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[1,2)', '[2018-02-03,2018-03-03)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[2,3)', '2018-01-02', '2018-04-01', '[1,2)'); +-- +-- test FK referencing updates +-- +-- slide the edge across a referenced transition: +UPDATE temporal_fk_per2rng SET valid_from = '2018-01-02', valid_til = '2018-02-20' WHERE id = '[1,2)'; +-- should fail: +UPDATE temporal_fk_per2rng SET valid_from = '2018-01-02', valid_til = '2018-05-01' WHERE id = '[1,2)'; +ERROR: insert or update on table "temporal_fk_per2rng" violates foreign key constraint "temporal_fk_per2rng_fk" +DETAIL: Key (parent_id, valid_at)=([1,2), [2018-01-02,2018-05-01)) is not present in table "temporal_rng". +UPDATE temporal_fk_per2rng SET parent_id = '[8,9)' WHERE id = '[1,2)'; +ERROR: insert or update on table "temporal_fk_per2rng" violates foreign key constraint "temporal_fk_per2rng_fk" +DETAIL: Key (parent_id, valid_at)=([8,9), [2018-01-02,2018-02-20)) is not present in table "temporal_rng". +-- ALTER FK DEFERRABLE +BEGIN; + INSERT INTO temporal_rng (id, valid_at) VALUES + ('[5,6)', '[2018-01-01,2018-02-01)'), + ('[5,6)', '[2018-02-01,2018-03-01)'); + INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES + ('[3,4)', '2018-01-05', '2018-01-10', '[5,6)'); + ALTER TABLE temporal_fk_per2rng + ALTER CONSTRAINT temporal_fk_per2rng_fk + DEFERRABLE INITIALLY DEFERRED; + DELETE FROM temporal_rng WHERE id = '[5,6)'; --should not fail yet. +COMMIT; -- should fail here. +ERROR: update or delete on table "temporal_rng" violates foreign key constraint "temporal_fk_per2rng_fk" on table "temporal_fk_per2rng" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_per2rng". +-- +-- test FK referenced updates NO ACTION +-- +TRUNCATE temporal_rng, temporal_fk_per2rng; +ALTER TABLE temporal_fk_per2rng + DROP CONSTRAINT temporal_fk_per2rng_fk; +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng + ON UPDATE NO ACTION; +-- a PK update that succeeds because the numeric id isn't referenced: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[5,6)', '[2018-01-01,2018-02-01)'); +UPDATE temporal_rng SET valid_at = '[2016-01-01,2016-02-01)' WHERE id = '[5,6)'; +-- a PK update that succeeds even though the numeric id is referenced because the range isn't: +DELETE FROM temporal_rng WHERE id = '[5,6)'; +INSERT INTO temporal_rng (id, valid_at) VALUES + ('[5,6)', '[2018-01-01,2018-02-01)'), + ('[5,6)', '[2018-02-01,2018-03-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES + ('[3,4)', '2018-01-05', '2018-01-10', '[5,6)'); +UPDATE temporal_rng SET valid_at = '[2016-02-01,2016-03-01)' +WHERE id = '[5,6)' AND valid_at = '[2018-02-01,2018-03-01)'; +-- A PK update sliding the edge between two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES + ('[6,7)', '[2018-01-01,2018-02-01)'), + ('[6,7)', '[2018-02-01,2018-03-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES + ('[4,5)', '2018-01-15', '2018-02-15', '[6,7)'); +UPDATE temporal_rng +SET valid_at = CASE WHEN lower(valid_at) = '2018-01-01' THEN daterange('2018-01-01', '2018-01-05') + WHEN lower(valid_at) = '2018-02-01' THEN daterange('2018-01-05', '2018-03-01') END +WHERE id = '[6,7)'; +-- a PK update shrinking the referenced range but still valid: +-- There are two references: one fulfilled by the first pk row, +-- the other fulfilled by both pk rows combined. +INSERT INTO temporal_rng (id, valid_at) VALUES + ('[1,2)', '[2018-01-01,2018-03-01)'), + ('[1,2)', '[2018-03-01,2018-06-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES + ('[1,2)', '2018-01-15', '2018-02-01', '[1,2)'), + ('[2,3)', '2018-01-15', '2018-05-01', '[1,2)'); +UPDATE temporal_rng SET valid_at = '[2018-01-15,2018-03-01)' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +-- a PK update growing the referenced range is fine: +UPDATE temporal_rng SET valid_at = '[2018-01-01,2018-03-01)' +WHERE id = '[1,2)' AND valid_at @> '2018-01-25'::date; +-- a PK update shrinking the referenced range and changing the id invalidates the whole range: +UPDATE temporal_rng SET id = '[2,3)', valid_at = '[2018-01-15,2018-03-01)' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +ERROR: update or delete on table "temporal_rng" violates foreign key constraint "temporal_fk_per2rng_fk" on table "temporal_fk_per2rng" +DETAIL: Key (id, valid_at)=([1,2), [2018-01-01,2018-03-01)) is still referenced from table "temporal_fk_per2rng". +-- a PK update changing only the id invalidates the whole range: +UPDATE temporal_rng SET id = '[2,3)' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +ERROR: update or delete on table "temporal_rng" violates foreign key constraint "temporal_fk_per2rng_fk" on table "temporal_fk_per2rng" +DETAIL: Key (id, valid_at)=([1,2), [2018-01-01,2018-03-01)) is still referenced from table "temporal_fk_per2rng". +-- a PK update that loses time from both ends, but is still valid: +INSERT INTO temporal_rng (id, valid_at) VALUES + ('[2,3)', '[2018-01-01,2018-03-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES + ('[5,6)', '2018-01-15', '2018-02-01', '[2,3)'); +UPDATE temporal_rng SET valid_at = '[2018-01-15,2018-02-15)' +WHERE id = '[2,3)'; +-- a PK update that fails because both are referenced: +UPDATE temporal_rng SET valid_at = '[2016-01-01,2016-02-01)' +WHERE id = '[5,6)' AND valid_at = '[2018-01-01,2018-02-01)'; +ERROR: update or delete on table "temporal_rng" violates foreign key constraint "temporal_fk_per2rng_fk" on table "temporal_fk_per2rng" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_per2rng". +-- a PK update that fails because both are referenced, but not 'til commit: +BEGIN; + ALTER TABLE temporal_fk_per2rng + ALTER CONSTRAINT temporal_fk_per2rng_fk + DEFERRABLE INITIALLY DEFERRED; + UPDATE temporal_rng SET valid_at = '[2016-01-01,2016-02-01)' + WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); +COMMIT; +ERROR: update or delete on table "temporal_rng" violates foreign key constraint "temporal_fk_per2rng_fk" on table "temporal_fk_per2rng" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_per2rng". +-- changing the scalar part fails: +UPDATE temporal_rng SET id = '[7,8)' +WHERE id = '[5,6)' AND valid_at = '[2018-01-01,2018-02-01)'; +ERROR: update or delete on table "temporal_rng" violates foreign key constraint "temporal_fk_per2rng_fk" on table "temporal_fk_per2rng" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_per2rng". +-- changing an unreferenced part is okay: +UPDATE temporal_rng +FOR PORTION OF valid_at FROM '2018-01-02' TO '2018-01-03' +SET id = '[7,8)' +WHERE id = '[5,6)'; +-- changing just a part fails: +UPDATE temporal_rng +FOR PORTION OF valid_at FROM '2018-01-05' TO '2018-01-10' +SET id = '[7,8)' +WHERE id = '[5,6)'; +ERROR: update or delete on table "temporal_rng" violates foreign key constraint "temporal_fk_per2rng_fk" on table "temporal_fk_per2rng" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-03,2018-02-01)) is still referenced from table "temporal_fk_per2rng". +SELECT * FROM temporal_rng WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; + id | valid_at +-------+------------------------- + [5,6) | [2016-02-01,2016-03-01) + [5,6) | [2018-01-01,2018-01-02) + [5,6) | [2018-01-03,2018-02-01) + [7,8) | [2018-01-02,2018-01-03) +(4 rows) + +SELECT * FROM temporal_fk_per2rng WHERE id in ('[3,4)') ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-------+------------+------------+----------- + [3,4) | 2018-01-05 | 2018-01-10 | [5,6) +(1 row) + +-- then delete the objecting FK record and the same PK update succeeds: +DELETE FROM temporal_fk_per2rng WHERE id = '[3,4)'; +UPDATE temporal_rng SET valid_at = '[2016-01-01,2016-02-01)' +WHERE id = '[5,6)' AND valid_at = '[2018-01-01,2018-02-01)'; +-- +-- test FK referenced updates RESTRICT +-- +TRUNCATE temporal_rng, temporal_fk_per2rng; +ALTER TABLE temporal_fk_per2rng + DROP CONSTRAINT temporal_fk_per2rng_fk; +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng + ON UPDATE RESTRICT; +ERROR: unsupported ON UPDATE action for foreign key constraint using PERIOD +-- +-- test FK referenced deletes NO ACTION +-- +TRUNCATE temporal_rng, temporal_fk_per2rng; +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng; +-- a PK delete that succeeds because the numeric id isn't referenced: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[5,6)', '[2018-01-01,2018-02-01)'); +DELETE FROM temporal_rng WHERE id = '[5,6)'; +-- a PK delete that succeeds even though the numeric id is referenced because the range isn't: +INSERT INTO temporal_rng (id, valid_at) VALUES + ('[5,6)', '[2018-01-01,2018-02-01)'), + ('[5,6)', '[2018-02-01,2018-03-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[3,4)', '2018-01-05', '2018-01-10', '[5,6)'); +DELETE FROM temporal_rng WHERE id = '[5,6)' AND valid_at = '[2018-02-01,2018-03-01)'; +-- a PK delete that fails because both are referenced: +DELETE FROM temporal_rng WHERE id = '[5,6)' AND valid_at = '[2018-01-01,2018-02-01)'; +ERROR: update or delete on table "temporal_rng" violates foreign key constraint "temporal_fk_per2rng_fk" on table "temporal_fk_per2rng" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_per2rng". +-- a PK delete that fails because both are referenced, but not 'til commit: +BEGIN; + ALTER TABLE temporal_fk_per2rng + ALTER CONSTRAINT temporal_fk_per2rng_fk + DEFERRABLE INITIALLY DEFERRED; + DELETE FROM temporal_rng WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); +COMMIT; +ERROR: update or delete on table "temporal_rng" violates foreign key constraint "temporal_fk_per2rng_fk" on table "temporal_fk_per2rng" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-01,2018-02-01)) is still referenced from table "temporal_fk_per2rng". +-- deleting an unreferenced part is okay: +DELETE FROM temporal_rng +FOR PORTION OF valid_at FROM '2018-01-02' TO '2018-01-03' +WHERE id = '[5,6)'; +-- deleting just a part fails: +DELETE FROM temporal_rng +FOR PORTION OF valid_at FROM '2018-01-05' TO '2018-01-10' +WHERE id = '[5,6)'; +ERROR: update or delete on table "temporal_rng" violates foreign key constraint "temporal_fk_per2rng_fk" on table "temporal_fk_per2rng" +DETAIL: Key (id, valid_at)=([5,6), [2018-01-03,2018-02-01)) is still referenced from table "temporal_fk_per2rng". +SELECT * FROM temporal_rng WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; + id | valid_at +-------+------------------------- + [5,6) | [2018-01-01,2018-01-02) + [5,6) | [2018-01-03,2018-02-01) +(2 rows) + +SELECT * FROM temporal_fk_per2rng WHERE id in ('[3,4)') ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-------+------------+------------+----------- + [3,4) | 2018-01-05 | 2018-01-10 | [5,6) +(1 row) + +-- then delete the objecting FK record and the same PK delete succeeds: +DELETE FROM temporal_fk_per2rng WHERE id = '[3,4)'; +DELETE FROM temporal_rng WHERE id = '[5,6)' AND valid_at = '[2018-01-01,2018-02-01)'; +-- +-- test FK referenced deletes RESTRICT +-- +TRUNCATE temporal_rng, temporal_fk_per2rng; +ALTER TABLE temporal_fk_per2rng + DROP CONSTRAINT temporal_fk_per2rng_fk; +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng + ON DELETE RESTRICT; +ERROR: unsupported ON DELETE action for foreign key constraint using PERIOD +-- +-- per2rng test ON UPDATE/DELETE options +-- +-- TOC: +-- referenced updates CASCADE +-- referenced deletes CASCADE +-- referenced updates SET NULL +-- referenced deletes SET NULL +-- referenced updates SET DEFAULT +-- referenced deletes SET DEFAULT +-- referenced updates CASCADE (two scalar cols) +-- referenced deletes CASCADE (two scalar cols) +-- referenced updates SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- referenced updates SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) +-- +-- test FK referenced updates CASCADE +-- +TRUNCATE temporal_rng, temporal_fk_per2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [7,8) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_rng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [7,8) + [100,101) | 2019-01-01 | 2020-01-01 | [7,8) + [100,101) | 2020-01-01 | 2021-01-01 | [7,8) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +UPDATE temporal_rng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [200,201) | 2018-01-01 | 2020-01-01 | [9,10) + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) +(2 rows) + +-- +-- test FK referenced deletes CASCADE +-- +TRUNCATE temporal_rng, temporal_fk_per2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) +(2 rows) + +-- non-FPO delete: +DELETE FROM temporal_rng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +----+------------+-----------+----------- +(0 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +DELETE FROM temporal_rng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) +(1 row) + +-- +-- test FK referenced updates SET NULL +-- +TRUNCATE temporal_rng, temporal_fk_per2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +ALTER TABLE temporal_fk_per2rng + DROP CONSTRAINT temporal_fk_per2rng_fk, + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_rng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | + [100,101) | 2019-01-01 | 2020-01-01 | + [100,101) | 2020-01-01 | 2021-01-01 | +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +UPDATE temporal_rng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [200,201) | 2018-01-01 | 2020-01-01 | + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET NULL +-- +TRUNCATE temporal_rng, temporal_fk_per2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) +(3 rows) + +-- non-FPO delete: +DELETE FROM temporal_rng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | + [100,101) | 2019-01-01 | 2020-01-01 | + [100,101) | 2020-01-01 | 2021-01-01 | +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +DELETE FROM temporal_rng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [200,201) | 2018-01-01 | 2020-01-01 | + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) +(2 rows) + +-- +-- test FK referenced updates SET DEFAULT +-- +TRUNCATE temporal_rng, temporal_fk_per2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[-1,-1]', '(,)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +ALTER TABLE temporal_fk_per2rng + ALTER COLUMN parent_id SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk_per2rng_fk, + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_rng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [-1,0) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) + [100,101) | 2020-01-01 | 2021-01-01 | [-1,0) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +UPDATE temporal_rng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [200,201) | 2018-01-01 | 2020-01-01 | [-1,0) + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET DEFAULT +-- +TRUNCATE temporal_rng, temporal_fk_per2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[-1,-1]', '(,)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) +(3 rows) + +-- non-FPO update: +DELETE FROM temporal_rng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [100,101) | 2018-01-01 | 2019-01-01 | [-1,0) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) + [100,101) | 2020-01-01 | 2021-01-01 | [-1,0) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +DELETE FROM temporal_rng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id +-----------+------------+------------+----------- + [200,201) | 2018-01-01 | 2020-01-01 | [-1,0) + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) +(2 rows) + +-- +-- test FK referenced updates CASCADE (two scalar cols) +-- +TRUNCATE temporal_rng2, temporal_fk2_per2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_per2rng + DROP CONSTRAINT temporal_fk2_per2rng_fk, + ADD CONSTRAINT temporal_fk2_per2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [7,8) | [6,7) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_rng2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [7,8) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [7,8) | [6,7) + [100,101) | 2020-01-01 | 2021-01-01 | [7,8) | [6,7) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +UPDATE temporal_rng2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [200,201) | 2018-01-01 | 2020-01-01 | [9,10) | [8,9) + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes CASCADE (two scalar cols) +-- +TRUNCATE temporal_rng2, temporal_fk2_per2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) | [6,7) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) | [6,7) +(2 rows) + +-- non-FPO delete: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +----+------------+-----------+------------+------------ +(0 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) | [8,9) +(1 row) + +-- +-- test FK referenced updates SET NULL (two scalar cols) +-- +TRUNCATE temporal_rng2, temporal_fk2_per2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_per2rng + DROP CONSTRAINT temporal_fk2_per2rng_fk, + ADD CONSTRAINT temporal_fk2_per2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | | + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_rng2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | | + [100,101) | 2019-01-01 | 2020-01-01 | | + [100,101) | 2020-01-01 | 2021-01-01 | | +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +UPDATE temporal_rng2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [200,201) | 2018-01-01 | 2020-01-01 | | + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET NULL (two scalar cols) +-- +TRUNCATE temporal_rng2, temporal_fk2_per2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | | + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) | [6,7) +(3 rows) + +-- non-FPO delete: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | | + [100,101) | 2019-01-01 | 2020-01-01 | | + [100,101) | 2020-01-01 | 2021-01-01 | | +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [200,201) | 2018-01-01 | 2020-01-01 | | + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- +TRUNCATE temporal_rng2, temporal_fk2_per2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_per2rng + DROP CONSTRAINT temporal_fk2_per2rng_fk, + ADD CONSTRAINT temporal_fk2_per2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET NULL (valid_at) ON UPDATE SET NULL; +ERROR: column "valid_at" referenced in ON DELETE SET action cannot be PERIOD +-- ok: +ALTER TABLE temporal_fk2_per2rng + DROP CONSTRAINT temporal_fk2_per2rng_fk, + ADD CONSTRAINT temporal_fk2_per2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET NULL (parent_id1) ON UPDATE SET NULL; +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | | [6,7) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) | [6,7) +(3 rows) + +-- non-FPO delete: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | | [6,7) + [100,101) | 2020-01-01 | 2021-01-01 | | [6,7) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [200,201) | 2018-01-01 | 2020-01-01 | | [8,9) + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced updates SET DEFAULT (two scalar cols) +-- +TRUNCATE temporal_rng2, temporal_fk2_per2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[-1,-1]', '(,)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_per2rng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + ALTER COLUMN parent_id2 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_per2rng_fk, + ADD CONSTRAINT temporal_fk2_per2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) | [-1,0) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +UPDATE temporal_rng2 SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [-1,0) | [-1,0) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) | [-1,0) + [100,101) | 2020-01-01 | 2021-01-01 | [-1,0) | [-1,0) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +UPDATE temporal_rng2 SET id1 = '[9,10)', id2 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [200,201) | 2018-01-01 | 2020-01-01 | [-1,0) | [-1,0) + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols) +-- +TRUNCATE temporal_rng2, temporal_fk2_per2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[-1,-1]', '(,)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) | [-1,0) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [-1,0) | [-1,0) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) | [-1,0) + [100,101) | 2020-01-01 | 2021-01-01 | [-1,0) | [-1,0) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [200,201) | 2018-01-01 | 2020-01-01 | [-1,0) | [-1,0) + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) | [8,9) +(2 rows) + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) +-- +TRUNCATE temporal_rng2, temporal_fk2_per2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[6,7)', '(,)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_per2rng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_per2rng_fk, + ADD CONSTRAINT temporal_fk2_per2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET DEFAULT (valid_at) ON UPDATE SET DEFAULT; +ERROR: column "valid_at" referenced in ON DELETE SET action cannot be PERIOD +-- ok: +ALTER TABLE temporal_fk2_per2rng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_per2rng_fk, + ADD CONSTRAINT temporal_fk2_per2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET DEFAULT (parent_id1) ON UPDATE SET DEFAULT; +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [6,7) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) | [6,7) + [100,101) | 2020-01-01 | 2021-01-01 | [6,7) | [6,7) +(3 rows) + +-- non-FPO update: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [100,101) | 2018-01-01 | 2019-01-01 | [-1,0) | [6,7) + [100,101) | 2019-01-01 | 2020-01-01 | [-1,0) | [6,7) + [100,101) | 2020-01-01 | 2021-01-01 | [-1,0) | [6,7) +(3 rows) + +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[8,9)', '(,)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + id | valid_from | valid_til | parent_id1 | parent_id2 +-----------+------------+------------+------------+------------ + [200,201) | 2018-01-01 | 2020-01-01 | [-1,0) | [8,9) + [200,201) | 2020-01-01 | 2021-01-01 | [8,9) | [8,9) +(2 rows) + +-- FK with a custom range type +CREATE TYPE mydaterange AS range(subtype=date); +CREATE TABLE temporal_rng3 ( + id int4range, + valid_at mydaterange, + CONSTRAINT temporal_rng3_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +CREATE TABLE temporal_fk3_rng2rng ( + id int4range, + valid_at mydaterange, + parent_id int4range, + CONSTRAINT temporal_fk3_rng2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk3_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng3 (id, PERIOD valid_at) ON DELETE CASCADE +); +INSERT INTO temporal_rng3 (id, valid_at) VALUES ('[8,9)', mydaterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk3_rng2rng (id, valid_at, parent_id) VALUES ('[5,6)', mydaterange('2018-01-01', '2021-01-01'), '[8,9)'); +DELETE FROM temporal_rng3 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[8,9)'; +SELECT * FROM temporal_fk3_rng2rng WHERE id = '[5,6)'; + id | valid_at | parent_id +-------+-------------------------+----------- + [5,6) | [2018-01-01,2019-01-01) | [8,9) + [5,6) | [2020-01-01,2021-01-01) | [8,9) +(2 rows) + +DROP TABLE temporal_fk3_rng2rng; +DROP TABLE temporal_rng3; +DROP TYPE mydaterange; +-- +-- FK between partitioned tables: ranges +-- +CREATE TABLE temporal_partitioned_rng ( + id int4range, + valid_at daterange, + name text, + CONSTRAINT temporal_paritioned_rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +) PARTITION BY LIST (id); +CREATE TABLE tp1 PARTITION OF temporal_partitioned_rng FOR VALUES IN ('[1,2)', '[3,4)', '[5,6)', '[7,8)', '[9,10)', '[11,12)', '[13,14)', '[15,16)', '[17,18)', '[19,20)', '[21,22)', '[23,24)'); +CREATE TABLE tp2 PARTITION OF temporal_partitioned_rng FOR VALUES IN ('[0,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)'); +INSERT INTO temporal_partitioned_rng (id, valid_at, name) VALUES + ('[1,2)', daterange('2000-01-01', '2000-02-01'), 'one'), + ('[1,2)', daterange('2000-02-01', '2000-03-01'), 'one'), + ('[2,3)', daterange('2000-01-01', '2010-01-01'), 'two'); +CREATE TABLE temporal_partitioned_fk_rng2rng ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_partitioned_fk_rng2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_partitioned_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_partitioned_rng (id, PERIOD valid_at) +) PARTITION BY LIST (id); +CREATE TABLE tfkp1 PARTITION OF temporal_partitioned_fk_rng2rng FOR VALUES IN ('[1,2)', '[3,4)', '[5,6)', '[7,8)', '[9,10)', '[11,12)', '[13,14)', '[15,16)', '[17,18)', '[19,20)', '[21,22)', '[23,24)'); +CREATE TABLE tfkp2 PARTITION OF temporal_partitioned_fk_rng2rng FOR VALUES IN ('[0,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)'); +-- +-- partitioned FK referencing inserts +-- +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES + ('[1,2)', daterange('2000-01-01', '2000-02-15'), '[1,2)'), + ('[1,2)', daterange('2001-01-01', '2002-01-01'), '[2,3)'), + ('[2,3)', daterange('2000-01-01', '2000-02-15'), '[1,2)'); +-- should fail: +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES + ('[3,4)', daterange('2010-01-01', '2010-02-15'), '[1,2)'); +ERROR: insert or update on table "tfkp1" violates foreign key constraint "temporal_partitioned_fk_rng2rng_fk" +DETAIL: Key (parent_id, valid_at)=([1,2), [2010-01-01,2010-02-15)) is not present in table "temporal_partitioned_rng". +INSERT INTO temporal_partitioned_fk_rng2rng (id, valid_at, parent_id) VALUES + ('[3,4)', daterange('2000-01-01', '2000-02-15'), '[3,4)'); +ERROR: insert or update on table "tfkp1" violates foreign key constraint "temporal_partitioned_fk_rng2rng_fk" +DETAIL: Key (parent_id, valid_at)=([3,4), [2000-01-01,2000-02-15)) is not present in table "temporal_partitioned_rng". +-- +-- partitioned FK referencing updates +-- +UPDATE temporal_partitioned_fk_rng2rng SET valid_at = daterange('2000-01-01', '2000-02-13') WHERE id = '[2,3)'; +-- move a row from the first partition to the second +UPDATE temporal_partitioned_fk_rng2rng SET id = '[4,5)' WHERE id = '[1,2)'; +-- move a row from the second partition to the first +UPDATE temporal_partitioned_fk_rng2rng SET id = '[1,2)' WHERE id = '[4,5)'; -- should fail: UPDATE temporal_partitioned_fk_rng2rng SET valid_at = daterange('2000-01-01', '2000-04-01') WHERE id = '[1,2)'; ERROR: conflicting key value violates exclusion constraint "tfkp1_pkey" @@ -4220,4 +8524,18 @@ SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[15,16)'; DROP TABLE temporal_partitioned_fk_mltrng2mltrng; DROP TABLE temporal_partitioned_mltrng; +-- +-- FK between partitioned tables: PERIODs +-- +CREATE TABLE temporal_partitioned_per ( + id int4range, + valid_from date, + valid_til date, + name text, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_paritioned_rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +) PARTITION BY LIST (id); +CREATE TABLE tp1 PARTITION OF temporal_partitioned_per FOR VALUES IN ('[1,2)', '[3,4)', '[5,6)', '[7,8)', '[9,10)', '[11,12)', '[13,14)', '[15,16)', '[17,18)', '[19,20)', '[21,22)', '[23,24)'); +ERROR: Inheriting from a table with a PERIOD is not supported +DROP TABLE temporal_partitioned_per; RESET datestyle; diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule index 844350262170..60308d42bb7a 100644 --- a/src/test/regress/parallel_schedule +++ b/src/test/regress/parallel_schedule @@ -43,7 +43,7 @@ test: copy copyselect copydml copyencoding insert insert_conflict # Note: many of the tests in later groups depend on create_index # ---------- test: create_function_c create_misc create_operator create_procedure create_table create_type create_schema -test: create_index create_index_spgist create_view index_including index_including_gist +test: create_index create_index_spgist create_view index_including index_including_gist periods # ---------- # Another group of parallel tests diff --git a/src/test/regress/sql/for_portion_of.sql b/src/test/regress/sql/for_portion_of.sql index 7493cc4c233d..0b3361a1420a 100644 --- a/src/test/regress/sql/for_portion_of.sql +++ b/src/test/regress/sql/for_portion_of.sql @@ -801,6 +801,56 @@ SELECT * FROM for_portion_of_test2 ORDER BY id, valid_at; DROP TABLE for_portion_of_test2; +-- Test with PERIODs + +CREATE TABLE for_portion_of_test2 ( + id int4range NOT NULL, + valid_from date, + valid_til date, + name text NOT NULL, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT for_portion_of_test2_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +INSERT INTO for_portion_of_test2 +VALUES +('[1,2)', '2018-01-02', '2018-02-03', 'one'), +('[1,2)', '2018-02-04', '2018-03-03', 'one'), +('[1,2)', '2018-03-03', '2018-04-04', 'one'), +('[2,3)', '2018-01-01', '2018-05-01', 'two'), +('[3,4)', '2018-01-01', null, 'three'); +; + +UPDATE for_portion_of_test2 +FOR PORTION OF valid_at FROM '2018-01-10' TO '2018-02-10' +SET name = 'one^1' +WHERE id = '[1,2)'; + +DELETE FROM for_portion_of_test2 +FOR PORTION OF valid_at FROM '2018-01-15' TO '2018-02-15' +WHERE id = '[2,3)'; + +-- Setting the start column fails: +UPDATE for_portion_of_test2 +FOR PORTION OF valid_at FROM '2018-01-10' TO '2018-02-10' +SET valid_from = '2018-02-01' +WHERE id = '[1,2)'; + +-- Setting the end column fails: +UPDATE for_portion_of_test2 +FOR PORTION OF valid_at FROM '2018-01-10' TO '2018-02-10' +SET valid_til = '2018-02-01' +WHERE id = '[1,2)'; + +-- Setting the generated column fails: +UPDATE for_portion_of_test2 +FOR PORTION OF valid_at FROM '2018-01-10' TO '2018-02-10' +SET valid_at = '[2018-02-01,2018-02-03)' +WHERE id = '[1,2)'; + +SELECT * FROM for_portion_of_test2 ORDER BY id, valid_at; + +DROP TABLE for_portion_of_test2; + -- Test with a custom range type CREATE TYPE mydaterange AS range(subtype=date); diff --git a/src/test/regress/sql/periods.sql b/src/test/regress/sql/periods.sql new file mode 100644 index 000000000000..04a30110decc --- /dev/null +++ b/src/test/regress/sql/periods.sql @@ -0,0 +1,198 @@ +/* System periods are not implemented */ +create table pt (id integer, ds date, de date, period for system_time (ds, de)); + +/* Periods must specify actual columns */ +create table pt (id integer, ds date, de date, period for p (bogus, de)); +create table pt (id integer, ds date, de date, period for p (ds, bogus)); + +/* Data types must match exactly */ +create table pt (id integer, ds date, de timestamp, period for p (ds, de)); +create table pt (id integer, ds text collate "C", de text collate "POSIX", period for p (ds, de)); + +/* Periods must have a default BTree operator class */ +create table pt (id integer, ds xml, de xml, period for p (ds, de)); + +/* Period and column names are in the same namespace */ +create table pt (id integer, ds date, de date, period for ctid (ds, de)); +create table pt (id integer, ds date, de date, period for id (ds, de)); + +/* Period name can't be given more than once */ +create table pt (id integer, ds date, de date, period for p (ds, de), period for p (ds, de)); + +/* Period can't use the same colum for start and end*/ +create table pt (id integer, ds date, de date, period for p (ds, ds)); + +/* Now make one that works */ +create table pt (id integer, ds date, de date, period for p (ds, de)); +/* Its generated column looks good */ +select attname, atttypid::regtype, attnotnull, attgenerated from pg_attribute where attrelid = 'pt'::regclass and attname = 'p'; +select conname, contype from pg_constraint where conrelid = 'pt'::regclass order by conname; +/* It appears in the information_schema */ +select * from information_schema.periods; + +/* SELECT * excludes the PERIOD */ +insert into pt values (1, '2000-01-01', '2001-01-01'); +select * from pt; + +/* You can get it if you want */ +select *, p from pt; + +/* You can comment on it */ +comment on period pt.p is 'test comment'; +select obj_description((select oid from pg_period where perrelid = 'pt'::regclass and pername = 'p'), 'pg_period'); + +/* Two are okay */ +create table pt2 (id integer, ds date, de date, period for p1 (ds, de), period for p2 (ds, de)); +drop table pt2; + +/* Skip creating GENERATED column: works */ +create table pt2 (id integer, ds date, de date, p daterange not null generated always as (daterange(ds, de)) stored, period for p (ds, de) with (colexists = true)); +\d pt2 +drop table pt2; +/* Skip creating GENERATED column: fails because the col isn't there */ +create table pt2 (id integer, ds date, de date, period for p (ds, de) with (colexists = true)); +/* Skip creating GENERATED column: fails because the option has an invalid value */ +create table pt2 (id integer, ds date, de date, period for p (ds, de) with (colexists = 'whatever')); +/* Skip creating GENERATED column: fails because the column is not NOT NULL */ +create table pt2 (id integer, ds date, de date, p daterange generated always as (daterange(ds, de)) stored, period for p (ds, de) with (colexists = true)); +/* Skip creating GENERATED column: fails because the column is not GENERATED */ +create table pt2 (id integer, ds date, de date, p daterange not null, period for p (ds, de) with (colexists = true)); +/* Skip creating GENERATED column: fails because the column is GENERATED but with the wrong expression */ +-- TODO: +-- create table pt2 (id integer, ds date, de date, p daterange not null generated always as (daterange(de, ds)) stored, period for p (ds, de) with (colexists = true)); +/* Skip creating GENERATED column: fails because the column is the wrong type */ +create table pt2 (id integer, ds date, de date, p tsrange not null generated always as (tsrange(ds, de)) stored, period for p (ds, de) with (colexists = true)); +/* Skip creating GENERATED column: fails because the column is inherited */ +create table pt2parent (id integer, ds date, de date, p daterange not null generated always as (daterange(ds, de)) stored); +create table pt2 (period for p (ds, de) with (colexists = true)) inherits (pt2parent); +drop table pt2parent; + + +/* + * ALTER TABLE tests + */ +alter table pt drop period for p; +alter table pt add period for system_time (ds, de); +alter table pt add period for p (ds, de); +/* Its generated column looks good */ +select attname, atttypid::regtype, attnotnull, attgenerated from pg_attribute where attrelid = 'pt'::regclass and attname = 'p'; +select conname, contype from pg_constraint where conrelid = 'pt'::regclass order by conname; + +/* Adding a second one */ +create table pt2 (id integer, ds date, de date, period for p1 (ds, de)); +alter table pt2 add period for p2 (ds, de); +drop table pt2; + +/* Can't drop its columns */ +alter table pt drop column ds; +alter table pt drop column de; + +/* Can't change the data types */ +alter table pt alter column ds type timestamp; +alter table pt alter column ds type timestamp; + +/* column/period namespace conflicts */ +alter table pt add column p integer; +alter table pt rename column id to p; +alter table pt add period for tableoid (ds, de); +alter table pt add period for "........pg.dropped.4........" (ds, de); + +/* adding columns and the period at the same time */ +create table pt2 (id integer); +alter table pt2 add column ds date, add column de date, add period for p (ds, de); +drop table pt2; + +/* Ambiguous range types raise an error */ +create type mydaterange as range(subtype=date); +create table pt2 (id int, ds date, de date, period for p (ds, de)); + +/* You can give an explicit range type */ +create table pt2 (id int, ds date, de date, period for p (ds, de) with (rangetype = 'mydaterange')); +drop type mydaterange; +drop type mydaterange cascade; +drop table pt2; +create table pt2 (id int, ds date, de date, period for p (ds, de) with (rangetype = 'daterange')); + +/* Range type is not found */ +create table pt3 (id int, ds date, de date, period for p (ds, de) with (rangetype = 'notarange')); + +/* Range type is the wrong type */ +create table pt3 (id int, ds date, de date, period for p (ds, de) with (rangetype = 'tstzrange')); +drop table pt2; + +/* Period can't use the same colum for start and end*/ +create table pt2 (id integer, ds date, de date); +alter table pt2 add period for p (ds, ds); +drop table pt2; + +/* Skip creating GENERATED column: works */ +create table pt2 (id integer, ds date, de date, p daterange not null generated always as (daterange(ds, de)) stored); +alter table pt2 add period for p (ds, de) with (colexists = true); +\d pt2 +drop table pt2; +/* Skip creating GENERATED column: fails because the col isn't there */ +create table pt2 (id integer, ds date, de date); +alter table pt2 add period for p (ds, de) with (colexists = true); +drop table pt2; +/* Skip creating GENERATED column: fails because the option has an invalid value */ +create table pt2 (id integer, ds date, de date, p daterange not null generated always as (daterange(ds, de)) stored); +alter table pt2 add period for p (ds, de) with (colexists = 'whatever'); +drop table pt2; +/* Skip creating GENERATED column: fails because the column is not NOT NULL */ +create table pt2 (id integer, ds date, de date, p daterange generated always as (daterange(ds, de)) stored); +alter table pt2 add period for p (ds, de) with (colexists = true); +drop table pt2; +/* Skip creating GENERATED column: fails because the column is not GENERATED */ +create table pt2 (id integer, ds date, de date, p daterange not null); +alter table pt2 add period for p (ds, de) with (colexists = true); +drop table pt2; +/* Skip creating GENERATED column: fails because the column is GENERATED but with the wrong expression */ +-- TODO: +-- create table pt2 (id integer, ds date, de date, p daterange not null generated always as (daterange(de, ds)) stored); +-- alter table pt2 add period for p (ds, de) with (colexists = true); +/* Skip creating GENERATED column: fails because the column is the wrong type */ +create table pt2 (id integer, ds date, de date, p tsrange not null generated always as (tsrange(ds, de)) stored); +alter table pt2 add period for p (ds, de) with (colexists = true); +drop table pt2; +/* Skip creating GENERATED column: fails because the column is inherited */ +create table pt2parent (id integer, ds date, de date, p daterange not null generated always as (daterange(ds, de)) stored); +create table pt2 () inherits (pt2parent); +alter table pt2 add period for p (ds, de) with (colexists = true); +drop table pt2; +drop table pt2parent; + +/* CREATE TABLE (LIKE ...) */ + +/* Periods are not copied by LIKE, so their columns aren't either */ +create table pt2 (like pt); +\d pt2 +drop table pt2; + +/* Can add a period referring to LIKE'd columns */ +create table not_p (id integer, ds date, de date); +create table pt2 (like not_p, period for p (ds, de)); +\d pt2 +drop table pt2; + +/* Can add a period with the same name */ +create table pt2 (like pt, period for p (ds, de)); +\d pt2 +drop table pt2; + +/* Can add a period with a different name */ +create table pt2 (like pt, period for p2 (ds, de)); +\d pt2 +drop table pt2; + +/* Can't add a period whose name conflicts with a LIKE'd column */ +create table pt2 (like pt, period for id (ds, de)); + +/* CREATE TALBE INHERITS */ + +/* Can't inherit from a table with a period */ +create table pt2 (name text) inherits (pt); + +/* Can't inherit with a period */ +create table pt2 (d2s date, d2e date, period for p (d2s, d2e)) inherits (not_p); + +drop table not_p; diff --git a/src/test/regress/sql/privileges.sql b/src/test/regress/sql/privileges.sql index ae57f233314c..c36b1d34af5d 100644 --- a/src/test/regress/sql/privileges.sql +++ b/src/test/regress/sql/privileges.sql @@ -783,6 +783,34 @@ UPDATE t1 FOR PORTION OF valid_at FROM '2000-01-01' TO '2001-01-01' SET c1 = '[2 SET SESSION AUTHORIZATION regress_priv_user1; DROP TABLE t1; +-- test column-level privileges on the PERIOD used in FOR PORTION OF +SET SESSION AUTHORIZATION regress_priv_user1; +CREATE TABLE t1 ( + c1 int4range, + valid_from timestamp, + valid_til timestamp, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT t1pk PRIMARY KEY (c1, valid_at WITHOUT OVERLAPS) +); +GRANT SELECT ON t1 TO regress_priv_user2; +GRANT SELECT ON t1 TO regress_priv_user3; +GRANT SELECT ON t1 TO regress_priv_user4; +GRANT SELECT ON t1 TO regress_priv_user5; +GRANT UPDATE (c1) ON t1 TO regress_priv_user2; +GRANT UPDATE (c1, valid_at) ON t1 TO regress_priv_user3; +GRANT UPDATE (c1, valid_from, valid_til) ON t1 TO regress_priv_user4; +GRANT UPDATE (c1, valid_from, valid_til, valid_at) ON t1 TO regress_priv_user5; +SET SESSION AUTHORIZATION regress_priv_user2; +UPDATE t1 FOR PORTION OF valid_at FROM '2000-01-01' TO '2001-01-01' SET c1 = '[2,3)'; +SET SESSION AUTHORIZATION regress_priv_user3; +UPDATE t1 FOR PORTION OF valid_at FROM '2000-01-01' TO '2001-01-01' SET c1 = '[2,3)'; +SET SESSION AUTHORIZATION regress_priv_user4; +UPDATE t1 FOR PORTION OF valid_at FROM '2000-01-01' TO '2001-01-01' SET c1 = '[2,3)'; +SET SESSION AUTHORIZATION regress_priv_user5; +UPDATE t1 FOR PORTION OF valid_at FROM '2000-01-01' TO '2001-01-01' SET c1 = '[2,3)'; +SET SESSION AUTHORIZATION regress_priv_user1; +DROP TABLE t1; + -- test column-level privileges when involved with DELETE SET SESSION AUTHORIZATION regress_priv_user1; ALTER TABLE atest6 ADD COLUMN three integer; diff --git a/src/test/regress/sql/without_overlaps.sql b/src/test/regress/sql/without_overlaps.sql index 224ddef84307..188041e1d07c 100644 --- a/src/test/regress/sql/without_overlaps.sql +++ b/src/test/regress/sql/without_overlaps.sql @@ -91,6 +91,31 @@ CREATE TABLE temporal_rng2 ( SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_rng2_pk'; SELECT pg_get_indexdef(conindid, 0, true) FROM pg_constraint WHERE conname = 'temporal_rng2_pk'; +-- PK with one column plus a PERIOD: +CREATE TABLE temporal_per ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +\d temporal_per +SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_per_pk'; +SELECT pg_get_indexdef(conindid, 0, true) FROM pg_constraint WHERE conname = 'temporal_per_pk'; + +-- PK with two columns plus a PERIOD: +CREATE TABLE temporal_per2 ( + id1 int4range, + id2 int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_per2_pk PRIMARY KEY (id1, id2, valid_at WITHOUT OVERLAPS) +); +\d temporal_per2 +SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_per2_pk'; +SELECT pg_get_indexdef(conindid, 0, true) FROM pg_constraint WHERE conname = 'temporal_per2_pk'; + -- PK with a custom range type: CREATE TYPE textrange2 AS range (subtype=text, collation="C"); CREATE TABLE temporal_rng3 ( @@ -169,6 +194,33 @@ SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_rn SELECT pg_get_indexdef(conindid, 0, true) FROM pg_constraint WHERE conname = 'temporal_rng3_uq'; DROP TABLE temporal_rng3; +-- UNIQUE with one column plus a PERIOD: +CREATE TABLE temporal_per3 ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_per3_uq UNIQUE (id, valid_at WITHOUT OVERLAPS) +); +\d temporal_per3 +SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_per3_uq'; +SELECT pg_get_indexdef(conindid, 0, true) FROM pg_constraint WHERE conname = 'temporal_per3_uq'; +DROP TABLE temporal_per3; + +-- UNIQUE with two columns plus a PERIOD: +CREATE TABLE temporal_per3 ( + id1 int4range, + id2 int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_per3_uq UNIQUE (id1, id2, valid_at WITHOUT OVERLAPS) +); +\d temporal_per3 +SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_per3_uq'; +SELECT pg_get_indexdef(conindid, 0, true) FROM pg_constraint WHERE conname = 'temporal_per3_uq'; +DROP TABLE temporal_per3; + -- UNIQUE with a custom range type: CREATE TYPE textrange2 AS range (subtype=text, collation="C"); CREATE TABLE temporal_rng3 ( @@ -245,6 +297,58 @@ ALTER TABLE temporal3 UNIQUE (id, valid_at WITHOUT OVERLAPS); DROP TABLE temporal3; +-- PRIMARY KEY with PERIOD already there +CREATE TABLE temporal3 ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til) +); +ALTER TABLE temporal3 + ADD CONSTRAINT temporal3_pk + PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); +\d temporal3 +DROP TABLE temporal3; + +-- PRIMARY KEY with PERIOD too +CREATE TABLE temporal3 ( + id int4range, + valid_from date, + valid_til date +); +ALTER TABLE temporal3 + ADD PERIOD FOR valid_at (valid_from, valid_til), + ADD CONSTRAINT temporal3_pk + PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); +\d temporal3 +DROP TABLE temporal3; + +-- UNIQUE with PERIOD already there +CREATE TABLE temporal3 ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til) +); +ALTER TABLE temporal3 + ADD CONSTRAINT temporal3_uq + UNIQUE (id, valid_at WITHOUT OVERLAPS); +\d temporal3 +DROP TABLE temporal3; + +-- UNIQUE with PERIOD too +CREATE TABLE temporal3 ( + id int4range, + valid_from date, + valid_til date +); +ALTER TABLE temporal3 + ADD PERIOD FOR valid_at (valid_from, valid_til), + ADD CONSTRAINT temporal3_uq + UNIQUE (id, valid_at WITHOUT OVERLAPS); +\d temporal3 +DROP TABLE temporal3; + -- -- range PK: test with existing rows -- @@ -615,6 +719,212 @@ WHERE id = '[1,2)' AND valid_at IS NULL; SELECT * FROM temporal_mltrng3 ORDER BY id, valid_at; DROP TABLE temporal_mltrng3; +-- +-- PERIOD PK: test with existing rows +-- + +ALTER TABLE temporal_per DROP CONSTRAINT temporal_per_pk; + +-- okay: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2018-01-02', '2018-02-03'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2018-03-03', '2018-04-04'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[2,3)', '2018-01-01', '2018-01-05'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[3,4)', '2018-01-01', NULL); +ALTER TABLE temporal_per ADD CONSTRAINT temporal_per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); +ALTER TABLE temporal_per DROP CONSTRAINT temporal_per_pk; + +-- should fail: +BEGIN; + INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2018-01-01', '2018-01-05'); + ALTER TABLE temporal_per ADD CONSTRAINT temporal_per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); +ROLLBACK; +-- rejects empty: +BEGIN; + ALTER TABLE temporal_per DROP PERIOD FOR valid_at; + INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[3,4)', '2020-01-01', '2020-01-01'); + ALTER TABLE temporal_per ADD PERIOD FOR valid_at (valid_from, valid_til); +ROLLBACK; +ALTER TABLE temporal_per ADD CONSTRAINT temporal_per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); +DELETE FROM temporal_per; + +-- +-- PERIOD PK: test inserts +-- + +-- okay: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2018-01-02', '2018-02-03'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2018-03-03', '2018-04-04'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[2,3)', '2018-01-01', '2018-01-05'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[3,4)', '2018-01-01', NULL); + +-- should fail: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2018-01-01', '2018-01-05'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES (NULL, '2018-01-01', '2018-01-05'); +-- rejects empty: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[3,4)', '2020-01-01', '2020-01-01'); +SELECT * FROM temporal_per ORDER BY id, valid_at; + +-- +-- PERIOD PK: test updates +-- + +-- update the scalar part +UPDATE temporal_per +SET id = '[11,12)' +WHERE id = '[1,2)' +AND valid_at @> '2018-01-15'::date; +-- update the PERIOD bounds +UPDATE temporal_per +SET valid_from = '2020-01-01', + valid_til = '2021-01-01' +WHERE id = '[11,12)' +AND valid_at @> '2018-01-15'::date; +-- update both at once +UPDATE temporal_per +SET id = '[21,22)', + valid_from = '2018-01-02', + valid_til = '2018-02-03' +WHERE id = '[11,12)' +AND valid_at @> '2020-01-15'::date; +SELECT * FROM temporal_per ORDER BY id, valid_at; +-- should fail: +UPDATE temporal_per +SET id = '[1,2)', + valid_from = '2018-03-05', + valid_til = '2018-05-05' +WHERE id = '[21,22)'; +-- set the scalar part to NULL +UPDATE temporal_per +SET id = NULL, + valid_from = '2018-03-05', + valid_til = '2018-05-05' +WHERE id = '[21,22)'; +-- set a PERIOD bound to NULL (okay) +UPDATE temporal_per +SET id = '[1,2)', + valid_from = '2018-04-04', + valid_til = NULL +WHERE id = '[21,22)'; +-- rejects empty: +UPDATE temporal_per +SET id = '[21,22)', + valid_from = '2020-01-01', + valid_til = '2020-01-01' +WHERE id = '[1,2)'; +SELECT * FROM temporal_per ORDER BY id, valid_at; + +-- +-- PERIOD UQ: test with existing rows +-- + +CREATE TABLE temporal_per3 ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til) +); + +-- okay: +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2018-01-02', '2018-02-03'); +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2018-03-03', '2018-04-04'); +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[2,3)', '2018-01-01', '2018-01-05'); +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[3,4)', '2018-01-01', NULL); +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES (NULL, '2018-01-01', '2018-01-05'); +ALTER TABLE temporal_per3 ADD CONSTRAINT temporal_per3_uq UNIQUE (id, valid_at WITHOUT OVERLAPS); +ALTER TABLE temporal_per3 DROP CONSTRAINT temporal_per3_uq; + +-- should fail: +BEGIN; + INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2018-01-01', '2018-01-05'); + ALTER TABLE temporal_per3 ADD CONSTRAINT temporal_per3_uq UNIQUE (id, valid_at WITHOUT OVERLAPS); +ROLLBACK; +-- rejects empty: +BEGIN; + ALTER TABLE temporal_per3 DROP PERIOD FOR valid_at; + INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[3,4)', '2020-01-01', '2020-01-01'); + ALTER TABLE temporal_per3 ADD PERIOD FOR valid_at (valid_from, valid_til); +ROLLBACK; +ALTER TABLE temporal_per3 ADD CONSTRAINT temporal_per3_uq UNIQUE (id, valid_at WITHOUT OVERLAPS); +DELETE FROM temporal_per3; + +-- +-- PERIOD UQ: test inserts +-- + +-- okay: +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2018-01-02', '2018-02-03'); +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2018-03-03', '2018-04-04'); +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[2,3)', '2018-01-01', '2018-01-05'); +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[3,4)', '2018-01-01', NULL); +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES (NULL, '2018-01-01', '2018-01-05'); + +-- should fail: +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2018-01-01', '2018-01-05'); +-- rejects empty: +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[3,4)', '2020-01-01', '2020-01-01'); +SELECT * FROM temporal_per3 ORDER BY id, valid_at; + +-- +-- PERIOD UQ: test updates +-- + +-- update the scalar part +UPDATE temporal_per3 +SET id = '[11,12)' +WHERE id = '[1,2)' +AND valid_at @> '2018-01-15'::date; +-- update the PERIOD bounds +UPDATE temporal_per3 +SET valid_from = '2020-01-01', + valid_til = '2021-01-01' +WHERE id = '[11,12)' +AND valid_at @> '2018-01-15'::date; +-- update both at once +UPDATE temporal_per3 +SET id = '[21,22)', + valid_from = '2018-01-02', + valid_til = '2018-02-03' +WHERE id = '[11,12)' +AND valid_at @> '2020-01-15'::date; +SELECT * FROM temporal_per3 ORDER BY id, valid_at; +-- should fail: +UPDATE temporal_per3 +SET id = '[1,2)', + valid_from = '2018-03-05', + valid_til = '2018-05-05' +WHERE id = '[21,22)'; +-- set the scalar part to NULL (okay) +UPDATE temporal_per3 +SET id = NULL, + valid_from = '2020-01-01', + valid_til = '2021-01-01' +WHERE id = '[21,22)'; +-- set a PERIOD bound to NULL (okay) +UPDATE temporal_per3 +SET id = '[1,2)', + valid_from = '2018-04-04', + valid_til = NULL +WHERE id IS NULL AND valid_at @> '2020-06-01'::date; +SELECT * FROM temporal_per3 ORDER BY id, valid_at; +-- should fail: +UPDATE temporal_per3 +SET valid_from = '2018-03-01', + valid_til = '2018-05-05' +WHERE id = '[1,2)' AND valid_til IS NULL; +-- rejects empty: +UPDATE temporal_per3 +SET valid_from = '2020-01-01', + valid_til = '2020-01-01' +WHERE id = '[1,2)' AND valid_til IS NULL; +-- still rejects empty when scalar part is NULL: +UPDATE temporal_per3 +SET id = NULL, + valid_from = '2020-01-01', + valid_til = '2020-01-01' +WHERE id = '[1,2)' AND valid_til IS NULL; +SELECT * FROM temporal_per3 ORDER BY id, valid_at; +DROP TABLE temporal_per3; + -- -- test a range with both a PK and a UNIQUE constraint -- @@ -662,6 +972,37 @@ ALTER TABLE temporal3 ALTER COLUMN valid_at DROP NOT NULL; ALTER TABLE temporal3 ALTER COLUMN valid_at TYPE tstzrange USING tstzrange(lower(valid_at), upper(valid_at)); ALTER TABLE temporal3 RENAME COLUMN valid_at TO valid_thru; ALTER TABLE temporal3 DROP COLUMN valid_thru; +\d temporal3 +DROP TABLE temporal3; + +CREATE TABLE temporal3 ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal3_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +\d temporal3 +SELECT attnotnull FROM pg_attribute WHERE attrelid = 'temporal3'::regclass AND attname = 'valid_at'; +ALTER TABLE temporal3 ALTER COLUMN valid_at DROP NOT NULL; +ALTER TABLE temporal3 ALTER COLUMN valid_at TYPE tstzrange USING tstzrange(lower(valid_at), upper(valid_at)); +ALTER TABLE temporal3 DROP COLUMN valid_at; +ALTER TABLE temporal3 DROP PERIOD FOR valid_at; +\d temporal3 +DROP TABLE temporal3; + +-- Same results if we add the PERIOD and PK from ALTER TABLE: +CREATE TABLE temporal3 ( + id int4range, + valid_from date, + valid_til date +); +ALTER TABLE temporal3 + ADD PERIOD FOR valid_at (valid_from, valid_til), + ADD CONSTRAINT temporal3_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); +\d temporal3 +SELECT attnotnull FROM pg_attribute WHERE attrelid = 'temporal3'::regclass AND attname = 'valid_at'; +ALTER TABLE temporal3 ALTER COLUMN valid_at DROP NOT NULL; DROP TABLE temporal3; -- @@ -963,6 +1304,121 @@ SELECT * FROM temporal_mltrng3 ORDER BY id, valid_at; DROP TABLE temporal_mltrng3; +-- +-- ON CONFLICT: PERIODs +-- + +TRUNCATE temporal_per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT DO NOTHING; +-- id matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT DO NOTHING; +-- date matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT DO NOTHING; +SELECT * FROM temporal_per ORDER BY id, valid_from, valid_til; + +TRUNCATE temporal_per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT (id, valid_at) DO NOTHING; +-- id matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT (id, valid_at) DO NOTHING; +-- date matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT (id, valid_at) DO NOTHING; +SELECT * FROM temporal_per ORDER BY id, valid_from, valid_til; + +TRUNCATE temporal_per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT ON CONSTRAINT temporal_per_pk DO NOTHING; +-- id matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT ON CONSTRAINT temporal_per_pk DO NOTHING; +-- date matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT ON CONSTRAINT temporal_per_pk DO NOTHING; +SELECT * FROM temporal_per ORDER BY id, valid_from, valid_til; + +TRUNCATE temporal_per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT (id, valid_at) DO UPDATE SET id = EXCLUDED.id + '[2,3)'; +-- id matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT (id, valid_at) DO UPDATE SET id = EXCLUDED.id + '[3,4)'; +-- date matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT (id, valid_at) DO UPDATE SET id = EXCLUDED.id + '[4,5)'; +SELECT * FROM temporal_per ORDER BY id, valid_from, valid_til; + +TRUNCATE temporal_per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT ON CONSTRAINT temporal_per_pk DO UPDATE SET id = EXCLUDED.id + '[2,3)'; +-- id matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT ON CONSTRAINT temporal_per_pk DO UPDATE SET id = EXCLUDED.id + '[3,4)'; +-- date matches but no conflict +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT ON CONSTRAINT temporal_per_pk DO UPDATE SET id = EXCLUDED.id + '[4,5)'; +SELECT * FROM temporal_per ORDER BY id, valid_from, valid_til; + +-- with a UNIQUE constraint: + +CREATE TABLE temporal_per3 ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_per3_uq UNIQUE (id, valid_at WITHOUT OVERLAPS) +); +TRUNCATE temporal_per3; +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT DO NOTHING; +-- id matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT DO NOTHING; +-- date matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT DO NOTHING; +SELECT * FROM temporal_per3 ORDER BY id, valid_from, valid_til; + +TRUNCATE temporal_per3; +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT (id, valid_at) DO NOTHING; +-- id matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT (id, valid_at) DO NOTHING; +-- date matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT (id, valid_at) DO NOTHING; +SELECT * FROM temporal_per3 ORDER BY id, valid_from, valid_til; + +TRUNCATE temporal_per3; +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT ON CONSTRAINT temporal_per3_uq DO NOTHING; +-- id matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT ON CONSTRAINT temporal_per3_uq DO NOTHING; +-- date matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT ON CONSTRAINT temporal_per3_uq DO NOTHING; +SELECT * FROM temporal_per3 ORDER BY id, valid_from, valid_til; + +TRUNCATE temporal_per3; +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT (id, valid_at) DO UPDATE SET id = EXCLUDED.id + '[2,3)'; +-- id matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT (id, valid_at) DO UPDATE SET id = EXCLUDED.id + '[3,4)'; +-- date matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT (id, valid_at) DO UPDATE SET id = EXCLUDED.id + '[4,5)'; +SELECT * FROM temporal_per3 ORDER BY id, valid_from, valid_til; + +TRUNCATE temporal_per3; +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2000-01-01', '2010-01-01'); +-- with a conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2005-01-01', '2006-01-01') ON CONFLICT ON CONSTRAINT temporal_per3_uq DO UPDATE SET id = EXCLUDED.id + '[2,3)'; +-- id matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[1,2)', '2010-01-01', '2020-01-01') ON CONFLICT ON CONSTRAINT temporal_per3_uq DO UPDATE SET id = EXCLUDED.id + '[3,4)'; +-- date matches but no conflict +INSERT INTO temporal_per3 (id, valid_from, valid_til) VALUES ('[2,3)', '2005-01-01', '2006-01-01') ON CONFLICT ON CONSTRAINT temporal_per3_uq DO UPDATE SET id = EXCLUDED.id + '[4,5)'; +SELECT * FROM temporal_per3 ORDER BY id, valid_from, valid_til; + +DROP TABLE temporal_per3; + -- -- test FK dependencies -- @@ -986,6 +1442,29 @@ ALTER TABLE temporal3 DROP COLUMN valid_at CASCADE; DROP TABLE temporal_fk_rng2rng; DROP TABLE temporal3; +-- can't drop a PERIOD referenced by an FK, unless with CASCADE +CREATE TABLE temporal3 ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal3_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal3 (id, PERIOD valid_at) +); +ALTER TABLE temporal3 DROP PERIOD FOR valid_at; +ALTER TABLE temporal3 DROP PERIOD FOR valid_at CASCADE; +DROP TABLE temporal_fk_per2per; +DROP TABLE temporal3; + -- -- test FOREIGN KEY, range references range -- @@ -1016,6 +1495,7 @@ CREATE TABLE temporal_fk_rng2rng ( CONSTRAINT temporal_fk_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) REFERENCES temporal_rng (id, PERIOD valid_at) ); +\d temporal_fk_rng2rng DROP TABLE temporal_fk_rng2rng; -- with mismatched PERIOD columns: @@ -2567,47 +3047,2555 @@ INSERT INTO temporal_fk2_mltrng2mltrng (id, valid_at, parent_id1, parent_id2) VA DELETE FROM temporal_mltrng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; SELECT * FROM temporal_fk2_mltrng2mltrng WHERE id = '[200,201)' ORDER BY id, valid_at; --- FK with a custom range type +-- +-- test FOREIGN KEY, PERIOD references PERIOD +-- -CREATE TYPE mydaterange AS range(subtype=date); +-- test table setup +DROP TABLE temporal_per; +CREATE TABLE temporal_per ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til) +); +ALTER TABLE temporal_per + ADD CONSTRAINT temporal_per_pk + PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); -CREATE TABLE temporal_rng3 ( +-- Can't create a FK with a mismatched range type +CREATE TABLE temporal_fk_per2per ( id int4range, - valid_at mydaterange, - CONSTRAINT temporal_rng3_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) + valid_from int, + valid_til int, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id, PERIOD valid_at) ); -CREATE TABLE temporal_fk3_rng2rng ( + +-- works: PERIOD for both referenced and referencing +CREATE TABLE temporal_fk_per2per ( id int4range, - valid_at mydaterange, + valid_from date, + valid_til date, parent_id int4range, - CONSTRAINT temporal_fk3_rng2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), - CONSTRAINT temporal_fk3_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) - REFERENCES temporal_rng3 (id, PERIOD valid_at) ON DELETE CASCADE + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id, PERIOD valid_at) ); -INSERT INTO temporal_rng3 (id, valid_at) VALUES ('[8,9)', mydaterange('2018-01-01', '2021-01-01')); -INSERT INTO temporal_fk3_rng2rng (id, valid_at, parent_id) VALUES ('[5,6)', mydaterange('2018-01-01', '2021-01-01'), '[8,9)'); -DELETE FROM temporal_rng3 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[8,9)'; -SELECT * FROM temporal_fk3_rng2rng WHERE id = '[5,6)'; +\d temporal_fk_per2per -DROP TABLE temporal_fk3_rng2rng; -DROP TABLE temporal_rng3; -DROP TYPE mydaterange; +DROP TABLE temporal_fk_per2per; --- --- FK between partitioned tables: ranges --- +-- with mismatched PERIOD columns: -CREATE TABLE temporal_partitioned_rng ( +-- (parent_id, PERIOD valid_at) REFERENCES (id, valid_at) +-- REFERENCES part should specify PERIOD +CREATE TABLE temporal_fk_per2per ( id int4range, - valid_at daterange, - name text, - CONSTRAINT temporal_paritioned_rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) -) PARTITION BY LIST (id); -CREATE TABLE tp1 PARTITION OF temporal_partitioned_rng FOR VALUES IN ('[1,2)', '[3,4)', '[5,6)', '[7,8)', '[9,10)', '[11,12)', '[13,14)', '[15,16)', '[17,18)', '[19,20)', '[21,22)', '[23,24)'); -CREATE TABLE tp2 PARTITION OF temporal_partitioned_rng FOR VALUES IN ('[0,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)'); -INSERT INTO temporal_partitioned_rng (id, valid_at, name) VALUES - ('[1,2)', daterange('2000-01-01', '2000-02-01'), 'one'), - ('[1,2)', daterange('2000-02-01', '2000-03-01'), 'one'), + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id, valid_at) +); +-- (parent_id, valid_at) REFERENCES (id, valid_at) +-- both should specify PERIOD: +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_per (id, valid_at) +); +-- (parent_id, valid_at) REFERENCES (id, PERIOD valid_at) +-- FOREIGN KEY part should specify PERIOD +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_per (id, PERIOD valid_at) +); +-- (parent_id, valid_at) REFERENCES [implicit] +-- FOREIGN KEY part should specify PERIOD +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_per +); +-- (parent_id, PERIOD valid_at) REFERENCES (id) +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id) +); +-- (parent_id) REFERENCES (id, PERIOD valid_at) +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id) + REFERENCES temporal_per (id, PERIOD valid_at) +); +-- with inferred PK on the referenced table: +-- (parent_id, PERIOD valid_at) REFERENCES [implicit] +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per +); +DROP TABLE temporal_fk_per2per; +-- (parent_id) REFERENCES [implicit] +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id) + REFERENCES temporal_per +); + +-- should fail because of duplicate referenced columns: +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2per_fk FOREIGN KEY (parent_id, PERIOD parent_id) + REFERENCES temporal_per (id, PERIOD id) +); + +-- Two scalar columns +DROP TABLE temporal_per2; +CREATE TABLE temporal_per2 ( + id1 int4range, + id2 int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_per2_pk PRIMARY KEY (id1, id2, valid_at WITHOUT OVERLAPS) +); + +CREATE TABLE temporal_fk2_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id1 int4range, + parent_id2 int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk2_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk2_per2per_fk FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 (id1, id2, PERIOD valid_at) +); +\d temporal_fk2_per2per +DROP TABLE temporal_fk2_per2per; + +-- +-- test ALTER TABLE ADD CONSTRAINT +-- + +CREATE TABLE temporal_fk_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id, PERIOD valid_at); +-- Two scalar columns: +CREATE TABLE temporal_fk2_per2per ( + id int4range, + valid_from date, + valid_til date, + parent_id1 int4range, + parent_id2 int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk2_per2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +ALTER TABLE temporal_fk2_per2per + ADD CONSTRAINT temporal_fk2_per2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 (id1, id2, PERIOD valid_at); +\d temporal_fk2_per2per + +-- with inferred PK on the referenced table, and wrong column type: +ALTER TABLE temporal_fk_per2per + DROP CONSTRAINT temporal_fk_per2per_fk, + DROP PERIOD FOR valid_at, + ALTER COLUMN valid_from TYPE timestamp, + ALTER COLUMN valid_til TYPE timestamp, + ADD PERIOD FOR valid_at (valid_from, valid_til); +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +ALTER TABLE temporal_fk_per2per + DROP PERIOD FOR valid_at, + ALTER COLUMN valid_from TYPE date, + ALTER COLUMN valid_til TYPE date, + ADD PERIOD FOR valid_at (valid_from, valid_til); + +-- with inferred PK on the referenced table: +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; + +-- should fail because of duplicate referenced columns: +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk2 + FOREIGN KEY (parent_id, PERIOD parent_id) + REFERENCES temporal_per (id, PERIOD id); + +-- +-- test with rows already +-- + +DELETE FROM temporal_fk_per2per; +DELETE FROM temporal_per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[1,2)', '2018-01-02', '2018-02-03'), + ('[1,2)', '2018-03-03', '2018-04-04'), + ('[2,3)', '2018-01-01', '2018-01-05'), + ('[3,4)', '2018-01-01', NULL); + +ALTER TABLE temporal_fk_per2per + DROP CONSTRAINT temporal_fk_per2per_fk; +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[1,2)', '2018-01-02', '2018-02-01', '[1,2)'); +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +ALTER TABLE temporal_fk_per2per + DROP CONSTRAINT temporal_fk_per2per_fk; +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[2,3)', '2018-01-02', '2018-04-01', '[1,2)'); +-- should fail: +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +-- okay again: +DELETE FROM temporal_fk_per2per; +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; + +-- +-- test pg_get_constraintdef +-- + +SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_fk_per2per_fk'; + +-- +-- test FK referencing inserts +-- + +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[1,2)', '2018-01-02', '2018-02-01', '[1,2)'); +-- should fail: +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[2,3)', '2018-01-02', '2018-04-01', '[1,2)'); +-- now it should work: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2018-02-03', '2018-03-03'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[2,3)', '2018-01-02', '2018-04-01', '[1,2)'); + +-- +-- test FK referencing updates +-- + +-- slide the edge across a referenced transition: +UPDATE temporal_fk_per2per SET valid_from = '2018-01-02', valid_til = '2018-02-20' WHERE id = '[1,2)'; +-- should fail: +UPDATE temporal_fk_per2per SET valid_from = '2018-01-02', valid_til = '2018-05-01' WHERE id = '[1,2)'; +UPDATE temporal_fk_per2per SET parent_id = '[8,9)' WHERE id = '[1,2)'; + +-- ALTER FK DEFERRABLE + +BEGIN; + INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[5,6)', '2018-01-01', '2018-02-01'), + ('[5,6)', '2018-02-01', '2018-03-01'); + INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES + ('[3,4)', '2018-01-05', '2018-01-10', '[5,6)'); + ALTER TABLE temporal_fk_per2per + ALTER CONSTRAINT temporal_fk_per2per_fk + DEFERRABLE INITIALLY DEFERRED; + + DELETE FROM temporal_per WHERE id = '[5,6)'; --should not fail yet. +COMMIT; -- should fail here. + +-- +-- test FK referenced updates NO ACTION +-- + +TRUNCATE temporal_per, temporal_fk_per2per; +ALTER TABLE temporal_fk_per2per + DROP CONSTRAINT temporal_fk_per2per_fk; +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON UPDATE NO ACTION; +-- a PK update that succeeds because the numeric id isn't referenced: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[5,6)', '2018-01-01', '2018-02-01'); +UPDATE temporal_per SET valid_from = '2016-01-01', valid_til = '2016-02-01' WHERE id = '[5,6)'; +-- a PK update that succeeds even though the numeric id is referenced because the range isn't: +DELETE FROM temporal_per WHERE id = '[5,6)'; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[5,6)', '2018-01-01', '2018-02-01'), + ('[5,6)', '2018-02-01', '2018-03-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES + ('[3,4)', '2018-01-05', '2018-01-10', '[5,6)'); +UPDATE temporal_per SET valid_from = '2016-02-01', valid_til = '2016-03-01' +WHERE id = '[5,6)' AND valid_from = '2018-02-01' AND valid_til = '2018-03-01'; +-- A PK update sliding the edge between two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[6,7)', '2018-01-01', '2018-02-01'), + ('[6,7)', '2018-02-01', '2018-03-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES + ('[4,5)', '2018-01-15', '2018-02-15', '[6,7)'); +UPDATE temporal_per +SET valid_from = CASE WHEN valid_from = '2018-01-01' THEN '2018-01-01' + WHEN valid_from = '2018-02-01' THEN '2018-01-05' END::date, + valid_til = CASE WHEN valid_from = '2018-01-01' THEN '2018-01-05' + WHEN valid_from = '2018-02-01' THEN '2018-03-01' END::date +WHERE id = '[6,7)'; +-- a PK update shrinking the referenced range but still valid: +-- There are two references: one fulfilled by the first pk row, +-- the other fulfilled by both pk rows combined. +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[1,2)', '2018-01-01', '2018-03-01'), + ('[1,2)', '2018-03-01', '2018-06-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES + ('[1,2)', '2018-01-15', '2018-02-01', '[1,2)'), + ('[2,3)', '2018-01-15', '2018-05-01', '[1,2)'); +UPDATE temporal_per SET valid_from = '2018-01-15', valid_til = '2018-03-01' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +-- a PK update growing the referenced range is fine: +UPDATE temporal_per SET valid_from = '2018-01-01', valid_til = '2018-03-01' +WHERE id = '[1,2)' AND valid_at @> '2018-01-25'::date; +-- a PK update shrinking the referenced range and changing the id invalidates the whole range: +UPDATE temporal_per SET id = '[2,3)', valid_from = '2018-01-15', valid_til = '2018-03-01' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +-- a PK update changing only the id invalidates the whole range: +UPDATE temporal_per SET id = '[2,3)' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +-- a PK update that loses time from both ends, but is still valid: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[2,3)', '2018-01-01', '2018-03-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES + ('[5,6)', '2018-01-15', '2018-02-01', '[2,3)'); +UPDATE temporal_per SET valid_from = '2018-01-15', valid_til = '2018-02-15' +WHERE id = '[2,3)'; +-- a PK update that fails because both are referenced: +UPDATE temporal_per SET valid_from = '2016-01-01', valid_til = '2016-02-01' +WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; +-- a PK update that fails because both are referenced, but not 'til commit: +BEGIN; + ALTER TABLE temporal_fk_per2per + ALTER CONSTRAINT temporal_fk_per2per_fk + DEFERRABLE INITIALLY DEFERRED; + + UPDATE temporal_per SET valid_from = '2016-01-01', valid_til = '2016-02-01' + WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); +COMMIT; +-- changing the scalar part fails: +UPDATE temporal_per SET id = '[7,8)' +WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; +-- changing an unreferenced part is okay: +UPDATE temporal_per +FOR PORTION OF valid_at FROM '2018-01-02' TO '2018-01-03' +SET id = '[7,8)' +WHERE id = '[5,6)'; +-- changing just a part fails: +UPDATE temporal_per +FOR PORTION OF valid_at FROM '2018-01-05' TO '2018-01-10' +SET id = '[7,8)' +WHERE id = '[5,6)'; +SELECT * FROM temporal_per WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; +SELECT * FROM temporal_fk_per2per WHERE id in ('[3,4)') ORDER BY id, valid_at; +-- then delete the objecting FK record and the same PK update succeeds: +DELETE FROM temporal_fk_per2per WHERE id = '[3,4)'; +UPDATE temporal_per SET valid_from = '2016-01-01', valid_til = '2016-02-01' +WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; + +-- +-- test FK referenced updates RESTRICT +-- + +TRUNCATE temporal_per, temporal_fk_per2per; +ALTER TABLE temporal_fk_per2per + DROP CONSTRAINT temporal_fk_per2per_fk; +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON UPDATE RESTRICT; + +-- +-- test FK referenced deletes NO ACTION +-- + +TRUNCATE temporal_per, temporal_fk_per2per; +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +-- a PK delete that succeeds because the numeric id isn't referenced: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[5,6)', '2018-01-01', '2018-02-01'); +DELETE FROM temporal_per WHERE id = '[5,6)'; +-- a PK delete that succeeds even though the numeric id is referenced because the range isn't: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[5,6)', '2018-01-01', '2018-02-01'), + ('[5,6)', '2018-02-01', '2018-03-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[3,4)', '2018-01-05', '2018-01-10', '[5,6)'); +DELETE FROM temporal_per WHERE id = '[5,6)' AND valid_from = '2018-02-01' AND valid_til = '2018-03-01'; +-- a PK delete that fails because both are referenced: +DELETE FROM temporal_per WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; +-- a PK delete that fails because both are referenced, but not 'til commit: +BEGIN; + ALTER TABLE temporal_fk_per2per + ALTER CONSTRAINT temporal_fk_per2per_fk + DEFERRABLE INITIALLY DEFERRED; + + DELETE FROM temporal_per WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); +COMMIT; +-- deleting an unreferenced part is okay: +DELETE FROM temporal_per +FOR PORTION OF valid_at FROM '2018-01-02' TO '2018-01-03' +WHERE id = '[5,6)'; +-- deleting just a part fails: +DELETE FROM temporal_per +FOR PORTION OF valid_at FROM '2018-01-05' TO '2018-01-10' +WHERE id = '[5,6)'; +SELECT * FROM temporal_per WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; +SELECT * FROM temporal_fk_per2per WHERE id in ('[3,4)') ORDER BY id, valid_at; +-- then delete the objecting FK record and the same PK delete succeeds: +DELETE FROM temporal_fk_per2per WHERE id = '[3,4)'; +DELETE FROM temporal_per WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; + +-- +-- test FK referenced deletes RESTRICT +-- + +TRUNCATE temporal_per, temporal_fk_per2per; +ALTER TABLE temporal_fk_per2per + DROP CONSTRAINT temporal_fk_per2per_fk; +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON DELETE RESTRICT; + +-- +-- per2per test ON UPDATE/DELETE options +-- +-- TOC: +-- referenced updates CASCADE +-- referenced deletes CASCADE +-- referenced updates SET NULL +-- referenced deletes SET NULL +-- referenced updates SET DEFAULT +-- referenced deletes SET DEFAULT +-- referenced updates CASCADE (two scalar cols) +-- referenced deletes CASCADE (two scalar cols) +-- referenced updates SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- referenced updates SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) + +-- +-- test FK referenced updates CASCADE +-- + +TRUNCATE temporal_per, temporal_fk_per2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +ALTER TABLE temporal_fk_per2per + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_per SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +UPDATE temporal_per SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes CASCADE +-- + +TRUNCATE temporal_per, temporal_fk_per2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_per WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +DELETE FROM temporal_per WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET NULL +-- + +TRUNCATE temporal_per, temporal_fk_per2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +ALTER TABLE temporal_fk_per2per + DROP CONSTRAINT temporal_fk_per2per_fk, + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_per SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +UPDATE temporal_per SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET NULL +-- + +TRUNCATE temporal_per, temporal_fk_per2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_per WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +DELETE FROM temporal_per WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET DEFAULT +-- + +TRUNCATE temporal_per, temporal_fk_per2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[-1,-1]', null, null); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +ALTER TABLE temporal_fk_per2per + ALTER COLUMN parent_id SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk_per2per_fk, + ADD CONSTRAINT temporal_fk_per2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_per SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +UPDATE temporal_per SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET DEFAULT +-- + +TRUNCATE temporal_per, temporal_fk_per2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[-1,-1]', null, null); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +DELETE FROM temporal_per WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +DELETE FROM temporal_per WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced updates CASCADE (two scalar cols) +-- + +TRUNCATE temporal_per2, temporal_fk2_per2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_per2per + DROP CONSTRAINT temporal_fk2_per2per_fk, + ADD CONSTRAINT temporal_fk2_per2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_per2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +UPDATE temporal_per2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes CASCADE (two scalar cols) +-- + +TRUNCATE temporal_per2, temporal_fk2_per2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET NULL (two scalar cols) +-- + +TRUNCATE temporal_per2, temporal_fk2_per2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_per2per + DROP CONSTRAINT temporal_fk2_per2per_fk, + ADD CONSTRAINT temporal_fk2_per2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_per2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +UPDATE temporal_per2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET NULL (two scalar cols) +-- + +TRUNCATE temporal_per2, temporal_fk2_per2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- + +TRUNCATE temporal_per2, temporal_fk2_per2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_per2per + DROP CONSTRAINT temporal_fk2_per2per_fk, + ADD CONSTRAINT temporal_fk2_per2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET NULL (valid_at) ON UPDATE SET NULL; +-- ok: +ALTER TABLE temporal_fk2_per2per + DROP CONSTRAINT temporal_fk2_per2per_fk, + ADD CONSTRAINT temporal_fk2_per2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET NULL (parent_id1) ON UPDATE SET NULL; +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET DEFAULT (two scalar cols) +-- + +TRUNCATE temporal_per2, temporal_fk2_per2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[-1,-1]', '[-1,-1]', null, null); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_per2per + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + ALTER COLUMN parent_id2 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_per2per_fk, + ADD CONSTRAINT temporal_fk2_per2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_per2 SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +UPDATE temporal_per2 SET id1 = '[9,10)', id2 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols) +-- + +TRUNCATE temporal_per2, temporal_fk2_per2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[-1,-1]', '[-1,-1]', null, null); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) +-- + +TRUNCATE temporal_per2, temporal_fk2_per2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[-1,-1]', '[6,7)', null, null); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_per2per + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_per2per_fk, + ADD CONSTRAINT temporal_fk2_per2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET DEFAULT (valid_at) ON UPDATE SET DEFAULT; +-- ok: +ALTER TABLE temporal_fk2_per2per + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_per2per_fk, + ADD CONSTRAINT temporal_fk2_per2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET DEFAULT (parent_id1) ON UPDATE SET DEFAULT; +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[-1,-1]', '[8,9)', null, null); +INSERT INTO temporal_fk2_per2per (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FOREIGN KEY, range references PERIOD +-- + +-- test table setup +DROP TABLE temporal_per CASCADE; +CREATE TABLE temporal_per ( + id int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til) +); +ALTER TABLE temporal_per + ADD CONSTRAINT temporal_per_pk + PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); + +-- Can't create a FK with a mismatched range type +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at int4range, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id, PERIOD valid_at) +); + +-- works: PERIOD for referenced, range for referencing +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id, PERIOD valid_at) +); +\d temporal_fk_rng2per +DROP TABLE temporal_fk_rng2per; + +-- with mismatched PERIOD columns: + +-- (parent_id, PERIOD valid_at) REFERENCES (id, valid_at) +-- REFERENCES part should specify PERIOD +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id, valid_at) +); +-- (parent_id, valid_at) REFERENCES (id, valid_at) +-- both should specify PERIOD: +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_per (id, valid_at) +); +-- (parent_id, valid_at) REFERENCES (id, PERIOD valid_at) +-- FOREIGN KEY part should specify PERIOD +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_per (id, PERIOD valid_at) +); +-- (parent_id, valid_at) REFERENCES [implicit] +-- FOREIGN KEY part should specify PERIOD +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_per +); +-- (parent_id, PERIOD valid_at) REFERENCES (id) +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id) +); +-- (parent_id) REFERENCES (id, PERIOD valid_at) +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id) + REFERENCES temporal_per (id, PERIOD valid_at) +); +-- with inferred PK on the referenced table: +-- (parent_id, PERIOD valid_at) REFERENCES [implicit] +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per +); +DROP TABLE temporal_fk_rng2per; +-- (parent_id) REFERENCES [implicit] +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id) + REFERENCES temporal_per +); + +-- should fail because of duplicate referenced columns: +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_rng2per_fk FOREIGN KEY (parent_id, PERIOD parent_id) + REFERENCES temporal_per (id, PERIOD id) +); + +-- Two scalar columns +DROP TABLE temporal_per2 CASCADE; +CREATE TABLE temporal_per2 ( + id1 int4range, + id2 int4range, + valid_from date, + valid_til date, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_per2_pk PRIMARY KEY (id1, id2, valid_at WITHOUT OVERLAPS) +); + +CREATE TABLE temporal_fk2_rng2per ( + id int4range, + valid_at daterange, + parent_id1 int4range, + parent_id2 int4range, + CONSTRAINT temporal_fk2_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk2_rng2per_fk FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 (id1, id2, PERIOD valid_at) +); +\d temporal_fk2_rng2per +DROP TABLE temporal_fk2_rng2per; + +-- +-- test ALTER TABLE ADD CONSTRAINT +-- + +CREATE TABLE temporal_fk_rng2per ( + id int4range, + valid_at daterange, + parent_id int4range, + CONSTRAINT temporal_fk_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per (id, PERIOD valid_at); +-- Two scalar columns: +CREATE TABLE temporal_fk2_rng2per ( + id int4range, + valid_at daterange, + parent_id1 int4range, + parent_id2 int4range, + CONSTRAINT temporal_fk2_rng2per_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +ALTER TABLE temporal_fk2_rng2per + ADD CONSTRAINT temporal_fk2_rng2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 (id1, id2, PERIOD valid_at); +\d temporal_fk2_rng2per + +-- with inferred PK on the referenced table, and wrong column type: +ALTER TABLE temporal_fk_rng2per + DROP CONSTRAINT temporal_fk_rng2per_fk, + ALTER COLUMN valid_at TYPE tsrange USING tsrange(lower(valid_at), upper(valid_at)); +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +ALTER TABLE temporal_fk_rng2per + ALTER COLUMN valid_at TYPE daterange USING daterange(lower(valid_at)::date, upper(valid_at)::date); + +-- with inferred PK on the referenced table: +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; + +-- should fail because of duplicate referenced columns: +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk2 + FOREIGN KEY (parent_id, PERIOD parent_id) + REFERENCES temporal_per (id, PERIOD id); + +-- +-- test with rows already +-- + +DELETE FROM temporal_fk_rng2per; +DELETE FROM temporal_per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[1,2)', '2018-01-02', '2018-02-03'), + ('[1,2)', '2018-03-03', '2018-04-04'), + ('[2,3)', '2018-01-01', '2018-01-05'), + ('[3,4)', '2018-01-01', NULL); + +ALTER TABLE temporal_fk_rng2per + DROP CONSTRAINT temporal_fk_rng2per_fk; +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[1,2)', '[2018-01-02,2018-02-01)', '[1,2)'); +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +ALTER TABLE temporal_fk_rng2per + DROP CONSTRAINT temporal_fk_rng2per_fk; +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[2,3)', '[2018-01-02,2018-04-01)', '[1,2)'); +-- should fail: +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +-- okay again: +DELETE FROM temporal_fk_rng2per; +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; + +-- +-- test pg_get_constraintdef +-- + +SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_fk_rng2per_fk'; + +-- +-- test FK referencing inserts +-- + +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[1,2)', '[2018-01-02,2018-02-01)', '[1,2)'); +-- should fail: +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[2,3)', '[2018-01-02,2018-04-01)', '[1,2)'); +-- now it should work: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[1,2)', '2018-02-03', '2018-03-03'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[2,3)', '[2018-01-02,2018-04-01)', '[1,2)'); + +-- +-- test FK referencing updates +-- + +-- slide the edge across a referenced transition: +UPDATE temporal_fk_rng2per SET valid_at = '[2018-01-02,2018-02-20)' WHERE id = '[1,2)'; +-- should fail: +UPDATE temporal_fk_rng2per SET valid_at = '[2018-01-02,2018-05-01)' WHERE id = '[1,2)'; +UPDATE temporal_fk_rng2per SET parent_id = '[8,9)' WHERE id = '[1,2)'; + +-- ALTER FK DEFERRABLE + +BEGIN; + INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[5,6)', '2018-01-01', '2018-02-01'), + ('[5,6)', '2018-02-01', '2018-03-01'); + INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES + ('[3,4)', '[2018-01-05,2018-01-10)', '[5,6)'); + ALTER TABLE temporal_fk_rng2per + ALTER CONSTRAINT temporal_fk_rng2per_fk + DEFERRABLE INITIALLY DEFERRED; + + DELETE FROM temporal_per WHERE id = '[5,6)'; --should not fail yet. +COMMIT; -- should fail here. + +-- +-- test FK referenced updates NO ACTION +-- + +TRUNCATE temporal_per, temporal_fk_rng2per; +ALTER TABLE temporal_fk_rng2per + DROP CONSTRAINT temporal_fk_rng2per_fk; +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON UPDATE NO ACTION; +-- a PK update that succeeds because the numeric id isn't referenced: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[5,6)', '2018-01-01', '2018-02-01'); +UPDATE temporal_per SET valid_from = '2016-01-01', valid_til = '2016-02-01' WHERE id = '[5,6)'; +-- a PK update that succeeds even though the numeric id is referenced because the range isn't: +DELETE FROM temporal_per WHERE id = '[5,6)'; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[5,6)', '2018-01-01', '2018-02-01'), + ('[5,6)', '2018-02-01', '2018-03-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES + ('[3,4)', '[2018-01-05,2018-01-10)', '[5,6)'); +UPDATE temporal_per SET valid_from = '2016-02-01', valid_til = '2016-03-01' +WHERE id = '[5,6)' AND valid_from = '2018-02-01' AND valid_til = '2018-03-01'; +-- A PK update sliding the edge between two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[6,7)', '2018-01-01', '2018-02-01'), + ('[6,7)', '2018-02-01', '2018-03-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES + ('[4,5)', '[2018-01-15,2018-02-15)', '[6,7)'); +UPDATE temporal_per +SET valid_from = CASE WHEN valid_from = '2018-01-01' THEN '2018-01-01' + WHEN valid_from = '2018-02-01' THEN '2018-01-05' END::date, + valid_til = CASE WHEN valid_from = '2018-01-01' THEN '2018-01-05' + WHEN valid_from = '2018-02-01' THEN '2018-03-01' END::date +WHERE id = '[6,7)'; +-- a PK update shrinking the referenced range but still valid: +-- There are two references: one fulfilled by the first pk row, +-- the other fulfilled by both pk rows combined. +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[1,2)', '2018-01-01', '2018-03-01'), + ('[1,2)', '2018-03-01', '2018-06-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES + ('[1,2)', '[2018-01-15,2018-02-01)', '[1,2)'), + ('[2,3)', '[2018-01-15,2018-05-01)', '[1,2)'); +UPDATE temporal_per SET valid_from = '2018-01-15', valid_til = '2018-03-01' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +-- a PK update growing the referenced range is fine: +UPDATE temporal_per SET valid_from = '2018-01-01', valid_til = '2018-03-01' +WHERE id = '[1,2)' AND valid_at @> '2018-01-25'::date; +-- a PK update shrinking the referenced range and changing the id invalidates the whole range: +UPDATE temporal_per SET id = '[2,3)', valid_from = '2018-01-15', valid_til = '2018-03-01' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +-- a PK update changing only the id invalidates the whole range: +UPDATE temporal_per SET id = '[2,3)' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +-- a PK update that loses time from both ends, but is still valid: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[2,3)', '2018-01-01', '2018-03-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES + ('[5,6)', '[2018-01-15,2018-02-01)', '[2,3)'); +UPDATE temporal_per SET valid_from = '2018-01-15', valid_til = '2018-02-15' +WHERE id = '[2,3)'; +-- a PK update that fails because both are referenced: +UPDATE temporal_per SET valid_from = '2016-01-01', valid_til = '2016-02-01' +WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; +-- a PK update that fails because both are referenced, but not 'til commit: +BEGIN; + ALTER TABLE temporal_fk_rng2per + ALTER CONSTRAINT temporal_fk_rng2per_fk + DEFERRABLE INITIALLY DEFERRED; + + UPDATE temporal_per SET valid_from = '2016-01-01', valid_til = '2016-02-01' + WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); +COMMIT; +-- changing the scalar part fails: +UPDATE temporal_per SET id = '[7,8)' +WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; +-- changing an unreferenced part is okay: +UPDATE temporal_per +FOR PORTION OF valid_at FROM '2018-01-02' TO '2018-01-03' +SET id = '[7,8)' +WHERE id = '[5,6)'; +-- changing just a part fails: +UPDATE temporal_per +FOR PORTION OF valid_at FROM '2018-01-05' TO '2018-01-10' +SET id = '[7,8)' +WHERE id = '[5,6)'; +SELECT * FROM temporal_per WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; +SELECT * FROM temporal_fk_rng2per WHERE id in ('[3,4)') ORDER BY id, valid_at; +-- then delete the objecting FK record and the same PK update succeeds: +DELETE FROM temporal_fk_rng2per WHERE id = '[3,4)'; +UPDATE temporal_per SET valid_from = '2016-01-01', valid_til = '2016-02-01' +WHERE id = '[5,6)' AND valid_at = '[2018-01-01,2018-02-01)'; + +-- +-- test FK referenced updates RESTRICT +-- + +TRUNCATE temporal_per, temporal_fk_rng2per; +ALTER TABLE temporal_fk_rng2per + DROP CONSTRAINT temporal_fk_rng2per_fk; +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON UPDATE RESTRICT; + +-- +-- test FK referenced deletes NO ACTION +-- + +TRUNCATE temporal_per, temporal_fk_rng2per; +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per; +-- a PK delete that succeeds because the numeric id isn't referenced: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[5,6)', '2018-01-01', '2018-02-01'); +DELETE FROM temporal_per WHERE id = '[5,6)'; +-- a PK delete that succeeds even though the numeric id is referenced because the range isn't: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES + ('[5,6)', '2018-01-01', '2018-02-01'), + ('[5,6)', '2018-02-01', '2018-03-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[3,4)', '[2018-01-05,2018-01-10)', '[5,6)'); +DELETE FROM temporal_per WHERE id = '[5,6)' AND valid_from = '2018-02-01' AND valid_til = '2018-03-01'; +-- a PK delete that fails because both are referenced: +DELETE FROM temporal_per WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; +-- a PK delete that fails because both are referenced, but not 'til commit: +BEGIN; + ALTER TABLE temporal_fk_rng2per + ALTER CONSTRAINT temporal_fk_rng2per_fk + DEFERRABLE INITIALLY DEFERRED; + + DELETE FROM temporal_per WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); +COMMIT; +-- deleting an unreferenced part is okay: +DELETE FROM temporal_per +FOR PORTION OF valid_at FROM '2018-01-02' TO '2018-01-03' +WHERE id = '[5,6)'; +-- deleting just a part fails: +DELETE FROM temporal_per +FOR PORTION OF valid_at FROM '2018-01-05' TO '2018-01-10' +WHERE id = '[5,6)'; +SELECT * FROM temporal_per WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; +SELECT * FROM temporal_fk_rng2per WHERE id in ('[3,4)') ORDER BY id, valid_at; +-- then delete the objecting FK record and the same PK delete succeeds: +DELETE FROM temporal_fk_rng2per WHERE id = '[3,4)'; +DELETE FROM temporal_per WHERE id = '[5,6)' AND valid_from = '2018-01-01' AND valid_til = '2018-02-01'; + +-- +-- test FK referenced deletes RESTRICT +-- + +TRUNCATE temporal_per, temporal_fk_rng2per; +ALTER TABLE temporal_fk_rng2per + DROP CONSTRAINT temporal_fk_rng2per_fk; +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON DELETE RESTRICT; + +-- +-- rng2per test ON UPDATE/DELETE options +-- +-- TOC: +-- referenced updates CASCADE +-- referenced deletes CASCADE +-- referenced updates SET NULL +-- referenced deletes SET NULL +-- referenced updates SET DEFAULT +-- referenced deletes SET DEFAULT +-- referenced updates CASCADE (two scalar cols) +-- referenced deletes CASCADE (two scalar cols) +-- referenced updates SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- referenced updates SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) + +-- +-- test FK referenced updates CASCADE +-- + +TRUNCATE temporal_per, temporal_fk_rng2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)'); +ALTER TABLE temporal_fk_rng2per + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_per SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)'); +UPDATE temporal_per SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes CASCADE +-- + +TRUNCATE temporal_per, temporal_fk_rng2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_per WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)'); +DELETE FROM temporal_per WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET NULL +-- + +TRUNCATE temporal_per, temporal_fk_rng2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)'); +ALTER TABLE temporal_fk_rng2per + DROP CONSTRAINT temporal_fk_rng2per_fk, + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_per SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)'); +UPDATE temporal_per SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET NULL +-- + +TRUNCATE temporal_per, temporal_fk_rng2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_per WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)'); +DELETE FROM temporal_per WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET DEFAULT +-- + +TRUNCATE temporal_per, temporal_fk_rng2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[-1,-1]', null, null); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)'); +ALTER TABLE temporal_fk_rng2per + ALTER COLUMN parent_id SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk_rng2per_fk, + ADD CONSTRAINT temporal_fk_rng2per_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_per + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_per SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)'); +UPDATE temporal_per SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET DEFAULT +-- + +TRUNCATE temporal_per, temporal_fk_rng2per; +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[-1,-1]', null, null); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +DELETE FROM temporal_per WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per (id, valid_from, valid_til) VALUES ('[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk_rng2per (id, valid_at, parent_id) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)'); +DELETE FROM temporal_per WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced updates CASCADE (two scalar cols) +-- + +TRUNCATE temporal_per2, temporal_fk2_rng2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_rng2per + DROP CONSTRAINT temporal_fk2_rng2per_fk, + ADD CONSTRAINT temporal_fk2_rng2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_per2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)', '[8,9)'); +UPDATE temporal_per2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes CASCADE (two scalar cols) +-- + +TRUNCATE temporal_per2, temporal_fk2_rng2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET NULL (two scalar cols) +-- + +TRUNCATE temporal_per2, temporal_fk2_rng2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_rng2per + DROP CONSTRAINT temporal_fk2_rng2per_fk, + ADD CONSTRAINT temporal_fk2_rng2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_per2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)', '[8,9)'); +UPDATE temporal_per2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET NULL (two scalar cols) +-- + +TRUNCATE temporal_per2, temporal_fk2_rng2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- + +TRUNCATE temporal_per2, temporal_fk2_rng2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_rng2per + DROP CONSTRAINT temporal_fk2_rng2per_fk, + ADD CONSTRAINT temporal_fk2_rng2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET NULL (valid_at) ON UPDATE SET NULL; +-- ok: +ALTER TABLE temporal_fk2_rng2per + DROP CONSTRAINT temporal_fk2_rng2per_fk, + ADD CONSTRAINT temporal_fk2_rng2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET NULL (parent_id1) ON UPDATE SET NULL; +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET DEFAULT (two scalar cols) +-- + +TRUNCATE temporal_per2, temporal_fk2_rng2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[-1,-1]', '[-1,-1]', null, null); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_rng2per + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + ALTER COLUMN parent_id2 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_rng2per_fk, + ADD CONSTRAINT temporal_fk2_rng2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_per2 SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)', '[8,9)'); +UPDATE temporal_per2 SET id1 = '[9,10)', id2 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols) +-- + +TRUNCATE temporal_per2, temporal_fk2_rng2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[-1,-1]', '[-1,-1]', null, null); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) +-- + +TRUNCATE temporal_per2, temporal_fk2_rng2per; +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[-1,-1]', '[6,7)', null, null); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[6,7)', '[6,7)', '2018-01-01', '2021-01-01'); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[100,100]', '[2018-01-01,2021-01-01)', '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_rng2per + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_rng2per_fk, + ADD CONSTRAINT temporal_fk2_rng2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET DEFAULT (valid_at) ON UPDATE SET DEFAULT; +-- ok: +ALTER TABLE temporal_fk2_rng2per + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_rng2per_fk, + ADD CONSTRAINT temporal_fk2_rng2per_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_per2 + ON DELETE SET DEFAULT (parent_id1) ON UPDATE SET DEFAULT; +-- leftovers on both sides: +DELETE FROM temporal_per2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +DELETE FROM temporal_per2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2018-01-01', '2020-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[8,9)', '[8,9)', '2020-01-01', '2021-01-01'); +INSERT INTO temporal_per2 (id1, id2, valid_from, valid_til) VALUES ('[-1,-1]', '[8,9)', null, null); +INSERT INTO temporal_fk2_rng2per (id, valid_at, parent_id1, parent_id2) VALUES ('[200,200]', '[2018-01-01,2021-01-01)', '[8,9)', '[8,9)'); +DELETE FROM temporal_per2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_rng2per WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FOREIGN KEY, PERIOD references range +-- + +-- test table setup +DROP TABLE temporal_rng CASCADE; +CREATE TABLE temporal_rng ( + id int4range, + valid_at daterange +); +ALTER TABLE temporal_rng + ADD CONSTRAINT temporal_rng_pk + PRIMARY KEY (id, valid_at WITHOUT OVERLAPS); + +-- Can't create a FK with a mismatched range type +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from int, + valid_til int, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng (id, PERIOD valid_at) +); + +-- works: range for referenced, PERIOD for referencing +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng (id, PERIOD valid_at) +); +\d temporal_fk_per2rng +DROP TABLE temporal_fk_per2rng; + +-- with mismatched PERIOD columns: + +-- (parent_id, PERIOD valid_at) REFERENCES (id, valid_at) +-- REFERENCES part should specify PERIOD +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng (id, valid_at) +); +-- (parent_id, valid_at) REFERENCES (id, valid_at) +-- both should specify PERIOD: +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_rng (id, valid_at) +); +-- (parent_id, valid_at) REFERENCES (id, PERIOD valid_at) +-- FOREIGN KEY part should specify PERIOD +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_rng (id, PERIOD valid_at) +); +-- (parent_id, valid_at) REFERENCES [implicit] +-- FOREIGN KEY part should specify PERIOD +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, valid_at) + REFERENCES temporal_rng +); +-- (parent_id, PERIOD valid_at) REFERENCES (id) +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng (id) +); +-- (parent_id) REFERENCES (id, PERIOD valid_at) +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id) + REFERENCES temporal_rng (id, PERIOD valid_at) +); +-- with inferred PK on the referenced table: +-- (parent_id, PERIOD valid_at) REFERENCES [implicit] +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng +); +DROP TABLE temporal_fk_per2rng; +-- (parent_id) REFERENCES [implicit] +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id) + REFERENCES temporal_rng +); + +-- should fail because of duplicate referenced columns: +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk_per2rng_fk FOREIGN KEY (parent_id, PERIOD parent_id) + REFERENCES temporal_rng (id, PERIOD id) +); + +-- Two scalar columns +DROP TABLE temporal_rng2 CASCADE; +CREATE TABLE temporal_rng2 ( + id1 int4range, + id2 int4range, + valid_at daterange, + CONSTRAINT temporal_rng2_pk PRIMARY KEY (id1, id2, valid_at WITHOUT OVERLAPS) +); + +CREATE TABLE temporal_fk2_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id1 int4range, + parent_id2 int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk2_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk2_per2rng_fk FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 (id1, id2, PERIOD valid_at) +); +\d temporal_fk2_per2rng +DROP TABLE temporal_fk2_per2rng; + +-- +-- test ALTER TABLE ADD CONSTRAINT +-- + +CREATE TABLE temporal_fk_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng (id, PERIOD valid_at); +-- Two scalar columns: +CREATE TABLE temporal_fk2_per2rng ( + id int4range, + valid_from date, + valid_til date, + parent_id1 int4range, + parent_id2 int4range, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_fk2_per2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +ALTER TABLE temporal_fk2_per2rng + ADD CONSTRAINT temporal_fk2_per2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 (id1, id2, PERIOD valid_at); +\d temporal_fk2_per2rng + +-- with inferred PK on the referenced table, and wrong column type: +ALTER TABLE temporal_fk_per2rng + DROP CONSTRAINT temporal_fk_per2rng_fk, + DROP PERIOD FOR valid_at, + ALTER COLUMN valid_from TYPE timestamp, + ALTER COLUMN valid_til TYPE timestamp, + ADD PERIOD FOR valid_at (valid_from, valid_til); +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng; +ALTER TABLE temporal_fk_per2rng + DROP PERIOD FOR valid_at, + ALTER COLUMN valid_from TYPE date, + ALTER COLUMN valid_til TYPE date, + ADD PERIOD FOR valid_at (valid_from, valid_til); + +-- with inferred PK on the referenced table: +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng; + +-- should fail because of duplicate referenced columns: +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk2 + FOREIGN KEY (parent_id, PERIOD parent_id) + REFERENCES temporal_rng (id, PERIOD id); + +-- +-- test with rows already +-- + +DELETE FROM temporal_fk_per2rng; +DELETE FROM temporal_rng; +INSERT INTO temporal_rng (id, valid_at) VALUES + ('[1,2)', '[2018-01-02,2018-02-03)'), + ('[1,2)', '[2018-03-03,2018-04-04)'), + ('[2,3)', '[2018-01-01,2018-01-05)'), + ('[3,4)', '[2018-01-01,)'); + +ALTER TABLE temporal_fk_per2rng + DROP CONSTRAINT temporal_fk_per2rng_fk; +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[1,2)', '2018-01-02', '2018-02-01', '[1,2)'); +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng; +ALTER TABLE temporal_fk_per2rng + DROP CONSTRAINT temporal_fk_per2rng_fk; +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[2,3)', '2018-01-02', '2018-04-01', '[1,2)'); +-- should fail: +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng; +-- okay again: +DELETE FROM temporal_fk_per2rng; +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng; + +-- +-- test pg_get_constraintdef +-- + +SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_fk_per2rng_fk'; + +-- +-- test FK referencing inserts +-- + +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[1,2)', '2018-01-02', '2018-02-01', '[1,2)'); +-- should fail: +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[2,3)', '2018-01-02', '2018-04-01', '[1,2)'); +-- now it should work: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[1,2)', '[2018-02-03,2018-03-03)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[2,3)', '2018-01-02', '2018-04-01', '[1,2)'); + +-- +-- test FK referencing updates +-- + +-- slide the edge across a referenced transition: +UPDATE temporal_fk_per2rng SET valid_from = '2018-01-02', valid_til = '2018-02-20' WHERE id = '[1,2)'; +-- should fail: +UPDATE temporal_fk_per2rng SET valid_from = '2018-01-02', valid_til = '2018-05-01' WHERE id = '[1,2)'; +UPDATE temporal_fk_per2rng SET parent_id = '[8,9)' WHERE id = '[1,2)'; + +-- ALTER FK DEFERRABLE + +BEGIN; + INSERT INTO temporal_rng (id, valid_at) VALUES + ('[5,6)', '[2018-01-01,2018-02-01)'), + ('[5,6)', '[2018-02-01,2018-03-01)'); + INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES + ('[3,4)', '2018-01-05', '2018-01-10', '[5,6)'); + ALTER TABLE temporal_fk_per2rng + ALTER CONSTRAINT temporal_fk_per2rng_fk + DEFERRABLE INITIALLY DEFERRED; + + DELETE FROM temporal_rng WHERE id = '[5,6)'; --should not fail yet. +COMMIT; -- should fail here. + +-- +-- test FK referenced updates NO ACTION +-- + +TRUNCATE temporal_rng, temporal_fk_per2rng; +ALTER TABLE temporal_fk_per2rng + DROP CONSTRAINT temporal_fk_per2rng_fk; +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng + ON UPDATE NO ACTION; +-- a PK update that succeeds because the numeric id isn't referenced: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[5,6)', '[2018-01-01,2018-02-01)'); +UPDATE temporal_rng SET valid_at = '[2016-01-01,2016-02-01)' WHERE id = '[5,6)'; +-- a PK update that succeeds even though the numeric id is referenced because the range isn't: +DELETE FROM temporal_rng WHERE id = '[5,6)'; +INSERT INTO temporal_rng (id, valid_at) VALUES + ('[5,6)', '[2018-01-01,2018-02-01)'), + ('[5,6)', '[2018-02-01,2018-03-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES + ('[3,4)', '2018-01-05', '2018-01-10', '[5,6)'); +UPDATE temporal_rng SET valid_at = '[2016-02-01,2016-03-01)' +WHERE id = '[5,6)' AND valid_at = '[2018-02-01,2018-03-01)'; +-- A PK update sliding the edge between two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES + ('[6,7)', '[2018-01-01,2018-02-01)'), + ('[6,7)', '[2018-02-01,2018-03-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES + ('[4,5)', '2018-01-15', '2018-02-15', '[6,7)'); +UPDATE temporal_rng +SET valid_at = CASE WHEN lower(valid_at) = '2018-01-01' THEN daterange('2018-01-01', '2018-01-05') + WHEN lower(valid_at) = '2018-02-01' THEN daterange('2018-01-05', '2018-03-01') END +WHERE id = '[6,7)'; +-- a PK update shrinking the referenced range but still valid: +-- There are two references: one fulfilled by the first pk row, +-- the other fulfilled by both pk rows combined. +INSERT INTO temporal_rng (id, valid_at) VALUES + ('[1,2)', '[2018-01-01,2018-03-01)'), + ('[1,2)', '[2018-03-01,2018-06-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES + ('[1,2)', '2018-01-15', '2018-02-01', '[1,2)'), + ('[2,3)', '2018-01-15', '2018-05-01', '[1,2)'); +UPDATE temporal_rng SET valid_at = '[2018-01-15,2018-03-01)' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +-- a PK update growing the referenced range is fine: +UPDATE temporal_rng SET valid_at = '[2018-01-01,2018-03-01)' +WHERE id = '[1,2)' AND valid_at @> '2018-01-25'::date; +-- a PK update shrinking the referenced range and changing the id invalidates the whole range: +UPDATE temporal_rng SET id = '[2,3)', valid_at = '[2018-01-15,2018-03-01)' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +-- a PK update changing only the id invalidates the whole range: +UPDATE temporal_rng SET id = '[2,3)' +WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date; +-- a PK update that loses time from both ends, but is still valid: +INSERT INTO temporal_rng (id, valid_at) VALUES + ('[2,3)', '[2018-01-01,2018-03-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES + ('[5,6)', '2018-01-15', '2018-02-01', '[2,3)'); +UPDATE temporal_rng SET valid_at = '[2018-01-15,2018-02-15)' +WHERE id = '[2,3)'; +-- a PK update that fails because both are referenced: +UPDATE temporal_rng SET valid_at = '[2016-01-01,2016-02-01)' +WHERE id = '[5,6)' AND valid_at = '[2018-01-01,2018-02-01)'; +-- a PK update that fails because both are referenced, but not 'til commit: +BEGIN; + ALTER TABLE temporal_fk_per2rng + ALTER CONSTRAINT temporal_fk_per2rng_fk + DEFERRABLE INITIALLY DEFERRED; + + UPDATE temporal_rng SET valid_at = '[2016-01-01,2016-02-01)' + WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); +COMMIT; +-- changing the scalar part fails: +UPDATE temporal_rng SET id = '[7,8)' +WHERE id = '[5,6)' AND valid_at = '[2018-01-01,2018-02-01)'; +-- changing an unreferenced part is okay: +UPDATE temporal_rng +FOR PORTION OF valid_at FROM '2018-01-02' TO '2018-01-03' +SET id = '[7,8)' +WHERE id = '[5,6)'; +-- changing just a part fails: +UPDATE temporal_rng +FOR PORTION OF valid_at FROM '2018-01-05' TO '2018-01-10' +SET id = '[7,8)' +WHERE id = '[5,6)'; +SELECT * FROM temporal_rng WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; +SELECT * FROM temporal_fk_per2rng WHERE id in ('[3,4)') ORDER BY id, valid_at; +-- then delete the objecting FK record and the same PK update succeeds: +DELETE FROM temporal_fk_per2rng WHERE id = '[3,4)'; +UPDATE temporal_rng SET valid_at = '[2016-01-01,2016-02-01)' +WHERE id = '[5,6)' AND valid_at = '[2018-01-01,2018-02-01)'; + +-- +-- test FK referenced updates RESTRICT +-- + +TRUNCATE temporal_rng, temporal_fk_per2rng; +ALTER TABLE temporal_fk_per2rng + DROP CONSTRAINT temporal_fk_per2rng_fk; +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng + ON UPDATE RESTRICT; + +-- +-- test FK referenced deletes NO ACTION +-- + +TRUNCATE temporal_rng, temporal_fk_per2rng; +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng; +-- a PK delete that succeeds because the numeric id isn't referenced: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[5,6)', '[2018-01-01,2018-02-01)'); +DELETE FROM temporal_rng WHERE id = '[5,6)'; +-- a PK delete that succeeds even though the numeric id is referenced because the range isn't: +INSERT INTO temporal_rng (id, valid_at) VALUES + ('[5,6)', '[2018-01-01,2018-02-01)'), + ('[5,6)', '[2018-02-01,2018-03-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[3,4)', '2018-01-05', '2018-01-10', '[5,6)'); +DELETE FROM temporal_rng WHERE id = '[5,6)' AND valid_at = '[2018-02-01,2018-03-01)'; +-- a PK delete that fails because both are referenced: +DELETE FROM temporal_rng WHERE id = '[5,6)' AND valid_at = '[2018-01-01,2018-02-01)'; +-- a PK delete that fails because both are referenced, but not 'til commit: +BEGIN; + ALTER TABLE temporal_fk_per2rng + ALTER CONSTRAINT temporal_fk_per2rng_fk + DEFERRABLE INITIALLY DEFERRED; + + DELETE FROM temporal_rng WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01'); +COMMIT; +-- deleting an unreferenced part is okay: +DELETE FROM temporal_rng +FOR PORTION OF valid_at FROM '2018-01-02' TO '2018-01-03' +WHERE id = '[5,6)'; +-- deleting just a part fails: +DELETE FROM temporal_rng +FOR PORTION OF valid_at FROM '2018-01-05' TO '2018-01-10' +WHERE id = '[5,6)'; +SELECT * FROM temporal_rng WHERE id in ('[5,6)', '[7,8)') ORDER BY id, valid_at; +SELECT * FROM temporal_fk_per2rng WHERE id in ('[3,4)') ORDER BY id, valid_at; +-- then delete the objecting FK record and the same PK delete succeeds: +DELETE FROM temporal_fk_per2rng WHERE id = '[3,4)'; +DELETE FROM temporal_rng WHERE id = '[5,6)' AND valid_at = '[2018-01-01,2018-02-01)'; + +-- +-- test FK referenced deletes RESTRICT +-- + +TRUNCATE temporal_rng, temporal_fk_per2rng; +ALTER TABLE temporal_fk_per2rng + DROP CONSTRAINT temporal_fk_per2rng_fk; +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng + ON DELETE RESTRICT; + +-- +-- per2rng test ON UPDATE/DELETE options +-- +-- TOC: +-- referenced updates CASCADE +-- referenced deletes CASCADE +-- referenced updates SET NULL +-- referenced deletes SET NULL +-- referenced updates SET DEFAULT +-- referenced deletes SET DEFAULT +-- referenced updates CASCADE (two scalar cols) +-- referenced deletes CASCADE (two scalar cols) +-- referenced updates SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols) +-- referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- referenced updates SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols) +-- referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) + +-- +-- test FK referenced updates CASCADE +-- + +TRUNCATE temporal_rng, temporal_fk_per2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +ALTER TABLE temporal_fk_per2rng + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_rng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +UPDATE temporal_rng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes CASCADE +-- + +TRUNCATE temporal_rng, temporal_fk_per2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_rng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +DELETE FROM temporal_rng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET NULL +-- + +TRUNCATE temporal_rng, temporal_fk_per2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +ALTER TABLE temporal_fk_per2rng + DROP CONSTRAINT temporal_fk_per2rng_fk, + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_rng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +UPDATE temporal_rng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET NULL +-- + +TRUNCATE temporal_rng, temporal_fk_per2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_rng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +DELETE FROM temporal_rng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET DEFAULT +-- + +TRUNCATE temporal_rng, temporal_fk_per2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[-1,-1]', '(,)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +ALTER TABLE temporal_fk_per2rng + ALTER COLUMN parent_id SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk_per2rng_fk, + ADD CONSTRAINT temporal_fk_per2rng_fk + FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_rng SET id = '[7,8)' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +UPDATE temporal_rng SET id = '[9,10)' WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET DEFAULT +-- + +TRUNCATE temporal_rng, temporal_fk_per2rng; +INSERT INTO temporal_rng (id, valid_at) VALUES ('[-1,-1]', '(,)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +DELETE FROM temporal_rng WHERE id = '[6,7)'; +SELECT * FROM temporal_fk_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng (id, valid_at) VALUES ('[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk_per2rng (id, valid_from, valid_til, parent_id) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)'); +DELETE FROM temporal_rng WHERE id = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced updates CASCADE (two scalar cols) +-- + +TRUNCATE temporal_rng2, temporal_fk2_per2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_per2rng + DROP CONSTRAINT temporal_fk2_per2rng_fk, + ADD CONSTRAINT temporal_fk2_per2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE CASCADE ON UPDATE CASCADE; +-- leftovers on both sides: +UPDATE temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_rng2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +UPDATE temporal_rng2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes CASCADE (two scalar cols) +-- + +TRUNCATE temporal_rng2, temporal_fk2_per2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET NULL (two scalar cols) +-- + +TRUNCATE temporal_rng2, temporal_fk2_per2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_per2rng + DROP CONSTRAINT temporal_fk2_per2rng_fk, + ADD CONSTRAINT temporal_fk2_per2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET NULL ON UPDATE SET NULL; +-- leftovers on both sides: +UPDATE temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_rng2 SET id1 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +UPDATE temporal_rng2 SET id1 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET NULL (two scalar cols) +-- + +TRUNCATE temporal_rng2, temporal_fk2_per2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET NULL (two scalar cols, SET NULL subset) +-- + +TRUNCATE temporal_rng2, temporal_fk2_per2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_per2rng + DROP CONSTRAINT temporal_fk2_per2rng_fk, + ADD CONSTRAINT temporal_fk2_per2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET NULL (valid_at) ON UPDATE SET NULL; +-- ok: +ALTER TABLE temporal_fk2_per2rng + DROP CONSTRAINT temporal_fk2_per2rng_fk, + ADD CONSTRAINT temporal_fk2_per2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET NULL (parent_id1) ON UPDATE SET NULL; +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO delete: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced updates SET DEFAULT (two scalar cols) +-- + +TRUNCATE temporal_rng2, temporal_fk2_per2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[-1,-1]', '(,)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +ALTER TABLE temporal_fk2_per2rng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + ALTER COLUMN parent_id2 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_per2rng_fk, + ADD CONSTRAINT temporal_fk2_per2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET DEFAULT ON UPDATE SET DEFAULT; +-- leftovers on both sides: +UPDATE temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +UPDATE temporal_rng2 SET id1 = '[7,8)', id2 = '[7,8)' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +UPDATE temporal_rng2 SET id1 = '[9,10)', id2 = '[9,10)' WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols) +-- + +TRUNCATE temporal_rng2, temporal_fk2_per2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[-1,-1]', '(,)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- +-- test FK referenced deletes SET DEFAULT (two scalar cols, SET DEFAULT subset) +-- + +TRUNCATE temporal_rng2, temporal_fk2_per2rng; +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[6,7)', '(,)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[6,7)', '[6,7)', '[2018-01-01,2021-01-01)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[100,100]', '2018-01-01', '2021-01-01', '[6,7)', '[6,7)'); +-- fails because you can't set the PERIOD column: +ALTER TABLE temporal_fk2_per2rng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_per2rng_fk, + ADD CONSTRAINT temporal_fk2_per2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET DEFAULT (valid_at) ON UPDATE SET DEFAULT; +-- ok: +ALTER TABLE temporal_fk2_per2rng + ALTER COLUMN parent_id1 SET DEFAULT '[-1,-1]', + DROP CONSTRAINT temporal_fk2_per2rng_fk, + ADD CONSTRAINT temporal_fk2_per2rng_fk + FOREIGN KEY (parent_id1, parent_id2, PERIOD valid_at) + REFERENCES temporal_rng2 + ON DELETE SET DEFAULT (parent_id1) ON UPDATE SET DEFAULT; +-- leftovers on both sides: +DELETE FROM temporal_rng2 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- non-FPO update: +DELETE FROM temporal_rng2 WHERE id1 = '[6,7)'; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[100,100]' ORDER BY id, valid_at; +-- FK across two referenced rows: +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2018-01-01,2020-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[8,9)', '[8,9)', '[2020-01-01,2021-01-01)'); +INSERT INTO temporal_rng2 (id1, id2, valid_at) VALUES ('[-1,-1]', '[8,9)', '(,)'); +INSERT INTO temporal_fk2_per2rng (id, valid_from, valid_til, parent_id1, parent_id2) VALUES ('[200,200]', '2018-01-01', '2021-01-01', '[8,9)', '[8,9)'); +DELETE FROM temporal_rng2 WHERE id1 = '[8,9)' AND valid_at @> '2019-01-01'::date; +SELECT * FROM temporal_fk2_per2rng WHERE id = '[200,200]' ORDER BY id, valid_at; + +-- FK with a custom range type + +CREATE TYPE mydaterange AS range(subtype=date); + +CREATE TABLE temporal_rng3 ( + id int4range, + valid_at mydaterange, + CONSTRAINT temporal_rng3_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +); +CREATE TABLE temporal_fk3_rng2rng ( + id int4range, + valid_at mydaterange, + parent_id int4range, + CONSTRAINT temporal_fk3_rng2rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS), + CONSTRAINT temporal_fk3_rng2rng_fk FOREIGN KEY (parent_id, PERIOD valid_at) + REFERENCES temporal_rng3 (id, PERIOD valid_at) ON DELETE CASCADE +); +INSERT INTO temporal_rng3 (id, valid_at) VALUES ('[8,9)', mydaterange('2018-01-01', '2021-01-01')); +INSERT INTO temporal_fk3_rng2rng (id, valid_at, parent_id) VALUES ('[5,6)', mydaterange('2018-01-01', '2021-01-01'), '[8,9)'); +DELETE FROM temporal_rng3 FOR PORTION OF valid_at FROM '2019-01-01' TO '2020-01-01' WHERE id = '[8,9)'; +SELECT * FROM temporal_fk3_rng2rng WHERE id = '[5,6)'; + +DROP TABLE temporal_fk3_rng2rng; +DROP TABLE temporal_rng3; +DROP TYPE mydaterange; + +-- +-- FK between partitioned tables: ranges +-- + +CREATE TABLE temporal_partitioned_rng ( + id int4range, + valid_at daterange, + name text, + CONSTRAINT temporal_paritioned_rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +) PARTITION BY LIST (id); +CREATE TABLE tp1 PARTITION OF temporal_partitioned_rng FOR VALUES IN ('[1,2)', '[3,4)', '[5,6)', '[7,8)', '[9,10)', '[11,12)', '[13,14)', '[15,16)', '[17,18)', '[19,20)', '[21,22)', '[23,24)'); +CREATE TABLE tp2 PARTITION OF temporal_partitioned_rng FOR VALUES IN ('[0,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)'); +INSERT INTO temporal_partitioned_rng (id, valid_at, name) VALUES + ('[1,2)', daterange('2000-01-01', '2000-02-01'), 'one'), + ('[1,2)', daterange('2000-02-01', '2000-03-01'), 'one'), ('[2,3)', daterange('2000-01-01', '2010-01-01'), 'two'); CREATE TABLE temporal_partitioned_fk_rng2rng ( @@ -3007,4 +5995,19 @@ SELECT * FROM temporal_partitioned_fk_mltrng2mltrng WHERE id = '[15,16)'; DROP TABLE temporal_partitioned_fk_mltrng2mltrng; DROP TABLE temporal_partitioned_mltrng; +-- +-- FK between partitioned tables: PERIODs +-- + +CREATE TABLE temporal_partitioned_per ( + id int4range, + valid_from date, + valid_til date, + name text, + PERIOD FOR valid_at (valid_from, valid_til), + CONSTRAINT temporal_paritioned_rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS) +) PARTITION BY LIST (id); +CREATE TABLE tp1 PARTITION OF temporal_partitioned_per FOR VALUES IN ('[1,2)', '[3,4)', '[5,6)', '[7,8)', '[9,10)', '[11,12)', '[13,14)', '[15,16)', '[17,18)', '[19,20)', '[21,22)', '[23,24)'); +DROP TABLE temporal_partitioned_per; + RESET datestyle; diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list index 8c4a5840f1c0..088d6824040a 100644 --- a/src/tools/pgindent/typedefs.list +++ b/src/tools/pgindent/typedefs.list @@ -888,6 +888,7 @@ FormData_pg_opclass FormData_pg_operator FormData_pg_opfamily FormData_pg_partitioned_table +FormData_pg_period FormData_pg_policy FormData_pg_proc FormData_pg_publication @@ -2164,6 +2165,8 @@ PendingUnlinkEntry PendingWrite PendingWriteback PerLockTagEntry +PeriodDef +PeriodInfo PerlInterpreter Perl_ppaddr_t Permutation