Skip to content

Commit 212be1e

Browse files
committed
Versioning using oid
This closes #31
1 parent 14aa091 commit 212be1e

File tree

6 files changed

+377
-48
lines changed

6 files changed

+377
-48
lines changed

GNUmakefile

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -13,7 +13,7 @@ DOCS = README.md
1313

1414
REGRESS = install no_system_period invalid_system_period \
1515
no_history_table no_history_system_period invalid_types \
16-
invalid_system_period_values \
16+
invalid_system_period_values renaming \
1717
versioning versioning_custom_system_time combinations \
1818
structure uninstall
1919

appveyor.yml

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -68,7 +68,7 @@ test_script:
6868
- if %pgversion%==9.4 set psqlopt=--psqldir
6969
- pg_regress "%psqlopt%=%pgroot%\bin"
7070
install no_system_period invalid_system_period no_history_table
71-
no_history_system_period invalid_types invalid_system_period_values
71+
no_history_system_period invalid_types invalid_system_period_values renaming
7272
versioning versioning_custom_system_time structure uninstall
7373
- if ERRORLEVEL 1 (set Outcome=Failed) else set Outcome=Passed
7474
- perl -e "my @s=stat('regression.out'); print 1000*($s[9]-$s[10]);" > duration

expected/renaming.out

