-
Notifications
You must be signed in to change notification settings - Fork 21
/
README.sql
161 lines (128 loc) · 5.17 KB
/
README.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
------------------------------------------------------
-- Temporal schema for an example "countries" relation
--
-- https://github.com/ifad/chronomodel
--
create schema temporal; -- schema containing all temporal tables
create schema history; -- schema containing all history tables
-- Current countries data - nothing special
--
create table temporal.countries (
id serial primary key,
name varchar,
updated_at timestamptz
);
-- Countries historical data.
--
-- Inheritance is used to avoid duplicating the schema from the main table.
-- Please note that columns on the main table cannot be dropped, and other caveats
-- https://www.postgresql.org/docs/9.0/ddl-inherit.html#DDL-INHERIT-CAVEATS
--
create table history.countries (
hid serial primary key,
validity tsrange,
recorded_at timestamp not null default timezone('UTC', now()),
constraint overlapping_times exclude using gist ( id with =, validity with && )
) inherits ( temporal.countries );
-- Inherited primary key
create index country_inherit_pkey on history.countries ( id );
-- Snapshot of data at a specific point in time
create index country_snapshot on history.countries USING gist ( validity );
-- Used by the trigger functions when UPDATE'ing and DELETE'ing
create index country_lower_validity on history.countries ( lower(validity) )
create index country_upper_validity on history.countries ( upper(validity) )
create index country_recorded_at on history.countries ( id, valid_to )
-- Single instance whole history
create index country_instance_history on history.countries ( id, recorded_at )
-- The countries view, what the Rails' application ORM will actually CRUD on,
-- and the entry point of the temporal triggers.
--
-- SELECT - return only current data
--
create view public.countries as select * from only temporal.countries;
-- INSERT - insert data both in the current data table and in the history one.
--
create or replace function public.chronomodel_countries_insert() returns trigger as $$
begin
if new.id is null then
new.id = nextval('temporal.countries_id_seq');
end if;
insert into temporal.countries ( id, name, updated_at )
values ( new.id, new.name, new.updated_at );
insert into history.countries (id, name, updated_at, validity )
values ( new.id, new.name, new.updated_at, tsrange(timezone('utc', now()), null) );
return new;
end;
$$ language plpgsql;
create trigger chronomodel_insert
instead of insert on public.countries
for each row execute procedure public.chronomodel_countries_insert();
-- UPDATE - set the last history entry validity to now, save the current data
-- in a new history entry and update the temporal table with the new data.
--
-- If a row in the history with the current ID and current timestamp already
-- exists, update it with new data. This logic makes possible to "squash"
-- together changes made in a transaction in a single history row.
--
-- If the update doesn't change the data, it is skipped and the trigger
-- returns NULL.
--
-- By default, history is not recorded if only the updated_at field
-- is changed.
--
create function chronomodel_countries_update() returns trigger as $$
declare _now timestamp;
declare _hid integer;
declare _old record;
declare _new record;
begin
if old is not distinct from new then
return null;
end if;
_old := row(old.name);
_new := row(new.name);
if _old is not distinct from new then
update only temporal.countries set ( name, updated_at ) = ( new.name, new.updated_at ) where id = old.id
return new;
end if;
_now := timezone('utc', now());
_hid := null;
select hid into _hid from history.countries where id = old.id and lower(validity) = _now;
if _hid is not null then
update history.countries set ( name, updated_at ) = ( new.name ) where hid = _hid;
else
update history.countries set validity = tsrange(lower(validity), _now)
where id = old.id and upper_inf(validity);
insert into history.countries ( id, name, updated_at, validity )
values ( old.id, new.name, new.updated_at, tsrange(_now, null) );
end if;
update only temporal.countries set ( name ) = ( new.name ) where id = old.id;
return new;
end;
$$ language plpgsql;
create trigger chronomodel_update
instead of update on temporal.countries
for each row execute procedure chronomodel_countries_update();
-- DELETE - save the current data in the history and eventually delete the
-- data from the temporal table.
--
-- The first DELETE is required to remove history for records INSERTed and
-- DELETEd in the same transaction.
--
create or replace function chronomodel_countries_delete() returns trigger as $$
declare _now timestamp;
begin
_now := timezone('utc', now());
delete from history.countries
where id = old.id and validity = tsrange(_now, null);
update history.countries set valid_to = _now
where id = old.id and upper_inf(validity);
delete from only temporal.countries
where temporal.id = old.id;
return old;
end;
$$ language plpgsql;
create trigger chronomodel_delete
instead of delete on temporal.countries
for each row execute procedure chronomodel_countries_delete();
-- EOF