mirror of
https://github.com/postgres/postgres.git
synced 2025-04-20 00:42:27 +03:00
Add WITHOUT OVERLAPS clause to PRIMARY KEY and UNIQUE constraints. These are backed by GiST indexes instead of B-tree indexes, since they are essentially exclusion constraints with = for the scalar parts of the key and && for the temporal part. (previously committed as 46a0cd4cefb, reverted by 46a0cd4cefb; the new part is this:) Because 'empty' && 'empty' is false, the temporal PK/UQ constraint allowed duplicates, which is confusing to users and breaks internal expectations. For instance, when GROUP BY checks functional dependencies on the PK, it allows selecting other columns from the table, but in the presence of duplicate keys you could get the value from any of their rows. So we need to forbid empties. This all means that at the moment we can only support ranges and multiranges for temporal PK/UQs, unlike the original patch (above). Documentation and tests for this are added. But this could conceivably be extended by introducing some more general support for the notion of "empty" for other types. Author: Paul A. Jungwirth <pj@illuminatedcomputing.com> Reviewed-by: Peter Eisentraut <peter@eisentraut.org> Reviewed-by: jian he <jian.universality@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/CA+renyUApHgSZF9-nd-a0+OPGharLQLO=mDHcY4_qQ0+noCUVg@mail.gmail.com
26 lines
868 B
SQL
26 lines
868 B
SQL
-- Core must test WITHOUT OVERLAPS
|
|
-- with an int4range + daterange,
|
|
-- so here we do some simple tests
|
|
-- to make sure int + daterange works too,
|
|
-- since that is the expected use-case.
|
|
CREATE TABLE temporal_rng (
|
|
id integer,
|
|
valid_at daterange,
|
|
CONSTRAINT temporal_rng_pk PRIMARY KEY (id, valid_at WITHOUT OVERLAPS)
|
|
);
|
|
\d temporal_rng
|
|
SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_rng_pk';
|
|
SELECT pg_get_indexdef(conindid, 0, true) FROM pg_constraint WHERE conname = 'temporal_rng_pk';
|
|
|
|
INSERT INTO temporal_rng VALUES
|
|
(1, '[2000-01-01,2001-01-01)');
|
|
-- same key, doesn't overlap:
|
|
INSERT INTO temporal_rng VALUES
|
|
(1, '[2001-01-01,2002-01-01)');
|
|
-- overlaps but different key:
|
|
INSERT INTO temporal_rng VALUES
|
|
(2, '[2000-01-01,2001-01-01)');
|
|
-- should fail:
|
|
INSERT INTO temporal_rng VALUES
|
|
(1, '[2000-06-01,2001-01-01)');
|