Skip to content

Commit

Permalink
Allow SYSTEM_TIME columns to be date, timestamp, and timestamptz.
Browse files Browse the repository at this point in the history
The SQL standard provides rules for these types, so let's implement
them.
  • Loading branch information
Vik Fearing committed Jul 17, 2019
1 parent e7352e5 commit 939fccf
Show file tree
Hide file tree
Showing 8 changed files with 466 additions and 22 deletions.
16 changes: 11 additions & 5 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -152,11 +152,17 @@ here. You can use the range type operators instead.
## `SYSTEM_TIME`

If the period is named `SYSTEM_TIME`, then special rules apply. The type
of the columns must be `timestamp with time zone` and they are not
modifyable by the user. In the SQL standard, the start column is
`GENERATED ALWAYS AS ROW START` and the end column is `GENERATED ALWAYS
AS ROW END`. This extension uses triggers to set the start column to
`transaction_timestamp()` and the end column is always `'infinity'`.
of the columns must be `date`, `timestamp without time zone`, or
`timestamp with time zone`; and they are not modifiable by the user. In
the SQL standard, the start column is `GENERATED ALWAYS AS ROW START`
and the end column is `GENERATED ALWAYS AS ROW END`. This extension uses
triggers to set the start column to `transaction_timestamp()` and the
end column is always `'infinity'`.

***Note:*** It is generally unwise to use anything but `timestamp with
time zone` because changes in the `TimeZone` configuration paramater or
even just Daylight Savings Time changes can distort the history. Even
when only using UTC, we recommend the `timestamp with time zone` type.

