Skip to content

Commit e4d8a2a

Browse files
committed
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
1 parent 447aae1 commit e4d8a2a

File tree

7 files changed

+446
-1
lines changed

7 files changed

+446
-1
lines changed

doc/src/sgml/ddl.sgml

Lines changed: 292 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1585,6 +1585,298 @@ CREATE TABLE circles (
15851585
</para>
15861586
</sect1>
15871587

1588+
<sect1 id="ddl-temporal-tables">
1589+
<title>Temporal Tables</title>
1590+
1591+
<indexterm zone="ddl-temporal-tables">
1592+
<primary>temporal</primary>
1593+
</indexterm>
1594+
1595+
<para>
1596+
<firstterm>Temporal tables</firstterm> allow users to track different
1597+
dimensions of history. <firstterm>Application time</firstterm> tracks the
1598+
history of a thing out in the world, and <firstterm>system time</firstterm>
1599+
tracks the history of the database itself. (A database that does both is
1600+
also called <firstterm>bitemporal</firstterm>.) This section describes how
1601+
to express and manage such histories in temporal tables.
1602+
</para>
1603+
1604+
<sect2 id="ddl-application-time">
1605+
<title>Application Time</title>
1606+
1607+
<indexterm zone="ddl-application-time">
1608+
<primary>application time</primary>
1609+
</indexterm>
1610+
1611+
<para>
1612+
<firstterm>Application time</firstterm> refers to a history of the entity
1613+
described by a table. In a typical non-temporal table, there is single
1614+
row for each entity. In a temporal table, an entity may have multiple
1615+
rows, as long as those rows describe non-overlapping periods from its
1616+
history. Application time requires each row to have a start and end time,
1617+
expressing when the row is applicable.
1618+
</para>
1619+
1620+
<para>
1621+
The following SQL creates a temporal table that can store application time:
1622+
<programlisting>
1623+
CREATE TABLE products (
1624+
product_no integer,
1625+
price numeric,
1626+
<emphasis>valid_at daterange</emphasis>
1627+
);
1628+
</programlisting>
1629+
</para>
1630+
1631+
<para>
1632+
Records in a temporal table can be imagined on a timeline, as in <xref
1633+
linkend="temporal-entities-figure"/>. Here we show three records
1634+
describing two products. Each record is a tuple with three attributes:
1635+
the product number, the price, and the application time. So product 5 was
1636+
first offered for a price of 5.00 starting January 1, 2020, but then
1637+
became 8.00 starting January 1, 2022. Its second record has no specified
1638+
end time, indicating that it is true indefinitely, or for all future time.
1639+
The last record shows that product 6 was introduced January 1, 2021 for
1640+
9.00, then canceled January 1, 2024.
1641+
</para>
1642+
1643+
<figure id="temporal-entities-figure">
1644+
<title>Application Time Example</title>
1645+
<mediaobject>
1646+
<imageobject>
1647+
<imagedata fileref="images/temporal-entities.svg" format="SVG" width="100%"/>
1648+
</imageobject>
1649+
</mediaobject>
1650+
</figure>
1651+
1652+
<para>
1653+
In a table, these records would be:
1654+
<programlisting>
1655+
product_no | price | valid_at
1656+
------------+-------+-------------------------
1657+
5 | 5.00 | [2020-01-01,2022-01-01)
1658+
5 | 8.00 | [2022-01-01,)
1659+
6 | 9.00 | [2021-01-01,2024-01-01)
1660+
</programlisting>
1661+
</para>
1662+
1663+
<para>
1664+
We show the application time using range-type notation, because it is
1665+
stored as a single column (either a range or multirange). Ranges include
1666+
their start point but exclude their end point. That way two adjacent
1667+
ranges cover all points without overlapping. See <xref
1668+
linkend="rangetypes"/> for more information about range types.
1669+
</para>
1670+
1671+
<para>
1672+
In principle, a table with application-time ranges/multiranges is
1673+
equivalent to a table that stores application-time
1674+
<quote>instants</quote>: one for each second, millisecond, nanosecond, or
1675+
whatever finest granularity is available. But such a table would contain
1676+
far too many rows, so ranges/multiranges offer an optimization to
1677+
represent the same information in a compact form. In addition, ranges and
1678+
multiranges offer a more convenient interface for typical temporal
1679+
operations, where records change infrequently enough that separate
1680+
<quote>versions</quote> persist for extended periods of time.
1681+
</para>
1682+
1683+
<sect3 id="ddl-application-time-primary-keys">
1684+
<title>Temporal Primary Keys and Unique Constraints</title>
1685+
1686+
<para>
1687+
A table with application time has a different concept of entity
1688+
uniqueness than a non-temporal table. Temporal entity uniqueness can be
1689+
enforced with a temporal primary key. A regular primary key has at least
1690+
one column, all columns are <literal>NOT NULL</literal>, and the combined
1691+
value of all columns is unique. A temporal primary key also has at least
1692+
one such column, but in addition it has a final column that is of a range
1693+
type or multirange type that shows when the row is applicable. The
1694+
regular parts of the key must be unique for any moment in time, but
1695+
non-unique rows are allowed if their application time does not overlap.
1696+
</para>
1697+
1698+
<para>
1699+
The syntax to create a temporal primary key is as follows:
1700+
1701+
<programlisting>
1702+
CREATE TABLE products (
1703+
product_no integer,
1704+
price numeric,
1705+
valid_at daterange,
1706+
<emphasis>PRIMARY KEY (product_no, valid_at WITHOUT OVERLAPS)</emphasis>
1707+
);
1708+
</programlisting>
1709+
1710+
In this example, <literal>product_no</literal> is the non-temporal part
1711+
of the key, and <literal>valid_at</literal> is a range column containing
1712+
the application time.
1713+
</para>
1714+
1715+
<para>
1716+
The <literal>WITHOUT OVERLAPS</literal> column is implicitly <literal>NOT
1717+
NULL</literal> (like the other parts of the key). In addition it may not
1718+
contain empty values, that is, a range of <literal>'empty'</literal> or a
1719+
multirange of <literal>{}</literal>. An empty application time would
1720+
have no meaning.
1721+
</para>
1722+
1723+
<para>
1724+
It is also possible to create a temporal unique constraint that is
1725+
not a primary key. The syntax is similar:
1726+
1727+
<programlisting>
1728+
CREATE TABLE products (
1729+
product_no integer,
1730+
price numeric,
1731+
valid_at daterange,
1732+
<emphasis>UNIQUE (product_no, valid_at WITHOUT OVERLAPS)</emphasis>
1733+
);
1734+
</programlisting>
1735+
1736+
Temporal unique constraints also forbid empty ranges/multiranges for
1737+
their application time, but that column is permitted to be null (like the
1738+
other columns of the unique constraint).
1739+
</para>
1740+
1741+
<para>
1742+
Temporal primary keys and unique constraints are backed by GiST indexes
1743+
(see <xref linkend="gist"/>) rather than B-Tree indexes. In practice,
1744+
creating a temporal primary key or constraint requires installing the
1745+
<xref linkend="btree-gist"/> extension, so that the database has GiST
1746+
operator classes for the non-temporal parts of the key.
1747+
</para>
1748+
1749+
<para>
1750+
Temporal primary keys and unique constraints have the same behavior as
1751+
exclusion constraints (see <xref linkend="ddl-constraints-exclusion"/>),
1752+
where each regular key part is compared with equality, and the
1753+
application time is compared with overlaps, for example <literal>EXCLUDE
1754+
USING gist (id WITH =, valid_at WITH &amp;&amp;)</literal>. The only
1755+
difference is that they also forbid an empty application time.
1756+
</para>
1757+
</sect3>
1758+
1759+
<sect3 id="ddl-application-time-foreign-keys">
1760+
<title>Temporal Foreign Keys</title>
1761+
1762+
<para>
1763+
A temporal foreign key is a reference from one application-time table to
1764+
another application-time table. Just as a non-temporal reference
1765+
requires a referenced key to exist, so a temporal reference requires a
1766+
referenced key to exist, but during whatever history the reference exists
1767+
(at least). So if the <literal>products</literal> table is referenced by
1768+
a <literal>variants</literal> table, and a variant of product 5 has an
1769+
application-time of <literal>[2020-01-01,2026-01-01)</literal>, then
1770+
product 5 must exist throughout that period.
1771+
</para>
1772+
1773+
<para>
1774+
We can create the <literal>variants</literal> table with the following
1775+
schema (without a foreign key yet):
1776+
1777+
<programlisting>
1778+
CREATE TABLE variants (
1779+
id integer,
1780+
product_no integer,
1781+
name text,
1782+
valid_at daterange,
1783+
PRIMARY KEY (id, valid_at WITHOUT OVERLAPS)
1784+
);
1785+
</programlisting>
1786+
1787+
We have included a temporal primary key as a best practice, but it is not
1788+
strictly required by foreign keys.
1789+
</para>
1790+
1791+
<para>
1792+
<xref linkend="temporal-references-figure"/> plots product 5 (in green)
1793+
and two variants referencing it (in yellow) on the same timeline.
1794+
Variant 8 (Medium) was introduced first, then variant 9 (XXL). Both
1795+
satisfy the foreign key constraint, because the referenced product exists
1796+
throughout their entire history.
1797+
</para>
1798+
1799+
<figure id="temporal-references-figure">
1800+
<title>Temporal Foreign Key Example</title>
1801+
<mediaobject>
1802+
<imageobject>
1803+
<imagedata fileref="images/temporal-references.svg" format="SVG" width="100%"/>
1804+
</imageobject>
1805+
</mediaobject>
1806+
</figure>
1807+
1808+
<para>
1809+
1810+
In a table, these records would be:
1811+
<programlisting>
1812+
id | product_no | name | valid_at
1813+
----+------------+--------+-------------------------
1814+
8 | 5 | Medium | [2021-01-01,2023-06-01)
1815+
9 | 5 | XXL | [2022-03-01,2024-06-01)
1816+
</programlisting>
1817+
</para>
1818+
1819+
<para>
1820+
Note that a temporal reference need not be fulfilled by a single row in
1821+
the referenced table. Product 5 had a price change in the middle of
1822+
variant 8's history, but the reference is still valid. The combination
1823+
of all matching rows is used to test whether the referenced history
1824+
contains the referencing row.
1825+
</para>
1826+
1827+
<para>
1828+
The syntax to add a temporal foreign key to our table is:
1829+
1830+
<programlisting>
1831+
CREATE TABLE variants (
1832+
id integer,
1833+
product_no integer,
1834+
name text,
1835+
valid_at daterange,
1836+
PRIMARY KEY (id, valid_at WITHOUT OVERLAPS),
1837+
<emphasis>FOREIGN KEY (product_no, PERIOD valid_at) REFERENCES products (product_no, PERIOD valid_at)</emphasis>
1838+
);
1839+
</programlisting>
1840+
1841+
Note that the keyword <literal>PERIOD</literal> must be used for the
1842+
application-time column in both the referencing and referenced table.
1843+
</para>
1844+
1845+
<para>
1846+
A temporal primary key or unique constraint matching the referenced columns
1847+
must exist on the referenced table.
1848+
</para>
1849+
1850+
<para>
1851+
<productname>PostgreSQL</productname> supports temporal foreign keys with
1852+
action <literal>NO ACTION</literal>, but not <literal>RESTRICT</literal>,
1853+
<literal>CASCADE</literal>, <literal>SET NULL</literal>, or <literal>SET
1854+
DEFAULT</literal>.
1855+
</para>
1856+
</sect3>
1857+
</sect2>
1858+
1859+
<sect2 id="ddl-system-time">
1860+
<title>System Time</title>
1861+
1862+
<indexterm zone="ddl-system-time">
1863+
<primary>system time</primary>
1864+
</indexterm>
1865+
1866+
<para>
1867+
<firstterm>System time</firstterm> refers to the history of the database
1868+
table, not the entity it describes. It captures when each row was
1869+
inserted/updated/deleted.
1870+
</para>
1871+
1872+
<para>
1873+
<productname>PostgreSQL</productname> does not currently support system
1874+
time, but it could be emulated using triggers, and there are external
1875+
extensions that provide such functionality.
1876+
</para>
1877+
</sect2>
1878+
</sect1>
1879+
15881880
<sect1 id="ddl-alter">
15891881
<title>Modifying Tables</title>
15901882

doc/src/sgml/glossary.sgml

Lines changed: 47 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -81,6 +81,21 @@
8181
</glossdef>
8282
</glossentry>
8383

84+
<glossentry id="glossary-application-time">
85+
<glossterm>Application time</glossterm>
86+
<glossdef>
87+
<para>
88+
In a <glossterm linkend="glossary-temporal-table">temporal table</glossterm>,
89+
the dimension of time that represents when the entity described by the table
90+
changed (as opposed to the table itself).
91+
</para>
92+
<para>
93+
For more information, see
94+
<xref linkend="ddl-temporal-tables"/>.
95+
</para>
96+
</glossdef>
97+
</glossentry>
98+
8499
<glossentry id="glossary-aio">
85100
<glossterm>Asynchronous <acronym>I/O</acronym></glossterm>
86101
<acronym>AIO</acronym>
@@ -1847,6 +1862,22 @@
18471862
</glossdef>
18481863
</glossentry>
18491864

1865+
<glossentry id="glossary-system-time">
1866+
<glossterm>System time</glossterm>
1867+
<glossdef>
1868+
<para>
1869+
In a <glossterm linkend="glossary-temporal-table">temporal table</glossterm>,
1870+
the dimension of time that represents when the table itself was changed
1871+
(as opposed to the entity the table describes).
1872+
Often used for auditing, compliance, and debugging.
1873+
</para>
1874+
<para>
1875+
For more information, see
1876+
<xref linkend="ddl-temporal-tables"/>.
1877+
</para>
1878+
</glossdef>
1879+
</glossentry>
1880+
18501881
<glossentry id="glossary-table">
18511882
<glossterm>Table</glossterm>
18521883
<glossdef>
@@ -1885,6 +1916,22 @@
18851916
</glossdef>
18861917
</glossentry>
18871918

1919+
<glossentry id="glossary-temporal-table">
1920+
<glossterm>Temporal table</glossterm>
1921+
<glossdef>
1922+
<para>
1923+
<glossterm linkend="glossary-table">Tables</glossterm>
1924+
that track <glossterm linkend="glossary-application-time">application time</glossterm>
1925+
or <glossterm linkend="glossary-system-time">system time</glossterm> (or both).
1926+
Not to be confused with <glossterm linkend="glossary-temporary-table">temporary tables</glossterm>.
1927+
</para>
1928+
<para>
1929+
For more information, see
1930+
<xref linkend="ddl-temporal-tables"/>.
1931+
</para>
1932+
</glossdef>
1933+
</glossentry>
1934+
18881935
<glossentry id="glossary-temporary-table">
18891936
<glossterm>Temporary table</glossterm>
18901937
<glossdef>

doc/src/sgml/images/Makefile

Lines changed: 3 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -5,7 +5,9 @@
55
ALL_IMAGES = \
66
genetic-algorithm.svg \
77
gin.svg \
8-
pagelayout.svg
8+
pagelayout.svg \
9+
temporal-entities.svg \
10+
temporal-references.svg
911

1012
DITAA = ditaa
1113
DOT = dot

0 commit comments

Comments
 (0)