1
0
mirror of https://github.com/postgres/postgres.git synced 2025-11-09 06:21:09 +03:00

doc: Add section for temporal tables

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, unique constraints, and
temporal foreign keys.  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 <pj@illuminatedcomputing.com>
Discussion: https://www.postgresql.org/message-id/flat/ec498c3d-5f2b-48ec-b989-5561c8aa2024@illuminatedcomputing.com
This commit is contained in:
Peter Eisentraut
2025-11-05 16:38:04 +01:00
parent 447aae13b0
commit e4d8a2af07
7 changed files with 446 additions and 1 deletions

View File

@@ -1585,6 +1585,298 @@ CREATE TABLE circles (
</para> </para>
</sect1> </sect1>
<sect1 id="ddl-temporal-tables">
<title>Temporal Tables</title>
<indexterm zone="ddl-temporal-tables">
<primary>temporal</primary>
</indexterm>
<para>
<firstterm>Temporal tables</firstterm> allow users to track different
dimensions of history. <firstterm>Application time</firstterm> tracks the
history of a thing out in the world, and <firstterm>system time</firstterm>
tracks the history of the database itself. (A database that does both is
also called <firstterm>bitemporal</firstterm>.) This section describes how
to express and manage such histories in temporal tables.
</para>
<sect2 id="ddl-application-time">
<title>Application Time</title>
<indexterm zone="ddl-application-time">
<primary>application time</primary>
</indexterm>
<para>
<firstterm>Application time</firstterm> 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 applicable.
</para>
<para>
The following SQL creates a temporal table that can store application time:
<programlisting>
CREATE TABLE products (
product_no integer,
price numeric,
<emphasis>valid_at daterange</emphasis>
);
</programlisting>
</para>
<para>
Records in a temporal table can be imagined on a timeline, as in <xref
linkend="temporal-entities-figure"/>. Here we show three records
describing two products. Each record is a tuple with three attributes:
the product number, the price, and the application time. So product 5 was
first offered for a price of 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.
</para>
<figure id="temporal-entities-figure">
<title>Application Time Example</title>
<mediaobject>
<imageobject>
<imagedata fileref="images/temporal-entities.svg" format="SVG" width="100%"/>
</imageobject>
</mediaobject>
</figure>
<para>
In a table, these records would be:
<programlisting>
product_no | price | valid_at
------------+-------+-------------------------
5 | 5.00 | [2020-01-01,2022-01-01)
5 | 8.00 | [2022-01-01,)
6 | 9.00 | [2021-01-01,2024-01-01)
</programlisting>
</para>
<para>
We show the application time using range-type notation, because it is
stored as a single column (either a range or multirange). Ranges include
their start point but exclude their end point. That way two adjacent
ranges cover all points without overlapping. See <xref
linkend="rangetypes"/> for more information about range types.
</para>
<para>
In principle, a table with application-time ranges/multiranges is
equivalent to a table that stores application-time
<quote>instants</quote>: 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
<quote>versions</quote> persist for extended periods of time.
</para>
<sect3 id="ddl-application-time-primary-keys">
<title>Temporal Primary Keys and Unique Constraints</title>
<para>
A table with application time has a different concept of entity
uniqueness than a non-temporal table. Temporal entity uniqueness can be
enforced with a temporal primary key. A regular primary key has at least
one column, all columns are <literal>NOT NULL</literal>, and the combined
value of all columns is unique. A temporal primary key also has at least
one such column, but in addition it has a final column that is of a range
type or multirange type that shows when the row is applicable. The
regular parts of the key must be unique for any moment in time, but
non-unique rows are allowed if their application time does not overlap.
</para>
<para>
The syntax to create a temporal primary key is as follows:
<programlisting>
CREATE TABLE products (
product_no integer,
price numeric,
valid_at daterange,
<emphasis>PRIMARY KEY (product_no, valid_at WITHOUT OVERLAPS)</emphasis>
);
</programlisting>
In this example, <literal>product_no</literal> is the non-temporal part
of the key, and <literal>valid_at</literal> is a range column containing
the application time.
</para>
<para>
The <literal>WITHOUT OVERLAPS</literal> column is implicitly <literal>NOT
NULL</literal> (like the other parts of the key). In addition it may not
contain empty values, that is, a range of <literal>'empty'</literal> or a
multirange of <literal>{}</literal>. An empty application time would
have no meaning.
</para>
<para>
It is also possible to create a temporal unique constraint that is
not a primary key. The syntax is similar:
<programlisting>
CREATE TABLE products (
product_no integer,
price numeric,
valid_at daterange,
<emphasis>UNIQUE (product_no, valid_at WITHOUT OVERLAPS)</emphasis>
);
</programlisting>
Temporal unique constraints also forbid empty ranges/multiranges for
their application time, but that column is permitted to be null (like the
other columns of the unique constraint).
</para>
<para>
Temporal primary keys and unique constraints are backed by GiST indexes
(see <xref linkend="gist"/>) rather than B-Tree indexes. In practice,
creating a temporal primary key or constraint requires installing the
<xref linkend="btree-gist"/> extension, so that the database has GiST
operator classes for the non-temporal parts of the key.
</para>
<para>
Temporal primary keys and unique constraints have the same behavior as
exclusion constraints (see <xref linkend="ddl-constraints-exclusion"/>),
where each regular key part is compared with equality, and the
application time is compared with overlaps, for example <literal>EXCLUDE
USING gist (id WITH =, valid_at WITH &amp;&amp;)</literal>. The only
difference is that they also forbid an empty application time.
</para>
</sect3>
<sect3 id="ddl-application-time-foreign-keys">
<title>Temporal Foreign Keys</title>
<para>
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 <literal>products</literal> table is referenced by
a <literal>variants</literal> table, and a variant of product 5 has an
application-time of <literal>[2020-01-01,2026-01-01)</literal>, then
product 5 must exist throughout that period.
</para>
<para>
We can create the <literal>variants</literal> table with the following
schema (without a foreign key yet):
<programlisting>
CREATE TABLE variants (
id integer,
product_no integer,
name text,
valid_at daterange,
PRIMARY KEY (id, valid_at WITHOUT OVERLAPS)
);
</programlisting>
We have included a temporal primary key as a best practice, but it is not
strictly required by foreign keys.
</para>
<para>
<xref linkend="temporal-references-figure"/> 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.
</para>
<figure id="temporal-references-figure">
<title>Temporal Foreign Key Example</title>
<mediaobject>
<imageobject>
<imagedata fileref="images/temporal-references.svg" format="SVG" width="100%"/>
</imageobject>
</mediaobject>
</figure>
<para>
In a table, these records would be:
<programlisting>
id | product_no | name | valid_at
----+------------+--------+-------------------------
8 | 5 | Medium | [2021-01-01,2023-06-01)
9 | 5 | XXL | [2022-03-01,2024-06-01)
</programlisting>
</para>
<para>
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.
</para>
<para>
The syntax to add a temporal foreign key to our table is:
<programlisting>
CREATE TABLE variants (
id integer,
product_no integer,
name text,
valid_at daterange,
PRIMARY KEY (id, valid_at WITHOUT OVERLAPS),
<emphasis>FOREIGN KEY (product_no, PERIOD valid_at) REFERENCES products (product_no, PERIOD valid_at)</emphasis>
);
</programlisting>
Note that the keyword <literal>PERIOD</literal> must be used for the
application-time column in both the referencing and referenced table.
</para>
<para>
A temporal primary key or unique constraint matching the referenced columns
must exist on the referenced table.
</para>
<para>
<productname>PostgreSQL</productname> supports temporal foreign keys with
action <literal>NO ACTION</literal>, but not <literal>RESTRICT</literal>,
<literal>CASCADE</literal>, <literal>SET NULL</literal>, or <literal>SET
DEFAULT</literal>.
</para>
</sect3>
</sect2>
<sect2 id="ddl-system-time">
<title>System Time</title>
<indexterm zone="ddl-system-time">
<primary>system time</primary>
</indexterm>
<para>
<firstterm>System time</firstterm> refers to the history of the database
table, not the entity it describes. It captures when each row was
inserted/updated/deleted.
</para>
<para>
<productname>PostgreSQL</productname> does not currently support system
time, but it could be emulated using triggers, and there are external
extensions that provide such functionality.
</para>
</sect2>
</sect1>
<sect1 id="ddl-alter"> <sect1 id="ddl-alter">
<title>Modifying Tables</title> <title>Modifying Tables</title>

View File

@@ -81,6 +81,21 @@
</glossdef> </glossdef>
</glossentry> </glossentry>
<glossentry id="glossary-application-time">
<glossterm>Application time</glossterm>
<glossdef>
<para>
In a <glossterm linkend="glossary-temporal-table">temporal table</glossterm>,
the dimension of time that represents when the entity described by the table
changed (as opposed to the table itself).
</para>
<para>
For more information, see
<xref linkend="ddl-temporal-tables"/>.
</para>
</glossdef>
</glossentry>
<glossentry id="glossary-aio"> <glossentry id="glossary-aio">
<glossterm>Asynchronous <acronym>I/O</acronym></glossterm> <glossterm>Asynchronous <acronym>I/O</acronym></glossterm>
<acronym>AIO</acronym> <acronym>AIO</acronym>
@@ -1847,6 +1862,22 @@
</glossdef> </glossdef>
</glossentry> </glossentry>
<glossentry id="glossary-system-time">
<glossterm>System time</glossterm>
<glossdef>
<para>
In a <glossterm linkend="glossary-temporal-table">temporal table</glossterm>,
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.
</para>
<para>
For more information, see
<xref linkend="ddl-temporal-tables"/>.
</para>
</glossdef>
</glossentry>
<glossentry id="glossary-table"> <glossentry id="glossary-table">
<glossterm>Table</glossterm> <glossterm>Table</glossterm>
<glossdef> <glossdef>
@@ -1885,6 +1916,22 @@
</glossdef> </glossdef>
</glossentry> </glossentry>
<glossentry id="glossary-temporal-table">
<glossterm>Temporal table</glossterm>
<glossdef>
<para>
<glossterm linkend="glossary-table">Tables</glossterm>
that track <glossterm linkend="glossary-application-time">application time</glossterm>
or <glossterm linkend="glossary-system-time">system time</glossterm> (or both).
Not to be confused with <glossterm linkend="glossary-temporary-table">temporary tables</glossterm>.
</para>
<para>
For more information, see
<xref linkend="ddl-temporal-tables"/>.
</para>
</glossdef>
</glossentry>
<glossentry id="glossary-temporary-table"> <glossentry id="glossary-temporary-table">
<glossterm>Temporary table</glossterm> <glossterm>Temporary table</glossterm>
<glossdef> <glossdef>

View File

@@ -5,7 +5,9 @@
ALL_IMAGES = \ ALL_IMAGES = \
genetic-algorithm.svg \ genetic-algorithm.svg \
gin.svg \ gin.svg \
pagelayout.svg pagelayout.svg \
temporal-entities.svg \
temporal-references.svg
DITAA = ditaa DITAA = ditaa
DOT = dot DOT = dot

View File

@@ -0,0 +1,34 @@
<?xml version="1.0"?>
<svg xmlns="http://www.w3.org/2000/svg" viewBox="0 0 1020 252" width="1020" height="252" shape-rendering="geometricPrecision" version="1.0">
<defs>
<filter id="f2" x="0" y="0" width="200%" height="200%">
<feOffset result="offOut" in="SourceGraphic" dx="5" dy="5"/>
<feGaussianBlur result="blurOut" in="offOut" stdDeviation="3"/>
<feBlend in="SourceGraphic" in2="blurOut" mode="normal"/>
</filter>
</defs>
<g stroke-width="1" stroke-linecap="square" stroke-linejoin="round">
<rect x="0" y="0" width="1020" height="252" style="fill: #ffffff"/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="#99dd99" d="M215.0 105.0 L215.0 175.0 L785.0 175.0 L785.0 105.0 z"/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="#99dd99" d="M965.0 35.0 L965.0 105.0 L405.0 105.0 L405.0 35.0 z"/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="#99dd99" d="M25.0 35.0 L25.0 105.0 L405.0 105.0 L405.0 35.0 z"/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="none" d="M25.0 196.0 L25.0 209.0 "/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="none" d="M405.0 196.0 L405.0 209.0 "/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="none" d="M215.0 196.0 L215.0 209.0 "/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="none" d="M595.0 196.0 L595.0 209.0 "/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="none" d="M785.0 196.0 L785.0 209.0 "/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="none" d="M975.0 196.0 L975.0 209.0 "/>
<text x="40" y="68" font-family="Courier" font-size="15" stroke="none" fill="#000000">products</text>
<text x="40" y="82" font-family="Courier" font-size="15" stroke="none" fill="#000000">(5, 5.00, [1 Jan 2020,1 Jan 2022))</text>
<text x="20" y="222" font-family="Courier" font-size="15" stroke="none" fill="#000000">2020</text>
<text x="230" y="138" font-family="Courier" font-size="15" stroke="none" fill="#000000">products</text>
<text x="230" y="152" font-family="Courier" font-size="15" stroke="none" fill="#000000">(6, 9.00, [1 Jan 2021,1 Jan 2024))</text>
<text x="210" y="222" font-family="Courier" font-size="15" stroke="none" fill="#000000">2021</text>
<text x="400" y="222" font-family="Courier" font-size="15" stroke="none" fill="#000000">2022</text>
<text x="420" y="68" font-family="Courier" font-size="15" stroke="none" fill="#000000">products</text>
<text x="420" y="82" font-family="Courier" font-size="15" stroke="none" fill="#000000">(5, 8.00, [1 Jan 2022,))</text>
<text x="590" y="222" font-family="Courier" font-size="15" stroke="none" fill="#000000">2023</text>
<text x="780" y="222" font-family="Courier" font-size="15" stroke="none" fill="#000000">2024</text>
<text x="979" y="222" font-family="Courier" font-size="15" stroke="none" fill="#000000">...</text>
</g>
</svg>

After

Width:  |  Height:  |  Size: 3.2 KiB

View File

@@ -0,0 +1,14 @@
+-------------------------------------+-------------------------------------------------------+
| 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 ...

View File

@@ -0,0 +1,37 @@
<?xml version="1.0"?>
<svg xmlns="http://www.w3.org/2000/svg" viewBox="0 0 1020 322" width="1020" height="322" shape-rendering="geometricPrecision" version="1.0">
<defs>
<filter id="f2" x="0" y="0" width="200%" height="200%">
<feOffset result="offOut" in="SourceGraphic" dx="5" dy="5"/>
<feGaussianBlur result="blurOut" in="offOut" stdDeviation="3"/>
<feBlend in="SourceGraphic" in2="blurOut" mode="normal"/>
</filter>
</defs>
<g stroke-width="1" stroke-linecap="square" stroke-linejoin="round">
<rect x="0" y="0" width="1020" height="322" style="fill: #ffffff"/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="#99dd99" d="M395.0 105.0 L395.0 35.0 L945.0 35.0 L945.0 105.0 z"/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="#ffff33" d="M215.0 105.0 L215.0 175.0 L685.0 175.0 L685.0 105.0 z"/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="#ffff33" d="M455.0 175.0 L875.0 175.0 L875.0 245.0 L455.0 245.0 z"/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="#99dd99" d="M25.0 35.0 L25.0 105.0 L395.0 105.0 L395.0 35.0 z"/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="none" d="M25.0 266.0 L25.0 279.0 "/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="none" d="M405.0 266.0 L405.0 279.0 "/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="none" d="M215.0 266.0 L215.0 279.0 "/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="none" d="M595.0 266.0 L595.0 279.0 "/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="none" d="M785.0 266.0 L785.0 279.0 "/>
<path stroke="#000000" stroke-width="1.000000" stroke-linecap="round" stroke-linejoin="round" fill="none" d="M975.0 266.0 L975.0 279.0 "/>
<text x="40" y="68" font-family="Courier" font-size="15" stroke="none" fill="#000000">products</text>
<text x="40" y="82" font-family="Courier" font-size="15" stroke="none" fill="#000000">(5, 5.00, [1 Jan 2020,1 Jan 2022))</text>
<text x="210" y="292" font-family="Courier" font-size="15" stroke="none" fill="#000000">2021</text>
<text x="230" y="138" font-family="Courier" font-size="15" stroke="none" fill="#000000">variants</text>
<text x="230" y="152" font-family="Courier" font-size="15" stroke="none" fill="#000000">(8, 5, 'Medium', [1 Jan 2021,1 Jun 2023))</text>
<text x="20" y="292" font-family="Courier" font-size="15" stroke="none" fill="#000000">2020</text>
<text x="470" y="208" font-family="Courier" font-size="15" stroke="none" fill="#000000">variants</text>
<text x="470" y="222" font-family="Courier" font-size="15" stroke="none" fill="#000000">(9, 5, 'XXL', [1 Mar 2022,1 Jun 2024))</text>
<text x="410" y="68" font-family="Courier" font-size="15" stroke="none" fill="#000000">products</text>
<text x="410" y="82" font-family="Courier" font-size="15" stroke="none" fill="#000000">(5, 8.00, [1 Jan 2022,))</text>
<text x="590" y="292" font-family="Courier" font-size="15" stroke="none" fill="#000000">2023</text>
<text x="400" y="292" font-family="Courier" font-size="15" stroke="none" fill="#000000">2022</text>
<text x="780" y="292" font-family="Courier" font-size="15" stroke="none" fill="#000000">2024</text>
<text x="979" y="292" font-family="Courier" font-size="15" stroke="none" fill="#000000">...</text>
</g>
</svg>

After

Width:  |  Height:  |  Size: 3.7 KiB

View File

@@ -0,0 +1,19 @@
+------------------------------------+------------------------------------------------------+
| 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 ...