Skip to content

Commit

Permalink
Add temporal PRIMARY KEY and UNIQUE constraints
Browse files Browse the repository at this point in the history
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.

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
  • Loading branch information
petere committed Jan 24, 2024
1 parent 74a7306 commit 46a0cd4
Show file tree
Hide file tree
Showing 34 changed files with 1,135 additions and 52 deletions.
2 changes: 1 addition & 1 deletion contrib/btree_gist/Makefile
Expand Up @@ -40,7 +40,7 @@ PGFILEDESC = "btree_gist - B-tree equivalent GiST operator classes"
REGRESS = init int2 int4 int8 float4 float8 cash oid timestamp timestamptz \
time timetz date interval macaddr macaddr8 inet cidr text varchar char \
bytea bit varbit numeric uuid not_equal enum bool partitions \
stratnum
stratnum without_overlaps

SHLIB_LINK += $(filter -lm, $(LIBS))

Expand Down
44 changes: 44 additions & 0 deletions contrib/btree_gist/expected/without_overlaps.out
@@ -0,0 +1,44 @@
-- 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
Table "public.temporal_rng"
Column | Type | Collation | Nullable | Default
----------+-----------+-----------+----------+---------
id | integer | | not null |
valid_at | daterange | | not null |
Indexes:
"temporal_rng_pk" PRIMARY KEY (id, valid_at WITHOUT OVERLAPS)

SELECT pg_get_constraintdef(oid) FROM pg_constraint WHERE conname = 'temporal_rng_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_rng_pk';
pg_get_indexdef
-------------------------------------------------------------------------------
CREATE UNIQUE INDEX temporal_rng_pk ON temporal_rng USING gist (id, valid_at)
(1 row)

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)');
ERROR: conflicting key value violates exclusion constraint "temporal_rng_pk"
DETAIL: Key (id, valid_at)=(1, [06-01-2000,01-01-2001)) conflicts with existing key (id, valid_at)=(1, [01-01-2000,01-01-2001)).
1 change: 1 addition & 0 deletions contrib/btree_gist/meson.build
Expand Up @@ -91,6 +91,7 @@ tests += {
'bool',
'partitions',
'stratnum',
'without_overlaps',
],
},
}
25 changes: 25 additions & 0 deletions contrib/btree_gist/sql/without_overlaps.sql
@@ -0,0 +1,25 @@
-- 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)');
10 changes: 10 additions & 0 deletions doc/src/sgml/catalogs.sgml
Expand Up @@ -2709,6 +2709,16 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
</para></entry>
</row>

<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>conwithoutoverlaps</structfield> <type>bool</type>
</para>
<para>
This constraint is defined with <literal>WITHOUT OVERLAPS</literal>
(for primary keys and unique constraints).
</para></entry>
</row>

<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>conkey</structfield> <type>int2[]</type>
Expand Down
14 changes: 13 additions & 1 deletion doc/src/sgml/gist.sgml
Expand Up @@ -298,7 +298,8 @@ CREATE INDEX ON my_table USING GIST (my_inet_column inet_ops);
The optional twelfth method <function>stratnum</function> is used to
translate well-known <literal>RT*StrategyNumber</literal>s (from
<filename>src/include/access/stratnum.h</filename>) into strategy numbers
used by the operator class.
used by the operator class. This lets the core code look up operators for
temporal constraint indexes.
</para>

<variablelist>
Expand Down Expand Up @@ -1185,6 +1186,17 @@ my_sortsupport(PG_FUNCTION_ARGS)
operator class has no matching strategy.
</para>

<para>
This is used for temporal index constraints (i.e., <literal>PRIMARY
KEY</literal> and <literal>UNIQUE</literal>). If the operator class
provides this function and it returns results for
<literal>RTEqualStrategyNumber</literal>, it can be used in the
non-<literal>WITHOUT OVERLAPS</literal> part(s) of an index constraint.
If it returns results for <literal>RTOverlapStrategyNumber</literal>,
the operator class can be used in the <literal>WITHOUT
OVERLAPS</literal> part of an index constraint.
</para>

