Application Time Periods in Postgres
This is a preliminary draft - see avaitla16.com/how-i-write
I have been dealing with application time periods quite a bit recently. To learn more I was speaking with Paul Jungwirth on his good progress on Application periods in postgres. As a side note you should read his survey on temporal tables - it is quite good.
There are a few implementations for application periods we discussed:
- https://github.com/xocolatl/periods
- https://github.com/pjungwir/time_for_keys
These are great models for application periods, however they both use Postgres extensions which is more difficult to get working on hosted platforms like RDS which don't allow the installation of custom extensions.
After some reflection on them and guidance I decided to give it a shot in PG/SQL with an example. It's quite easy and clean to do with Postgres 14 and the tsmultirange types:
The gist is inlined here but can also be found here: gist.github.com/avaitla/2a19f3423fefa69f779..
CREATE EXTENSION btree_gist;
CREATE TABLE prices (
id serial PRIMARY KEY,
gas_station_id int,
gas_price_in_cents int
CONSTRAINT positive_price CHECK (gas_price_in_cents > 0),
ts_range tstzmultirange,
CONSTRAINT overlapping_times EXCLUDE USING GIST (
gas_station_id WITH =,
ts_range WITH &&
) DEFERRABLE INITIALLY IMMEDIATE
);
INSERT INTO prices (gas_station_id, gas_price_in_cents, ts_range) VALUES
(1, 2000, '{[2000-01-01 00:00, 2000-06-01 00:00)}');
INSERT INTO prices (gas_station_id, gas_price_in_cents, ts_range) VALUES
(1, 2000, '{[2000-06-01 00:00, 2000-12-01 00:00)}');
create or replace function new_gas_price(
new_gas_station_id integer,
new_gas_price_in_cents integer,
timerange tstzmultirange
) returns void language plpgsql as
$$
BEGIN
UPDATE prices SET ts_range = ts_range - timerange WHERE ts_range && timerange;
INSERT INTO prices (gas_station_id, gas_price_in_cents, ts_range) VALUES (new_gas_station_id, new_gas_price_in_cents, timerange);
DELETE FROM prices WHERE ts_range = '{}';
END;
$$;
START TRANSACTION;
SELECT new_gas_price(1, 100, '{[2000-03-01 00:00, 2000-04-01 00:00)}');
COMMIT;
SELECT * FROM prices;
SELECT new_gas_price(1, 600, '{[1999-06-01 00:00, 2001-12-01 00:00)}');
SELECT * FROM prices;
TRUNCATE TABLE prices;
It is indeed also possible with Postgres 13 but not clean whatsoever: gist.github.com/avaitla/1980e5c66e492d6fc84...