``` sql
CREATE TABLE example (
Expand Down
72 changes: 72 additions & 0 deletions expected/periods.out
Original file line number Diff line number Diff line change
Expand Up @@ -287,6 +287,78 @@ TABLE periods.for_portion_views;
(0 rows)

DROP TABLE pricing;
/* SYSTEM_TIME with date */
BEGIN;
SELECT transaction_timestamp()::date AS xd,
transaction_timestamp()::timestamp AS xts,
transaction_timestamp() AS xtstz
\gset
CREATE TABLE sysver_date (val text, start_date date, end_date date);
SELECT periods.add_system_time_period('sysver_date', 'start_date', 'end_date');
add_system_time_period
------------------------
t
(1 row)

TABLE periods.periods;
table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint
-------------+-------------+-------------------+-----------------+------------+-------------------------------
sysver_date | system_time | start_date | end_date | daterange | sysver_date_system_time_check
(1 row)

INSERT INTO sysver_date DEFAULT VALUES;
SELECT val, start_date = :'xd' AS start_date_eq, end_date FROM sysver_date;
val | start_date_eq | end_date
-----+---------------+----------
| t | infinity
(1 row)

DROP TABLE sysver_date;
/* SYSTEM_TIME with timestamp without time zone */
CREATE TABLE sysver_ts (val text, start_ts timestamp without time zone, end_ts timestamp without time zone);
SELECT periods.add_system_time_period('sysver_ts', 'start_ts', 'end_ts');
add_system_time_period
------------------------
t
(1 row)

TABLE periods.periods;
table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint
------------+-------------+-------------------+-----------------+------------+-----------------------------
sysver_ts | system_time | start_ts | end_ts | tsrange | sysver_ts_system_time_check
(1 row)

INSERT INTO sysver_ts DEFAULT VALUES;
SELECT val, start_ts = :'xts' AS start_ts_eq, end_ts FROM sysver_ts;
val | start_ts_eq | end_ts
-----+-------------+----------
| t | infinity
(1 row)

DROP TABLE sysver_ts;
/* SYSTEM_TIME with timestamp with time zone */
CREATE TABLE sysver_tstz (val text, start_tstz timestamp with time zone, end_tstz timestamp with time zone);
SELECT periods.add_system_time_period('sysver_tstz', 'start_tstz', 'end_tstz');
add_system_time_period
------------------------
t
(1 row)

TABLE periods.periods;
table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint
-------------+-------------+-------------------+-----------------+------------+-------------------------------
sysver_tstz | system_time | start_tstz | end_tstz | tstzrange | sysver_tstz_system_time_check
(1 row)

INSERT INTO sysver_tstz DEFAULT VALUES;
SELECT val, start_tstz = :'xtstz' AS start_tstz_eq, end_tstz FROM sysver_tstz;
val | start_tstz_eq | end_tstz
-----+---------------+----------
| t | infinity
(1 row)

DROP TABLE sysver_tstz;
COMMIT;
/* Basic SYSTEM_TIME periods with CASCADE/purge */
CREATE TABLE sysver (val text);
SELECT periods.add_system_time_period('sysver', 'startname');
Expand Down
72 changes: 72 additions & 0 deletions expected/periods_1.out
Original file line number Diff line number Diff line change
Expand Up @@ -289,6 +289,78 @@ TABLE periods.for_portion_views;
(0 rows)

DROP TABLE pricing;
/* SYSTEM_TIME with date */
BEGIN;
SELECT transaction_timestamp()::date AS xd,
transaction_timestamp()::timestamp AS xts,
transaction_timestamp() AS xtstz
\gset
CREATE TABLE sysver_date (val text, start_date date, end_date date);
SELECT periods.add_system_time_period('sysver_date', 'start_date', 'end_date');
add_system_time_period
------------------------
t
(1 row)

TABLE periods.periods;
table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint
-------------+-------------+-------------------+-----------------+------------+-------------------------------
sysver_date | system_time | start_date | end_date | daterange | sysver_date_system_time_check
(1 row)

INSERT INTO sysver_date DEFAULT VALUES;
SELECT val, start_date = :'xd' AS start_date_eq, end_date FROM sysver_date;
val | start_date_eq | end_date
-----+---------------+----------
| t | infinity
(1 row)

DROP TABLE sysver_date;
/* SYSTEM_TIME with timestamp without time zone */
CREATE TABLE sysver_ts (val text, start_ts timestamp without time zone, end_ts timestamp without time zone);
SELECT periods.add_system_time_period('sysver_ts', 'start_ts', 'end_ts');
add_system_time_period
------------------------
t
(1 row)

TABLE periods.periods;
table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint
------------+-------------+-------------------+-----------------+------------+-----------------------------
sysver_ts | system_time | start_ts | end_ts | tsrange | sysver_ts_system_time_check
(1 row)

INSERT INTO sysver_ts DEFAULT VALUES;
SELECT val, start_ts = :'xts' AS start_ts_eq, end_ts FROM sysver_ts;
val | start_ts_eq | end_ts
-----+-------------+----------
| t | infinity
(1 row)

DROP TABLE sysver_ts;
/* SYSTEM_TIME with timestamp with time zone */
CREATE TABLE sysver_tstz (val text, start_tstz timestamp with time zone, end_tstz timestamp with time zone);
SELECT periods.add_system_time_period('sysver_tstz', 'start_tstz', 'end_tstz');
add_system_time_period
------------------------
t
(1 row)

TABLE periods.periods;
table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint
-------------+-------------+-------------------+-----------------+------------+-------------------------------
sysver_tstz | system_time | start_tstz | end_tstz | tstzrange | sysver_tstz_system_time_check
(1 row)

INSERT INTO sysver_tstz DEFAULT VALUES;
SELECT val, start_tstz = :'xtstz' AS start_tstz_eq, end_tstz FROM sysver_tstz;
val | start_tstz_eq | end_tstz
-----+---------------+----------
| t | infinity
(1 row)

DROP TABLE sysver_tstz;
COMMIT;
/* Basic SYSTEM_TIME periods with CASCADE/purge */
CREATE TABLE sysver (val text);
SELECT periods.add_system_time_period('sysver', 'startname');
Expand Down
72 changes: 72 additions & 0 deletions expected/periods_2.out
Original file line number Diff line number Diff line change
Expand Up @@ -291,6 +291,78 @@ TABLE periods.for_portion_views;
(0 rows)

DROP TABLE pricing;
/* SYSTEM_TIME with date */
BEGIN;
SELECT transaction_timestamp()::date AS xd,
transaction_timestamp()::timestamp AS xts,
transaction_timestamp() AS xtstz
\gset
CREATE TABLE sysver_date (val text, start_date date, end_date date);
SELECT periods.add_system_time_period('sysver_date', 'start_date', 'end_date');
add_system_time_period
------------------------
t
(1 row)

TABLE periods.periods;
table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint
-------------+-------------+-------------------+-----------------+------------+-------------------------------
sysver_date | system_time | start_date | end_date | daterange | sysver_date_system_time_check
(1 row)

INSERT INTO sysver_date DEFAULT VALUES;
SELECT val, start_date = :'xd' AS start_date_eq, end_date FROM sysver_date;
val | start_date_eq | end_date
-----+---------------+----------
| t | infinity
(1 row)

DROP TABLE sysver_date;
/* SYSTEM_TIME with timestamp without time zone */
CREATE TABLE sysver_ts (val text, start_ts timestamp without time zone, end_ts timestamp without time zone);
SELECT periods.add_system_time_period('sysver_ts', 'start_ts', 'end_ts');
add_system_time_period
------------------------
t
(1 row)

TABLE periods.periods;
table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint
------------+-------------+-------------------+-----------------+------------+-----------------------------
sysver_ts | system_time | start_ts | end_ts | tsrange | sysver_ts_system_time_check
(1 row)

INSERT INTO sysver_ts DEFAULT VALUES;
SELECT val, start_ts = :'xts' AS start_ts_eq, end_ts FROM sysver_ts;
val | start_ts_eq | end_ts
-----+-------------+----------
| t | infinity
(1 row)

DROP TABLE sysver_ts;
/* SYSTEM_TIME with timestamp with time zone */
CREATE TABLE sysver_tstz (val text, start_tstz timestamp with time zone, end_tstz timestamp with time zone);
SELECT periods.add_system_time_period('sysver_tstz', 'start_tstz', 'end_tstz');
add_system_time_period
------------------------
t
(1 row)

TABLE periods.periods;
table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint
-------------+-------------+-------------------+-----------------+------------+-------------------------------
sysver_tstz | system_time | start_tstz | end_tstz | tstzrange | sysver_tstz_system_time_check
(1 row)

INSERT INTO sysver_tstz DEFAULT VALUES;
SELECT val, start_tstz = :'xtstz' AS start_tstz_eq, end_tstz FROM sysver_tstz;
val | start_tstz_eq | end_tstz
-----+---------------+----------
| t | infinity
(1 row)

DROP TABLE sysver_tstz;
COMMIT;
/* Basic SYSTEM_TIME periods with CASCADE/purge */
CREATE TABLE sysver (val text);
SELECT periods.add_system_time_period('sysver', 'startname');
Expand Down
72 changes: 72 additions & 0 deletions expected/periods_3.out
Original file line number Diff line number Diff line change
Expand Up @@ -285,6 +285,78 @@ TABLE periods.for_portion_views;
(0 rows)

DROP TABLE pricing;
/* SYSTEM_TIME with date */
BEGIN;
SELECT transaction_timestamp()::date AS xd,
transaction_timestamp()::timestamp AS xts,
transaction_timestamp() AS xtstz
\gset
CREATE TABLE sysver_date (val text, start_date date, end_date date);
SELECT periods.add_system_time_period('sysver_date', 'start_date', 'end_date');
add_system_time_period
------------------------
t
(1 row)

TABLE periods.periods;
table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint
-------------+-------------+-------------------+-----------------+------------+-------------------------------
sysver_date | system_time | start_date | end_date | daterange | sysver_date_system_time_check
(1 row)

INSERT INTO sysver_date DEFAULT VALUES;
SELECT val, start_date = :'xd' AS start_date_eq, end_date FROM sysver_date;
val | start_date_eq | end_date
-----+---------------+----------
| t | infinity
(1 row)

DROP TABLE sysver_date;
/* SYSTEM_TIME with timestamp without time zone */
CREATE TABLE sysver_ts (val text, start_ts timestamp without time zone, end_ts timestamp without time zone);
SELECT periods.add_system_time_period('sysver_ts', 'start_ts', 'end_ts');
add_system_time_period
------------------------
t
(1 row)

TABLE periods.periods;
table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint
------------+-------------+-------------------+-----------------+------------+-----------------------------
sysver_ts | system_time | start_ts | end_ts | tsrange | sysver_ts_system_time_check
(1 row)

INSERT INTO sysver_ts DEFAULT VALUES;
SELECT val, start_ts = :'xts' AS start_ts_eq, end_ts FROM sysver_ts;
val | start_ts_eq | end_ts
-----+-------------+----------
| t | infinity
(1 row)

DROP TABLE sysver_ts;
/* SYSTEM_TIME with timestamp with time zone */
CREATE TABLE sysver_tstz (val text, start_tstz timestamp with time zone, end_tstz timestamp with time zone);
SELECT periods.add_system_time_period('sysver_tstz', 'start_tstz', 'end_tstz');
add_system_time_period
------------------------
t
(1 row)

TABLE periods.periods;
table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint
-------------+-------------+-------------------+-----------------+------------+-------------------------------
sysver_tstz | system_time | start_tstz | end_tstz | tstzrange | sysver_tstz_system_time_check
(1 row)

INSERT INTO sysver_tstz DEFAULT VALUES;
SELECT val, start_tstz = :'xtstz' AS start_tstz_eq, end_tstz FROM sysver_tstz;
val | start_tstz_eq | end_tstz
-----+---------------+----------
| t | infinity
(1 row)

DROP TABLE sysver_tstz;
COMMIT;
/* Basic SYSTEM_TIME periods with CASCADE/purge */
CREATE TABLE sysver (val text);
SELECT periods.add_system_time_period('sysver', 'startname');
Expand Down
23 changes: 20 additions & 3 deletions periods--0.03.sql
Original file line number Diff line number Diff line change
Expand Up @@ -567,6 +567,11 @@ DECLARE
end_type oid;
end_collation oid;
end_notnull boolean;

DATE_OID CONSTANT integer := 1082;
TIMESTAMP_OID CONSTANT integer := 1114;
TIMESTAMPTZ_OID CONSTANT integer := 1184;
range_type regtype;
BEGIN
IF table_class IS NULL THEN
RAISE EXCEPTION 'no table name specified';
Expand Down Expand Up @@ -679,10 +684,22 @@ BEGIN
END IF;

/* Verify compatibility of start/end columns */
IF start_type <> 'timestamp with time zone'::regtype OR end_type <> 'timestamp with time zone'::regtype THEN
RAISE EXCEPTION 'start and end columns must be of type "timestamp with time zone"';
IF start_type::regtype NOT IN ('date', 'timestamp without time zone', 'timestamp with time zone') THEN
RAISE EXCEPTION 'SYSTEM_TIME periods must be of type "date", "timestamp without time zone", or "timestamp with time zone"';
END IF;
IF start_type <> end_type THEN
RAISE EXCEPTION 'start and end columns must be of same type';
END IF;

/* Get appropriate range type */
CASE start_type
WHEN DATE_OID THEN range_type := 'daterange';
WHEN TIMESTAMP_OID THEN range_type := 'tsrange';
WHEN TIMESTAMPTZ_OID THEN range_type := 'tstzrange';
ELSE
RAISE EXCEPTION 'unexpected data type: "%"', start_type::regtype;
END CASE;

/* can't be part of a foreign key */
IF EXISTS (
SELECT FROM periods.foreign_keys AS fk
Expand Down Expand Up @@ -767,7 +784,7 @@ BEGIN
EXECUTE format('CREATE TRIGGER %I AFTER TRUNCATE ON %s FOR EACH STATEMENT EXECUTE PROCEDURE periods.truncate_system_versioning()', truncate_trigger, table_class);

INSERT INTO periods.periods (table_name, period_name, start_column_name, end_column_name, range_type, bounds_check_constraint)
VALUES (table_class, period_name, start_column_name, end_column_name, 'tstzrange', bounds_check_constraint);
VALUES (table_class, period_name, start_column_name, end_column_name, range_type, bounds_check_constraint);

INSERT INTO periods.system_time_periods (table_name, period_name, infinity_check_constraint, generated_always_trigger, write_history_trigger, truncate_trigger)
VALUES (table_class, period_name, infinity_check_constraint, generated_always_trigger, write_history_trigger, truncate_trigger);
Expand Down
Loading

0 comments on commit 939fccf

Please sign in to comment.