<para>
The <acronym>SQL</acronym> declaration of the function must look like
this:
Expand Down
45 changes: 36 additions & 9 deletions doc/src/sgml/ref/create_table.sgml
Expand Up @@ -78,8 +78,8 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXI
[ CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> ]
{ CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
NOT NULL <replaceable class="parameter">column_name</replaceable> [ NO INHERIT ] |
UNIQUE [ NULLS [ NOT ] DISTINCT ] ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) <replaceable class="parameter">index_parameters</replaceable> |
PRIMARY KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) <replaceable class="parameter">index_parameters</replaceable> |
UNIQUE [ NULLS [ NOT ] DISTINCT ] ( <replaceable class="parameter">column_name</replaceable> [, ... ] [, <replaceable class="parameter">column_name</replaceable> WITHOUT OVERLAPS ] ) <replaceable class="parameter">index_parameters</replaceable> |
PRIMARY KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] [, <replaceable class="parameter">column_name</replaceable> WITHOUT OVERLAPS ] ) <replaceable class="parameter">index_parameters</replaceable> |
EXCLUDE [ USING <replaceable class="parameter">index_method</replaceable> ] ( <replaceable class="parameter">exclude_element</replaceable> WITH <replaceable class="parameter">operator</replaceable> [, ... ] ) <replaceable class="parameter">index_parameters</replaceable> [ WHERE ( <replaceable class="parameter">predicate</replaceable> ) ] |
FOREIGN KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) REFERENCES <replaceable class="parameter">reftable</replaceable> [ ( <replaceable class="parameter">refcolumn</replaceable> [, ... ] ) ]
[ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ] [ ON DELETE <replaceable
Expand Down Expand Up @@ -965,7 +965,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM

<varlistentry id="sql-createtable-parms-unique">
<term><literal>UNIQUE [ NULLS [ NOT ] DISTINCT ]</literal> (column constraint)</term>
<term><literal>UNIQUE [ NULLS [ NOT ] DISTINCT ] ( <replaceable class="parameter">column_name</replaceable> [, ... ] )</literal>
<term><literal>UNIQUE [ NULLS [ NOT ] DISTINCT ] ( <replaceable class="parameter">column_name</replaceable> [, ... ] [, <replaceable class="parameter">column_name</replaceable> WITHOUT OVERLAPS ] )</literal>
<optional> <literal>INCLUDE ( <replaceable class="parameter">column_name</replaceable> [, ...])</literal> </optional> (table constraint)</term>

<listitem>
Expand All @@ -979,6 +979,30 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
of these columns.
</para>

<para>
If the <literal>WITHOUT OVERLAPS</literal> option is specified for the
last column, then that column is checked for overlaps instead of
equality. In that case, the other columns of the constraint will allow
duplicates so long as the duplicates don't overlap in the
<literal>WITHOUT OVERLAPS</literal> column. (This is sometimes called a
temporal key, if the column is a range of dates or timestamps, but
PostgreSQL allows ranges over any base type.) In effect, such a
constraint is enforced with an <literal>EXCLUDE</literal> constraint
rather than a <literal>UNIQUE</literal> constraint. So for example
<literal>UNIQUE (id, valid_at WITHOUT OVERLAPS)</literal> behaves like
<literal>EXCLUDE USING GIST (id WITH =, valid_at WITH
&amp;&amp;)</literal>. The <literal>WITHOUT OVERLAPS</literal> column
must have a range or multirange type. (Technically, any type is allowed
whose default GiST opclass includes an overlaps operator. See the
<literal>stratnum</literal> support function under <xref
linkend="gist-extensibility"/> for details.) The non-<literal>WITHOUT
OVERLAPS</literal> columns of the constraint can be any type that can be
compared for equality in a GiST index. By default, only range types are
supported, but you can use other types by adding the <xref
linkend="btree-gist"/> extension (which is the expected way to use this
feature).
</para>

<para>
For the purpose of a unique constraint, null values are not
considered equal, unless <literal>NULLS NOT DISTINCT</literal> is
Expand All @@ -1000,8 +1024,10 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</para>

<para>
Adding a unique constraint will automatically create a unique btree
index on the column or group of columns used in the constraint.
Adding a unique constraint will automatically create a unique B-tree
index on the column or group of columns used in the constraint. But if
the constraint includes a <literal>WITHOUT OVERLAPS</literal> clause, it
will use a GiST index.
</para>

<para>
Expand All @@ -1019,7 +1045,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM

<varlistentry id="sql-createtable-parms-primary-key">
<term><literal>PRIMARY KEY</literal> (column constraint)</term>
<term><literal>PRIMARY KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] )</literal>
<term><literal>PRIMARY KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] [, <replaceable class="parameter">column_name</replaceable> WITHOUT OVERLAPS ] )</literal>
<optional> <literal>INCLUDE ( <replaceable class="parameter">column_name</replaceable> [, ...])</literal> </optional> (table constraint)</term>
<listitem>
<para>
Expand Down Expand Up @@ -1052,9 +1078,10 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</para>

<para>
Adding a <literal>PRIMARY KEY</literal> constraint will automatically
create a unique btree index on the column or group of columns used in the
constraint.
As with a <literal>UNIQUE</literal> constraint, adding a
<literal>PRIMARY KEY</literal> constraint will automatically create a
unique B-tree index, or GiST if <literal>WITHOUT OVERLAPS</literal> was
specified, on the column or group of columns used in the constraint.
</para>