Lines changed: 178 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,178 @@
1+
CREATE TABLE versioning (a bigint, "b b" date, sys_period tstzrange);
2+
-- Insert some data before versioning is enabled.
3+
INSERT INTO versioning (a, sys_period) VALUES (1, tstzrange('-infinity', NULL));
4+
INSERT INTO versioning (a, sys_period) VALUES (2, tstzrange('2000-01-01', NULL));
5+
CREATE TABLE versioning_history (a bigint, c date, sys_period tstzrange);
6+
CREATE OR REPLACE FUNCTION setup_versioning(
7+
main regclass,
8+
sys_period_column text,
9+
history regclass,
10+
adjust boolean)
11+
RETURNS void AS
12+
$BODY$
13+
begin
14+
execute format('
15+
CREATE TRIGGER versioning_trigger
16+
BEFORE INSERT OR UPDATE OR DELETE ON %I
17+
FOR EACH ROW EXECUTE PROCEDURE versioning2(''%s'', ''%s'', %s);
18+
', main, sys_period_column, history::oid, adjust::text);
19+
end;
20+
$BODY$
21+
LANGUAGE plpgsql;
22+
SELECT setup_versioning('versioning', 'sys_period', 'versioning_history', false);
23+
setup_versioning
24+
------------------
25+
26+
(1 row)
27+
28+
-- Insert.
29+
BEGIN;
30+
INSERT INTO versioning (a) VALUES (3);
31+
SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
32+
a | b b | ?column?
33+
---+-----+----------
34+
1 | | f
35+
2 | | f
36+
3 | | t
37+
(3 rows)
38+
39+
SELECT * FROM versioning_history ORDER BY a, sys_period;
40+
a | c | sys_period
41+
---+---+------------
42+
(0 rows)
43+
44+
COMMIT;
45+
-- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
46+
SELECT pg_sleep(0.1);
47+
pg_sleep
48+
----------
49+
50+
(1 row)
51+
52+
-- Update.
53+
BEGIN;
54+
UPDATE versioning SET a = 4 WHERE a = 3;
55+
SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
56+
a | b b | ?column?
57+
---+-----+----------
58+
1 | | f
59+
2 | | f
60+
4 | | t
61+
(3 rows)
62+
63+
SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
64+
a | c | ?column?
65+
---+---+----------
66+
3 | | t
67+
(1 row)
68+
69+
SELECT a, "b b" FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
70+
a | b b
71+
---+-----
72+
4 |
73+
(1 row)
74+
75+
COMMIT;
76+
-- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
77+
SELECT pg_sleep(0.1);
78+
pg_sleep
79+
----------
80+
81+
(1 row)
82+
83+
-- Multiple updates.
84+
BEGIN;
85+
UPDATE versioning SET a = 5 WHERE a = 4;
86+
UPDATE versioning SET "b b" = '2012-01-01' WHERE a = 5;
87+
SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
88+
a | b b | ?column?
89+
---+------------+----------
90+
1 | | f
91+
2 | | f
92+
5 | 01-01-2012 | t
93+
(3 rows)
94+
95+
SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
96+
a | c | ?column?
97+
---+---+----------
98+
3 | | f
99+
4 | | t
100+
(2 rows)
101+
102+
SELECT a, "b b" FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
103+
a | b b
104+
---+------------
105+
5 | 01-01-2012
106+
(1 row)
107+
108+
COMMIT;
109+
-- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
110+
SELECT pg_sleep(0.1);
111+
pg_sleep
112+
----------
113+
114+
(1 row)
115+
116+
-- Rename both tables
117+
ALTER TABLE versioning RENAME TO versioning_new;
118+
ALTER TABLE versioning_history RENAME TO versioning_new_history;
119+
-- Delete.
120+
BEGIN;
121+
DELETE FROM versioning_new WHERE a = 4;
122+
SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM versioning_new ORDER BY a, sys_period;
123+
a | b b | ?column?
124+
---+------------+----------
125+
1 | | f
126+
2 | | f
127+
5 | 01-01-2012 | f
128+
(3 rows)
129+
130+
SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_new_history ORDER BY a, sys_period;
131+
a | c | ?column?
132+
---+---+----------
133+
3 | | f
134+
4 | | f
135+
(2 rows)
136+
137+
SELECT a, "b b" FROM versioning_new WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
138+
a | b b
139+
---+-----
140+
(0 rows)
141+
142+
END;
143+
-- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
144+
SELECT pg_sleep(0.1);
145+
pg_sleep
146+
----------
147+
148+
(1 row)
149+
150+
CREATE SCHEMA new;
151+
ALTER TABLE versioning_new_history SET SCHEMA new;
152+
-- Delete.
153+
BEGIN;
154+
DELETE FROM versioning_new;
155+
SELECT * FROM versioning_new;
156+
a | b b | sys_period
157+
---+-----+------------
158+
(0 rows)
159+
160+
SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM new.versioning_new_history ORDER BY a, sys_period;
161+
a | c | ?column?
162+
---+---+----------
163+
1 | | t
164+
2 | | t
165+
3 | | f
166+
4 | | f
167+
5 | | t
168+
(5 rows)
169+
170+
SELECT a, "b b" FROM versioning_new WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
171+
a | b b
172+
---+-----
173+
(0 rows)
174+
175+
END;
176+
DROP TABLE versioning_new;
177+
DROP TABLE new.versioning_new_history;
178+
DROP SCHEMA new;

sql/renaming.sql

Lines changed: 113 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,113 @@
1+
CREATE TABLE versioning (a bigint, "b b" date, sys_period tstzrange);
2+
3+
-- Insert some data before versioning is enabled.
4+
INSERT INTO versioning (a, sys_period) VALUES (1, tstzrange('-infinity', NULL));
5+
INSERT INTO versioning (a, sys_period) VALUES (2, tstzrange('2000-01-01', NULL));
6+
7+
CREATE TABLE versioning_history (a bigint, c date, sys_period tstzrange);
8+
9+
CREATE OR REPLACE FUNCTION setup_versioning(
10+
main regclass,
11+
sys_period_column text,
12+
history regclass,
13+
adjust boolean)
14+
RETURNS void AS
15+
$BODY$
16+
begin
17+
execute format('
18+
CREATE TRIGGER versioning_trigger
19+
BEFORE INSERT OR UPDATE OR DELETE ON %I
20+
FOR EACH ROW EXECUTE PROCEDURE versioning2(''%s'', ''%s'', %s);
21+
', main, sys_period_column, history::oid, adjust::text);
22+
end;
23+
$BODY$
24+
LANGUAGE plpgsql;
25+
26+
SELECT setup_versioning('versioning', 'sys_period', 'versioning_history', false);
27+
28+
-- Insert.
29+
BEGIN;
30+
31+
INSERT INTO versioning (a) VALUES (3);
32+
33+
SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
34+
35+
SELECT * FROM versioning_history ORDER BY a, sys_period;
36+
37+
COMMIT;
38+
39+
-- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
40+
SELECT pg_sleep(0.1);
41+
42+
-- Update.
43+
BEGIN;
44+
45+
UPDATE versioning SET a = 4 WHERE a = 3;
46+
47+
SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
48+
49+
SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
50+
51+
SELECT a, "b b" FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
52+
53+
COMMIT;
54+
55+
-- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
56+
SELECT pg_sleep(0.1);
57+
58+
-- Multiple updates.
59+
BEGIN;
60+
61+
UPDATE versioning SET a = 5 WHERE a = 4;
62+
UPDATE versioning SET "b b" = '2012-01-01' WHERE a = 5;
63+
64+
SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
65+
66+
SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
67+
68+
SELECT a, "b b" FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
69+
70+
COMMIT;
71+
72+
-- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
73+
SELECT pg_sleep(0.1);
74+
75+
-- Rename both tables
76+
ALTER TABLE versioning RENAME TO versioning_new;
77+
ALTER TABLE versioning_history RENAME TO versioning_new_history;
78+
79+
-- Delete.
80+
BEGIN;
81+
82+
DELETE FROM versioning_new WHERE a = 4;
83+
84+
SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM versioning_new ORDER BY a, sys_period;
85+
86+
SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_new_history ORDER BY a, sys_period;
87+
88+
SELECT a, "b b" FROM versioning_new WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
89+
90+
END;
91+
92+
-- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
93+
SELECT pg_sleep(0.1);
94+
95+
CREATE SCHEMA new;
96+
ALTER TABLE versioning_new_history SET SCHEMA new;
97+
98+
-- Delete.
99+
BEGIN;
100+
101+
DELETE FROM versioning_new;
102+
103+
SELECT * FROM versioning_new;
104+
105+
SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM new.versioning_new_history ORDER BY a, sys_period;
106+
107+
SELECT a, "b b" FROM versioning_new WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
108+
109+
END;
110+
111+
DROP TABLE versioning_new;
112+
DROP TABLE new.versioning_new_history;
113+
DROP SCHEMA new;

temporal_tables--1.1.1.sql

Lines changed: 9 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -12,6 +12,15 @@ REVOKE ALL ON FUNCTION versioning() FROM PUBLIC;
1212

1313
COMMENT ON FUNCTION versioning() IS 'System-period temporal table trigger';
1414

15+
CREATE FUNCTION versioning2()
16+
RETURNS TRIGGER
17+
AS 'MODULE_PATHNAME'
18+
LANGUAGE C STRICT;
19+
20+
REVOKE ALL ON FUNCTION versioning2() FROM PUBLIC;
21+
22+
COMMENT ON FUNCTION versioning2() IS 'System-period temporal table trigger, use OID as text for history relation';
23+
1524
CREATE FUNCTION set_system_time(timestamptz)
1625
RETURNS VOID
1726
AS 'MODULE_PATHNAME'

0 commit comments

Comments
 (0)