<para>
Expand Down
29 changes: 29 additions & 0 deletions src/backend/access/gist/gistutil.c
Expand Up @@ -1070,3 +1070,32 @@ gist_stratnum_identity(PG_FUNCTION_ARGS)

PG_RETURN_UINT16(strat);
}

/*
* Returns the opclass's private stratnum used for the given strategy.
*
* Calls the opclass's GIST_STRATNUM_PROC support function, if any,
* and returns the result.
* Returns InvalidStrategy if the function is not defined.
*/
StrategyNumber
GistTranslateStratnum(Oid opclass, StrategyNumber strat)
{
Oid opfamily;
Oid opcintype;
Oid funcid;
Datum result;

/* Look up the opclass family and input datatype. */
if (!get_opclass_opfamily_and_input_type(opclass, &opfamily, &opcintype))
return InvalidStrategy;

/* Check whether the function is provided. */
funcid = get_opfamily_proc(opfamily, opcintype, opcintype, GIST_STRATNUM_PROC);
if (!OidIsValid(funcid))
return InvalidStrategy;

/* Ask the translation function */
result = OidFunctionCall1Coll(funcid, InvalidOid, UInt16GetDatum(strat));
return DatumGetUInt16(result);
}
2 changes: 2 additions & 0 deletions src/backend/catalog/heap.c
Expand Up @@ -2141,6 +2141,7 @@ StoreRelCheck(Relation rel, const char *ccname, Node *expr,
is_local, /* conislocal */
inhcount, /* coninhcount */
is_no_inherit, /* connoinherit */
false, /* conwithoutoverlaps */
is_internal); /* internally constructed? */

pfree(ccbin);
Expand Down Expand Up @@ -2191,6 +2192,7 @@ StoreRelNotNull(Relation rel, const char *nnname, AttrNumber attnum,
is_local,
inhcount,
is_no_inherit,
false, /* conwithoutoverlaps */
false);
return constrOid;
}
Expand Down
4 changes: 4 additions & 0 deletions src/backend/catalog/index.c
Expand Up @@ -1904,6 +1904,7 @@ index_concurrently_set_dead(Oid heapId, Oid indexId)
* INDEX_CONSTR_CREATE_UPDATE_INDEX: update the pg_index row
* INDEX_CONSTR_CREATE_REMOVE_OLD_DEPS: remove existing dependencies
* of index on table's columns
* INDEX_CONSTR_CREATE_WITHOUT_OVERLAPS: constraint uses WITHOUT OVERLAPS
* allow_system_table_mods: allow table to be a system catalog
* is_internal: index is constructed due to internal process
*/
Expand All @@ -1927,11 +1928,13 @@ index_constraint_create(Relation heapRelation,
bool mark_as_primary;
bool islocal;
bool noinherit;
bool is_without_overlaps;
int inhcount;

deferrable = (constr_flags & INDEX_CONSTR_CREATE_DEFERRABLE) != 0;
initdeferred = (constr_flags & INDEX_CONSTR_CREATE_INIT_DEFERRED) != 0;
mark_as_primary = (constr_flags & INDEX_CONSTR_CREATE_MARK_AS_PRIMARY) != 0;
is_without_overlaps = (constr_flags & INDEX_CONSTR_CREATE_WITHOUT_OVERLAPS) != 0;

/* constraint creation support doesn't work while bootstrapping */
Assert(!IsBootstrapProcessingMode());
Expand Down Expand Up @@ -2008,6 +2011,7 @@ index_constraint_create(Relation heapRelation,
islocal,
inhcount,
noinherit,
is_without_overlaps,
is_internal);

/*
Expand Down
2 changes: 2 additions & 0 deletions src/backend/catalog/pg_constraint.c
Expand Up @@ -78,6 +78,7 @@ CreateConstraintEntry(const char *constraintName,
bool conIsLocal,
int conInhCount,
bool conNoInherit,
bool conWithoutOverlaps,
bool is_internal)
{
Relation conDesc;
Expand Down Expand Up @@ -193,6 +194,7 @@ CreateConstraintEntry(const char *constraintName,
values[Anum_pg_constraint_conislocal - 1] = BoolGetDatum(conIsLocal);
values[Anum_pg_constraint_coninhcount - 1] = Int16GetDatum(conInhCount);
values[Anum_pg_constraint_connoinherit - 1] = BoolGetDatum(conNoInherit);
values[Anum_pg_constraint_conwithoutoverlaps - 1] = BoolGetDatum(conWithoutOverlaps);

if (conkeyArray)
values[Anum_pg_constraint_conkey - 1] = PointerGetDatum(conkeyArray);
Expand Down

0 comments on commit 46a0cd4

Please sign in to comment.