├── README.periods ├── debian ├── pgversions ├── source │ └── format ├── tests │ ├── installcheck │ └── control ├── watch ├── gitlab-ci.yml ├── rules ├── control ├── control.in ├── copyright └── changelog ├── .gitattributes ├── sql ├── uninstall.sql ├── beeswax.sql ├── install.sql ├── health_checks.sql ├── periods.sql ├── unique_foreign.sql ├── excluded_columns.sql ├── drop_protection.sql ├── issues.sql ├── rename_following.sql ├── for_portion_of.sql ├── system_versioning.sql ├── predicates.sql ├── system_time_periods.sql └── acl.sql ├── expected ├── uninstall.out ├── beeswax.out ├── install.out ├── health_checks_1.out ├── health_checks.out ├── periods_1.out ├── periods.out ├── issues.out ├── issues_1.out ├── unique_foreign_1.out ├── excluded_columns_1.out ├── unique_foreign.out ├── excluded_columns.out ├── drop_protection_1.out ├── for_portion_of.out ├── for_portion_of_1.out ├── for_portion_of_2.out ├── drop_protection.out ├── predicates.out ├── system_time_periods_1.out ├── system_time_periods.out ├── rename_following_1.out ├── system_versioning.out └── rename_following.out ├── .gitignore ├── periods.control ├── CODE_OF_CONDUCT.md ├── Makefile ├── .github └── workflows │ └── regression.yml ├── LICENSE ├── CHANGELOG.md └── periods.vcxproj /README.periods: -------------------------------------------------------------------------------- 1 | README.md -------------------------------------------------------------------------------- /debian/pgversions: -------------------------------------------------------------------------------- 1 | 9.5+ 2 | -------------------------------------------------------------------------------- /debian/source/format: -------------------------------------------------------------------------------- 1 | 3.0 (quilt) 2 | -------------------------------------------------------------------------------- /debian/tests/installcheck: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | pg_buildext installcheck 3 | -------------------------------------------------------------------------------- /.gitattributes: -------------------------------------------------------------------------------- 1 | sql/* linguist-language=SQL 2 | expected/* linguist-detectable=false 3 | -------------------------------------------------------------------------------- /debian/watch: -------------------------------------------------------------------------------- 1 | version=4 2 | https://github.com/xocolatl/periods/tags .*/v(.*).tar.gz 3 | -------------------------------------------------------------------------------- /sql/uninstall.sql: -------------------------------------------------------------------------------- 1 | DROP EXTENSION periods; 2 | DROP ROLE periods_unprivileged_user; 3 | -------------------------------------------------------------------------------- /expected/uninstall.out: -------------------------------------------------------------------------------- 1 | DROP EXTENSION periods; 2 | DROP ROLE periods_unprivileged_user; 3 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | .vscode/ 2 | periods.o 3 | periods.so 4 | regression.diffs 5 | regression.out 6 | results/ 7 | -------------------------------------------------------------------------------- /debian/gitlab-ci.yml: -------------------------------------------------------------------------------- 1 | include: https://salsa.debian.org/postgresql/postgresql-common/raw/master/gitlab/gitlab-ci.yml 2 | -------------------------------------------------------------------------------- /debian/tests/control: -------------------------------------------------------------------------------- 1 | Depends: 2 | postgresql-common-dev, 3 | @, 4 | Tests: 5 | installcheck, 6 | Restrictions: 7 | allow-stderr, 8 | -------------------------------------------------------------------------------- /debian/rules: -------------------------------------------------------------------------------- 1 | #!/usr/bin/make -f 2 | 3 | override_dh_installdocs: 4 | dh_installdocs --all README.* 5 | 6 | %: 7 | dh $@ --with pgxs 8 | -------------------------------------------------------------------------------- /periods.control: -------------------------------------------------------------------------------- 1 | comment = 'Provide Standard SQL functionality for PERIODs and SYSTEM VERSIONING' 2 | default_version = 1.2 3 | module_pathname = '$libdir/periods' 4 | relocatable = false 5 | requires = 'btree_gist' 6 | -------------------------------------------------------------------------------- /CODE_OF_CONDUCT.md: -------------------------------------------------------------------------------- 1 | This extension adheres to the official [PostgreSQL Community Code of 2 | Conduct](https://www.postgresql.org/about/policies/coc/). It is not 3 | reproduced here so that future modifications may take effect 4 | immediately. 5 | -------------------------------------------------------------------------------- /sql/beeswax.sql: -------------------------------------------------------------------------------- 1 | /* 2 | * Test creating a table, dropping a column, and then dropping the whole thing; 3 | * without any periods. This is to make sure the health checks don't try to do 4 | * anything. 5 | */ 6 | CREATE TABLE beeswax (col1 text, col2 date); 7 | ALTER TABLE beeswax DROP COLUMN col1; 8 | DROP TABLE beeswax; 9 | -------------------------------------------------------------------------------- /expected/beeswax.out: -------------------------------------------------------------------------------- 1 | /* 2 | * Test creating a table, dropping a column, and then dropping the whole thing; 3 | * without any periods. This is to make sure the health checks don't try to do 4 | * anything. 5 | */ 6 | CREATE TABLE beeswax (col1 text, col2 date); 7 | ALTER TABLE beeswax DROP COLUMN col1; 8 | DROP TABLE beeswax; 9 | -------------------------------------------------------------------------------- /sql/install.sql: -------------------------------------------------------------------------------- 1 | /* Once support for 9.5 has passed, use CASCADE */ 2 | CREATE EXTENSION IF NOT EXISTS btree_gist; 3 | /* Once support for 9.6 has passed, just create the extension */ 4 | CREATE EXTENSION periods VERSION '1.2'; 5 | 6 | SELECT extversion 7 | FROM pg_extension 8 | WHERE extname = 'periods'; 9 | 10 | DROP ROLE periods_unprivileged_user; 11 | CREATE ROLE periods_unprivileged_user; 12 | 13 | /* Make tests work on PG 15 */ 14 | GRANT CREATE ON SCHEMA public TO PUBLIC; 15 | -------------------------------------------------------------------------------- /expected/install.out: -------------------------------------------------------------------------------- 1 | /* Once support for 9.5 has passed, use CASCADE */ 2 | CREATE EXTENSION IF NOT EXISTS btree_gist; 3 | /* Once support for 9.6 has passed, just create the extension */ 4 | CREATE EXTENSION periods VERSION '1.2'; 5 | SELECT extversion 6 | FROM pg_extension 7 | WHERE extname = 'periods'; 8 | extversion 9 | ------------ 10 | 1.2 11 | (1 row) 12 | 13 | DROP ROLE periods_unprivileged_user; 14 | ERROR: role "periods_unprivileged_user" does not exist 15 | CREATE ROLE periods_unprivileged_user; 16 | /* Make tests work on PG 15 */ 17 | GRANT CREATE ON SCHEMA public TO PUBLIC; 18 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | MODULES = periods 2 | EXTENSION = periods 3 | DOCS = README.periods 4 | 5 | DATA = periods--1.0.sql \ 6 | periods--1.0--1.1.sql \ 7 | periods--1.1.sql \ 8 | periods--1.1--1.2.sql \ 9 | periods--1.2.sql 10 | 11 | REGRESS = install \ 12 | periods \ 13 | system_time_periods \ 14 | system_versioning \ 15 | excluded_columns \ 16 | unique_foreign \ 17 | for_portion_of \ 18 | predicates \ 19 | drop_protection \ 20 | rename_following \ 21 | health_checks \ 22 | acl \ 23 | issues \ 24 | beeswax \ 25 | uninstall 26 | 27 | PG_CONFIG = pg_config 28 | PGXS := $(shell $(PG_CONFIG) --pgxs) 29 | include $(PGXS) 30 | -------------------------------------------------------------------------------- /.github/workflows/regression.yml: -------------------------------------------------------------------------------- 1 | name: make installcheck 2 | on: [push, pull_request] 3 | 4 | jobs: 5 | test: 6 | strategy: 7 | matrix: 8 | pg: 9 | - 18 10 | - 17 11 | - 16 12 | - 15 13 | - 14 14 | - 13 15 | - 12 16 | - 11 17 | - 10 18 | - 9.6 19 | - 9.5 20 | 21 | name: PostgreSQL ${{ matrix.pg }} 22 | runs-on: ubuntu-latest 23 | container: pgxn/pgxn-tools 24 | steps: 25 | 26 | - name: Start PostgreSQL ${{ matrix.pg }} 27 | run: pg-start ${{ matrix.pg }} 28 | 29 | - name: Check out the repo 30 | uses: actions/checkout@v2 31 | 32 | - name: Test on PostgreSQL ${{ matrix.pg }} 33 | run: pg-build-test 34 | -------------------------------------------------------------------------------- /sql/health_checks.sql: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | 4 | /* Run tests as unprivileged user */ 5 | SET ROLE TO periods_unprivileged_user; 6 | 7 | /* Ensure tables with periods are persistent */ 8 | CREATE UNLOGGED TABLE log (id bigint, s date, e date); 9 | SELECT periods.add_period('log', 'p', 's', 'e'); -- fails 10 | SELECT periods.add_system_time_period('log'); -- fails 11 | ALTER TABLE log SET LOGGED; 12 | SELECT periods.add_period('log', 'p', 's', 'e'); -- passes 13 | SELECT periods.add_system_time_period('log'); -- passes 14 | ALTER TABLE log SET UNLOGGED; -- fails 15 | SELECT periods.add_system_versioning('log'); 16 | ALTER TABLE log_history SET UNLOGGED; -- fails 17 | SELECT periods.drop_system_versioning('log', purge => true); 18 | DROP TABLE log; 19 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | PostgreSQL License 2 | 3 | Copyright (c) 2019, The PostgreSQL Global Development Group (PGDG) 4 | 5 | Permission to use, copy, modify, and distribute this software and its 6 | documentation for any purpose, without fee, and without a written agreement is 7 | hereby granted, provided that the above copyright notice and this paragraph 8 | and the following two paragraphs appear in all copies. 9 | 10 | IN NO EVENT SHALL PGDG BE LIABLE TO ANY PARTY FOR DIRECT, INDIRECT, 11 | SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING LOST PROFITS, ARISING 12 | OUT OF THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION, EVEN IF PGDG 13 | HAS BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 14 | 15 | PGDG SPECIFICALLY DISCLAIMS ANY WARRANTIES, INCLUDING, BUT NOT 16 | LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A 17 | PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, 18 | AND PGDG HAS NO OBLIGATIONS TO PROVIDE MAINTENANCE, SUPPORT, UPDATES, 19 | ENHANCEMENTS, OR MODIFICATIONS. 20 | -------------------------------------------------------------------------------- /debian/control: -------------------------------------------------------------------------------- 1 | Source: postgresql-periods 2 | Section: database 3 | Priority: optional 4 | Maintainer: Debian PostgreSQL Maintainers 5 | Uploaders: 6 | Christoph Berg , 7 | Build-Depends: 8 | debhelper-compat (= 13), 9 | architecture-is-64-bit , 10 | postgresql-all , 11 | postgresql-server-dev-all, 12 | Standards-Version: 4.7.2 13 | Vcs-Browser: https://github.com/xocolatl/periods 14 | Vcs-Git: https://github.com/xocolatl/periods.git 15 | Homepage: https://github.com/xocolatl/periods 16 | 17 | Package: postgresql-18-periods 18 | Architecture: any 19 | Depends: 20 | postgresql-contrib-18, 21 | ${misc:Depends}, 22 | ${postgresql:Depends}, 23 | ${shlibs:Depends}, 24 | Breaks: 25 | ${postgresql:Breaks}, 26 | Description: PERIODs and SYSTEM VERSIONING for PostgreSQL 27 | This extension attempts to recreate the behavior defined in SQL:2016 28 | (originally SQL:2011) around periods and tables with SYSTEM VERSIONING. The 29 | idea is to figure out all the rules that PostgreSQL would like to adopt (there 30 | are some details missing in the standard) and to allow earlier versions of 31 | PostgreSQL to simulate the behavior once the feature is finally integrated. 32 | -------------------------------------------------------------------------------- /debian/control.in: -------------------------------------------------------------------------------- 1 | Source: postgresql-periods 2 | Section: database 3 | Priority: optional 4 | Maintainer: Debian PostgreSQL Maintainers 5 | Uploaders: 6 | Christoph Berg , 7 | Build-Depends: 8 | debhelper-compat (= 13), 9 | architecture-is-64-bit , 10 | postgresql-all , 11 | postgresql-server-dev-all, 12 | Standards-Version: 4.7.2 13 | Vcs-Browser: https://github.com/xocolatl/periods 14 | Vcs-Git: https://github.com/xocolatl/periods.git 15 | Homepage: https://github.com/xocolatl/periods 16 | 17 | Package: postgresql-PGVERSION-periods 18 | Architecture: any 19 | Depends: 20 | postgresql-contrib-PGVERSION, 21 | ${misc:Depends}, 22 | ${postgresql:Depends}, 23 | ${shlibs:Depends}, 24 | Breaks: 25 | ${postgresql:Breaks}, 26 | Description: PERIODs and SYSTEM VERSIONING for PostgreSQL 27 | This extension attempts to recreate the behavior defined in SQL:2016 28 | (originally SQL:2011) around periods and tables with SYSTEM VERSIONING. The 29 | idea is to figure out all the rules that PostgreSQL would like to adopt (there 30 | are some details missing in the standard) and to allow earlier versions of 31 | PostgreSQL to simulate the behavior once the feature is finally integrated. 32 | -------------------------------------------------------------------------------- /sql/periods.sql: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 130000 AS pre_13 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | 4 | /* Run tests as unprivileged user */ 5 | SET ROLE TO periods_unprivileged_user; 6 | 7 | /* Basic period definitions with dates */ 8 | CREATE TABLE basic (val text, s date, e date); 9 | TABLE periods.periods; 10 | SELECT periods.add_period('basic', 'bp', 's', 'e'); 11 | TABLE periods.periods; 12 | SELECT periods.drop_period('basic', 'bp'); 13 | TABLE periods.periods; 14 | SELECT periods.add_period('basic', 'bp', 's', 'e', bounds_check_constraint => 'c'); 15 | TABLE periods.periods; 16 | SELECT periods.drop_period('basic', 'bp', purge => true); 17 | TABLE periods.periods; 18 | SELECT periods.add_period('basic', 'bp', 's', 'e'); 19 | TABLE periods.periods; 20 | /* Test constraints */ 21 | INSERT INTO basic (val, s, e) VALUES ('x', null, null); --fail 22 | INSERT INTO basic (val, s, e) VALUES ('x', '3000-01-01', null); --fail 23 | INSERT INTO basic (val, s, e) VALUES ('x', null, '1000-01-01'); --fail 24 | INSERT INTO basic (val, s, e) VALUES ('x', '3000-01-01', '1000-01-01'); --fail 25 | INSERT INTO basic (val, s, e) VALUES ('x', '1000-01-01', '3000-01-01'); --success 26 | TABLE basic; 27 | /* Test dropping the whole thing */ 28 | DROP TABLE basic; 29 | TABLE periods.periods; 30 | 31 | -------------------------------------------------------------------------------- /debian/copyright: -------------------------------------------------------------------------------- 1 | Format: https://www.debian.org/doc/packaging-manuals/copyright-format/1.0/ 2 | Upstream-Name: periods 3 | Source: https://github.com/xocolatl/periods 4 | 5 | Files: * 6 | Copyright: Portions Copyright (c) 1996-2019, PostgreSQL Global Development Group 7 | Portions Copyright (c) 1994, The Regents of the University of California 8 | License: PostgreSQL 9 | Permission to use, copy, modify, and distribute this software and its 10 | documentation for any purpose, without fee, and without a written agreement 11 | is hereby granted, provided that the above copyright notice and this 12 | paragraph and the following two paragraphs appear in all copies. 13 | . 14 | IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR 15 | DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING 16 | LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS 17 | DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE 18 | POSSIBILITY OF SUCH DAMAGE. 19 | . 20 | THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES, 21 | INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY 22 | AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS 23 | ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO 24 | PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS. 25 | -------------------------------------------------------------------------------- /expected/health_checks_1.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | pre_96 4 | -------- 5 | t 6 | (1 row) 7 | 8 | /* Run tests as unprivileged user */ 9 | SET ROLE TO periods_unprivileged_user; 10 | /* Ensure tables with periods are persistent */ 11 | CREATE UNLOGGED TABLE log (id bigint, s date, e date); 12 | SELECT periods.add_period('log', 'p', 's', 'e'); -- fails 13 | ERROR: table "log" must be persistent 14 | SELECT periods.add_system_time_period('log'); -- fails 15 | ERROR: table "log" must be persistent 16 | ALTER TABLE log SET LOGGED; 17 | SELECT periods.add_period('log', 'p', 's', 'e'); -- passes 18 | add_period 19 | ------------ 20 | t 21 | (1 row) 22 | 23 | SELECT periods.add_system_time_period('log'); -- passes 24 | add_system_time_period 25 | ------------------------ 26 | t 27 | (1 row) 28 | 29 | ALTER TABLE log SET UNLOGGED; -- fails 30 | ERROR: table "log" must remain persistent because it has periods 31 | SELECT periods.add_system_versioning('log'); 32 | NOTICE: history table "log_history" created for "log", be sure to index it properly 33 | add_system_versioning 34 | ----------------------- 35 | 36 | (1 row) 37 | 38 | ALTER TABLE log_history SET UNLOGGED; -- fails 39 | ERROR: history table "log" must remain persistent because it has periods 40 | SELECT periods.drop_system_versioning('log', purge => true); 41 | drop_system_versioning 42 | ------------------------ 43 | t 44 | (1 row) 45 | 46 | DROP TABLE log; 47 | -------------------------------------------------------------------------------- /expected/health_checks.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | pre_96 4 | -------- 5 | f 6 | (1 row) 7 | 8 | /* Run tests as unprivileged user */ 9 | SET ROLE TO periods_unprivileged_user; 10 | /* Ensure tables with periods are persistent */ 11 | CREATE UNLOGGED TABLE log (id bigint, s date, e date); 12 | SELECT periods.add_period('log', 'p', 's', 'e'); -- fails 13 | ERROR: table "log" must be persistent 14 | CONTEXT: PL/pgSQL function periods.add_period(regclass,name,name,name,regtype,name) line 72 at RAISE 15 | SELECT periods.add_system_time_period('log'); -- fails 16 | ERROR: table "log" must be persistent 17 | CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name,name[]) line 74 at RAISE 18 | ALTER TABLE log SET LOGGED; 19 | SELECT periods.add_period('log', 'p', 's', 'e'); -- passes 20 | add_period 21 | ------------ 22 | t 23 | (1 row) 24 | 25 | SELECT periods.add_system_time_period('log'); -- passes 26 | add_system_time_period 27 | ------------------------ 28 | t 29 | (1 row) 30 | 31 | ALTER TABLE log SET UNLOGGED; -- fails 32 | ERROR: table "log" must remain persistent because it has periods 33 | CONTEXT: PL/pgSQL function periods.health_checks() line 15 at RAISE 34 | SELECT periods.add_system_versioning('log'); 35 | NOTICE: history table "log_history" created for "log", be sure to index it properly 36 | add_system_versioning 37 | ----------------------- 38 | 39 | (1 row) 40 | 41 | ALTER TABLE log_history SET UNLOGGED; -- fails 42 | ERROR: history table "log" must remain persistent because it has periods 43 | CONTEXT: PL/pgSQL function periods.health_checks() line 26 at RAISE 44 | SELECT periods.drop_system_versioning('log', purge => true); 45 | drop_system_versioning 46 | ------------------------ 47 | t 48 | (1 row) 49 | 50 | DROP TABLE log; 51 | -------------------------------------------------------------------------------- /sql/unique_foreign.sql: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | 4 | /* Run tests as unprivileged user */ 5 | SET ROLE TO periods_unprivileged_user; 6 | 7 | -- Unique keys are already pretty much guaranteed by the underlying features of 8 | -- PostgreSQL, but test them anyway. 9 | CREATE TABLE uk (id integer, s integer, e integer, CONSTRAINT uk_pkey PRIMARY KEY (id, s, e)); 10 | SELECT periods.add_period('uk', 'p', 's', 'e'); 11 | SELECT periods.add_unique_key('uk', ARRAY['id'], 'p', key_name => 'uk_id_p', unique_constraint => 'uk_pkey'); 12 | TABLE periods.unique_keys; 13 | INSERT INTO uk (id, s, e) VALUES (100, 1, 3), (100, 3, 4), (100, 4, 10); -- success 14 | INSERT INTO uk (id, s, e) VALUES (200, 1, 3), (200, 3, 4), (200, 5, 10); -- success 15 | INSERT INTO uk (id, s, e) VALUES (300, 1, 3), (300, 3, 5), (300, 4, 10); -- fail 16 | 17 | CREATE TABLE fk (id integer, uk_id integer, s integer, e integer, PRIMARY KEY (id)); 18 | SELECT periods.add_period('fk', 'q', 's', 'e'); 19 | SELECT periods.add_foreign_key('fk', ARRAY['uk_id'], 'q', 'uk_id_p', 20 | key_name => 'fk_uk_id_q', 21 | fk_insert_trigger => 'fki', 22 | fk_update_trigger => 'fku', 23 | uk_update_trigger => 'uku', 24 | uk_delete_trigger => 'ukd'); 25 | TABLE periods.foreign_keys; 26 | SELECT periods.drop_foreign_key('fk', 'fk_uk_id_q'); 27 | SELECT periods.add_foreign_key('fk', ARRAY['uk_id'], 'q', 'uk_id_p', key_name => 'fk_uk_id_q'); 28 | TABLE periods.foreign_keys; 29 | 30 | -- INSERT 31 | INSERT INTO fk VALUES (0, 100, 0, 1); -- fail 32 | INSERT INTO fk VALUES (0, 100, 0, 10); -- fail 33 | INSERT INTO fk VALUES (0, 100, 1, 11); -- fail 34 | INSERT INTO fk VALUES (1, 100, 1, 3); -- success 35 | INSERT INTO fk VALUES (2, 100, 1, 10); -- success 36 | -- UPDATE 37 | UPDATE fk SET e = 20 WHERE id = 1; -- fail 38 | UPDATE fk SET e = 6 WHERE id = 1; -- success 39 | UPDATE uk SET s = 2 WHERE (id, s, e) = (100, 1, 3); -- fail 40 | UPDATE uk SET s = 0 WHERE (id, s, e) = (100, 1, 3); -- success 41 | -- DELETE 42 | DELETE FROM uk WHERE (id, s, e) = (100, 3, 4); -- fail 43 | DELETE FROM uk WHERE (id, s, e) = (200, 3, 5); -- success 44 | 45 | DROP TABLE fk; 46 | DROP TABLE uk; 47 | -------------------------------------------------------------------------------- /sql/excluded_columns.sql: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | 4 | /* Run tests as unprivileged user */ 5 | SET ROLE TO periods_unprivileged_user; 6 | 7 | CREATE TABLE excl ( 8 | value text NOT NULL, 9 | null_value integer, 10 | flap text NOT NULL 11 | ); 12 | SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['xmin']); -- fails 13 | SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['none']); -- fails 14 | SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['flap']); -- passes 15 | SELECT periods.add_system_versioning('excl'); 16 | 17 | TABLE periods.periods; 18 | TABLE periods.system_time_periods; 19 | TABLE periods.system_versioning; 20 | 21 | BEGIN; 22 | SELECT CURRENT_TIMESTAMP AS now \gset 23 | INSERT INTO excl (value, flap) VALUES ('hello world', 'off'); 24 | COMMIT; 25 | SELECT value, null_value, flap, system_time_start <> :'now' AS changed FROM excl; 26 | 27 | UPDATE excl SET flap = 'off'; 28 | UPDATE excl SET flap = 'on'; 29 | UPDATE excl SET flap = 'off'; 30 | UPDATE excl SET flap = 'on'; 31 | SELECT value, null_value, flap, system_time_start <> :'now' AS changed FROM excl; 32 | 33 | BEGIN; 34 | SELECT CURRENT_TIMESTAMP AS now2 \gset 35 | UPDATE excl SET value = 'howdy folks!'; 36 | COMMIT; 37 | SELECT value, null_value, flap, system_time_start <> :'now' AS changed FROM excl; 38 | 39 | UPDATE excl SET null_value = 0; 40 | SELECT value, null_value, flap, system_time_start <> :'now2' AS changed FROM excl; 41 | 42 | /* Test directly setting the excluded columns */ 43 | SELECT periods.drop_system_versioning('excl'); 44 | ALTER TABLE excl ADD COLUMN flop text; 45 | ALTER TABLE excl_history ADD COLUMN flop text; 46 | SELECT periods.add_system_versioning('excl'); 47 | 48 | SELECT periods.set_system_time_period_excluded_columns('excl', ARRAY['flap', 'flop']); 49 | TABLE periods.system_time_periods; 50 | UPDATE excl SET flop = 'flop'; 51 | SELECT value, null_value, flap, flop FROM excl; 52 | SELECT value, null_value, flap, flop FROM excl_history ORDER BY system_time_start; 53 | 54 | SELECT periods.drop_system_versioning('excl', drop_behavior => 'CASCADE', purge => true); 55 | DROP TABLE excl; 56 | -------------------------------------------------------------------------------- /CHANGELOG.md: -------------------------------------------------------------------------------- 1 | # Changelog 2 | 3 | All notable changes to this project will be documented in this file. 4 | 5 | The format is based on [Keep a Changelog](https://keepachangelog.com/en/1.0.0/). 6 | 7 | ## [Unreleased] 8 | 9 | ### Added 10 | ### Fixed 11 | 12 | ## [1.2] – 2020-09-21 13 | 14 | ### Added 15 | 16 | - Add Access Control to prevent users from modifying the history. Only the table owner 17 | and superusers can do this because we can't prevent it. 18 | 19 | - Compatibility with PostgreSQL 13 20 | 21 | ### Fixed 22 | 23 | - Use SPI to insert into the history table. They previous way of doing it didn't 24 | update the indexes, leading to wrong results depending on the execution plan. 25 | 26 | Users must REINDEX all indexes on history tables. 27 | 28 | - Ensure all of our functions are `SECURITY DEFINER`. 29 | 30 | - Ensure ownership of history and for-portion objects follow the main table's owner. 31 | 32 | - Quote all identifiers when building queries. 33 | 34 | - Don't use `regprocedure` in our catalogs, they prevent `pg_upgrade` from working. 35 | This reduces functionality a little but, but not being able to upgrade is a 36 | showstopper. 37 | 38 | ## [1.1] – 2020-02-05 39 | 40 | ### Added 41 | 42 | - Add support for excluded columns. These are columns for which 43 | updates do not cause `GENERATED ALWAYS AS ROW START` to change, and 44 | historical rows will not be generated. 45 | 46 | This is not in the standard, but was requested by several people. 47 | 48 | - Cache some query plans in the C code. 49 | 50 | - Describe the proper way to `ALTER` a table with `SYSTEM VERSIONING`. 51 | 52 | ### Fixed 53 | 54 | - Match columns in the main table and the history table by name. This was an 55 | issue if either of the tables had dropped columns. 56 | 57 | - Use the main table's tuple descriptor when there is no mapping necessary with the 58 | history table's tuple descriptor (see previous item). This works around PostgreSQL 59 | bug #16242 where missing attributes are not considered when detecting differences. 60 | 61 | ## [1.0] – 2019-08-25 62 | 63 | ### Added 64 | 65 | - Initial release. Supports all features of the SQL Standard 66 | concerning periods and `SYSTEM VERSIONING`. 67 | 68 | [Unreleased]: https://github.com/xocolatl/periods/compare/v1.2...HEAD 69 | [1.2]: https://github.com/xocolatl/periods/compare/v1.1...v1.2 70 | [1.1]: https://github.com/xocolatl/periods/compare/v1.0...v1.1 71 | [1.0]: https://github.com/xocolatl/periods/releases/tag/v1.0 72 | -------------------------------------------------------------------------------- /sql/drop_protection.sql: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | 4 | /* Run tests as unprivileged user */ 5 | SET ROLE TO periods_unprivileged_user; 6 | 7 | /* Make sure nobody drops the objects we keep track of in our catalogs. */ 8 | 9 | CREATE TYPE integerrange AS RANGE (SUBTYPE = integer); 10 | CREATE TABLE dp ( 11 | id bigint, 12 | s integer, 13 | e integer, 14 | x boolean 15 | ); 16 | 17 | /* periods */ 18 | SELECT periods.add_period('dp', 'p', 's', 'e', 'integerrange'); 19 | DROP TYPE integerrange; 20 | 21 | /* system_time_periods */ 22 | SELECT periods.add_system_time_period('dp', excluded_column_names => ARRAY['x']); 23 | ALTER TABLE dp DROP COLUMN x; -- fails 24 | ALTER TABLE dp DROP CONSTRAINT dp_system_time_end_infinity_check; -- fails 25 | DROP TRIGGER dp_system_time_generated_always ON dp; -- fails 26 | DROP TRIGGER dp_system_time_write_history ON dp; -- fails 27 | DROP TRIGGER dp_truncate ON dp; -- fails 28 | 29 | /* for_portion_views */ 30 | ALTER TABLE dp ADD CONSTRAINT dp_pkey PRIMARY KEY (id); 31 | SELECT periods.add_for_portion_view('dp', 'p'); 32 | DROP VIEW dp__for_portion_of_p; 33 | DROP TRIGGER for_portion_of_p ON dp__for_portion_of_p; 34 | ALTER TABLE dp DROP CONSTRAINT dp_pkey; 35 | SELECT periods.drop_for_portion_view('dp', 'p'); 36 | ALTER TABLE dp DROP CONSTRAINT dp_pkey; 37 | 38 | /* unique_keys */ 39 | ALTER TABLE dp 40 | ADD CONSTRAINT u UNIQUE (id, s, e), 41 | ADD CONSTRAINT x EXCLUDE USING gist (id WITH =, integerrange(s, e, '[)') WITH &&); 42 | SELECT periods.add_unique_key('dp', ARRAY['id'], 'p', 'k', 'u', 'x'); 43 | ALTER TABLE dp DROP CONSTRAINT u; -- fails 44 | ALTER TABLE dp DROP CONSTRAINT x; -- fails 45 | ALTER TABLE dp DROP CONSTRAINT dp_p_check; -- fails 46 | 47 | /* foreign_keys */ 48 | CREATE TABLE dp_ref (LIKE dp); 49 | SELECT periods.add_period('dp_ref', 'p', 's', 'e', 'integerrange'); 50 | SELECT periods.add_foreign_key('dp_ref', ARRAY['id'], 'p', 'k', key_name => 'f'); 51 | DROP TRIGGER f_fk_insert ON dp_ref; -- fails 52 | DROP TRIGGER f_fk_update ON dp_ref; -- fails 53 | DROP TRIGGER f_uk_update ON dp; -- fails 54 | DROP TRIGGER f_uk_delete ON dp; -- fails 55 | SELECT periods.drop_foreign_key('dp_ref', 'f'); 56 | DROP TABLE dp_ref; 57 | 58 | /* system_versioning */ 59 | SELECT periods.add_system_versioning('dp'); 60 | -- Note: The history table is protected by the history view and the history 61 | -- view is protected by the temporal functions. 62 | DROP TABLE dp_history CASCADE; 63 | DROP VIEW dp_with_history CASCADE; 64 | DROP FUNCTION dp__as_of(timestamp with time zone); 65 | DROP FUNCTION dp__between(timestamp with time zone,timestamp with time zone); 66 | DROP FUNCTION dp__between_symmetric(timestamp with time zone,timestamp with time zone); 67 | DROP FUNCTION dp__from_to(timestamp with time zone,timestamp with time zone); 68 | SELECT periods.drop_system_versioning('dp', purge => true); 69 | 70 | DROP TABLE dp; 71 | DROP TYPE integerrange; 72 | -------------------------------------------------------------------------------- /debian/changelog: -------------------------------------------------------------------------------- 1 | postgresql-periods (1.2.3-2) unstable; urgency=medium 2 | 3 | * Upload for PostgreSQL 18. (Closes: #1117324) 4 | * Add ${postgresql:Breaks}. 5 | * debian/tests: Depend on postgresql-common-dev instead of 'make'. 6 | 7 | -- Christoph Berg Wed, 08 Oct 2025 19:43:26 +0200 8 | 9 | postgresql-periods (1.2.3-1) unstable; urgency=medium 10 | 11 | * New upstream version. 12 | * Upload for PostgreSQL 17. 13 | * Restrict to 64-bit architectures. 14 | * Mark postgresql-all as . 15 | 16 | -- Christoph Berg Sat, 14 Sep 2024 23:33:38 +0200 17 | 18 | postgresql-periods (1.2.2-2) unstable; urgency=medium 19 | 20 | * Upload for PostgreSQL 16. 21 | * Use ${postgresql:Depends}. 22 | 23 | -- Christoph Berg Mon, 18 Sep 2023 21:31:15 +0200 24 | 25 | postgresql-periods (1.2.2-1) unstable; urgency=medium 26 | 27 | * Upload for PostgreSQL 15. 28 | 29 | -- Christoph Berg Mon, 24 Oct 2022 16:03:45 +0200 30 | 31 | postgresql-periods (1.2.1-1) unstable; urgency=medium 32 | 33 | * New version with PG 15 support. 34 | 35 | -- Christoph Berg Wed, 28 Sep 2022 13:33:57 +0200 36 | 37 | postgresql-periods (1.2-4) unstable; urgency=medium 38 | 39 | * Upload for PostgreSQL 14. 40 | 41 | -- Christoph Berg Thu, 21 Oct 2021 09:58:19 +0200 42 | 43 | postgresql-periods (1.2-3) unstable; urgency=medium 44 | 45 | * Depend on postgresql-contrib-PGVERSION for btree_gist on 9.x. 46 | 47 | -- Christoph Berg Fri, 06 Nov 2020 13:27:51 +0100 48 | 49 | postgresql-periods (1.2-2) unstable; urgency=medium 50 | 51 | * Upload for PostgreSQL 13. 52 | * R³: no. 53 | * debian/tests: Use 'make' instead of postgresql-server-dev-all. 54 | 55 | -- Christoph Berg Mon, 19 Oct 2020 15:39:38 +0200 56 | 57 | postgresql-periods (1.2-1) unstable; urgency=medium 58 | 59 | * New upstream version. 60 | * DH 13. 61 | * Use dh --with pgxs. 62 | 63 | -- Christoph Berg Wed, 30 Sep 2020 16:43:33 +0200 64 | 65 | postgresql-periods (1.1-1) unstable; urgency=medium 66 | 67 | * New upstream version. 68 | 69 | -- Christoph Berg Wed, 05 Feb 2020 13:07:16 +0100 70 | 71 | postgresql-periods (1.0-2) unstable; urgency=medium 72 | 73 | * Upload for PostgreSQL 12. 74 | 75 | -- Christoph Berg Thu, 31 Oct 2019 12:59:23 +0100 76 | 77 | postgresql-periods (1.0-1) unstable; urgency=medium 78 | 79 | * New upstream version. 80 | * Rename source package to postgresql-periods. 81 | 82 | -- Christoph Berg Mon, 26 Aug 2019 12:08:01 +0200 83 | 84 | periods (0.04-1) unstable; urgency=medium 85 | 86 | * New upstream version. 87 | 88 | -- Christoph Berg Wed, 31 Jul 2019 10:34:51 +0200 89 | 90 | periods (0.03-1) unstable; urgency=medium 91 | 92 | * Initial release. 93 | 94 | -- Christoph Berg Wed, 17 Jul 2019 12:54:33 +0200 95 | -------------------------------------------------------------------------------- /sql/issues.sql: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 100000 AS pre_10 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | 4 | /* Run tests as unprivileged user */ 5 | SET ROLE TO periods_unprivileged_user; 6 | 7 | /* https://github.com/xocolatl/periods/issues/5 */ 8 | 9 | CREATE TABLE issue5 ( 10 | id integer GENERATED ALWAYS AS IDENTITY PRIMARY KEY, 11 | value VARCHAR NOT NULL 12 | ); 13 | 14 | CREATE TABLE IF NOT EXISTS issue5 ( 15 | id serial PRIMARY KEY, 16 | value VARCHAR NOT NULL 17 | ); 18 | 19 | ALTER TABLE issue5 20 | DROP COLUMN value; 21 | 22 | ALTER TABLE issue5 23 | ADD COLUMN value2 varchar NOT NULL; 24 | 25 | INSERT INTO issue5 (value2) 26 | VALUES ('hello'), ('world'); 27 | 28 | SELECT periods.add_system_time_period ('issue5'); 29 | SELECT periods.add_system_versioning ('issue5'); 30 | 31 | BEGIN; 32 | 33 | SELECT now() AS ts \gset 34 | 35 | UPDATE issue5 36 | SET value2 = 'goodbye' 37 | WHERE id = 2; 38 | 39 | SELECT id, value2, system_time_start, system_time_end 40 | FROM issue5_with_history 41 | EXCEPT ALL 42 | VALUES (1::integer, 'hello'::varchar, '-infinity'::timestamptz, 'infinity'::timestamptz), 43 | (2, 'goodbye', :'ts', 'infinity'), 44 | (2, 'world', '-infinity', :'ts'); 45 | 46 | COMMIT; 47 | 48 | SELECT periods.drop_system_versioning('issue5', drop_behavior => 'CASCADE', purge => true); 49 | DROP TABLE issue5; 50 | 51 | /* Check PostgreSQL Bug #16242 */ 52 | CREATE TABLE pg16242 (value text); 53 | INSERT INTO pg16242 (value) VALUES ('helloworld'); 54 | SELECT periods.add_system_time_period('pg16242'); 55 | SELECT periods.add_system_versioning('pg16242'); 56 | UPDATE pg16242 SET value = 'hello world'; 57 | SELECT system_time_start FROM pg16242_history; 58 | SELECT periods.drop_system_versioning('pg16242', drop_behavior => 'CASCADE', purge => true); 59 | DROP TABLE pg16242; 60 | 61 | /* https://github.com/xocolatl/periods/issues/11 */ 62 | 63 | CREATE TABLE "issue11" ( 64 | "id" BIGINT GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, 65 | "revision" INTEGER NOT NULL 66 | ); 67 | -- for versions pre-10: 68 | CREATE TABLE "issue11" ( 69 | "id" bigserial PRIMARY KEY, 70 | "revision" INTEGER NOT NULL 71 | ); 72 | 73 | SELECT periods.add_system_time_period('issue11', 'row_start_time', 'row_end_time'); 74 | SELECT periods.add_system_versioning('issue11'); 75 | 76 | INSERT INTO "issue11" ("revision") VALUES (1); 77 | INSERT INTO "issue11" ("revision") VALUES (10); 78 | 79 | UPDATE "issue11" SET "revision" = 2 WHERE ("id" = 1); 80 | UPDATE "issue11" SET "revision" = 3 WHERE ("id" = 1); 81 | 82 | CREATE INDEX "yolo" ON "issue11_history" ("id", "revision"); 83 | 84 | UPDATE "issue11" SET "revision" = 11 WHERE ("id" = 2); 85 | 86 | -- returns 2 rows 87 | SELECT id, revision FROM "issue11_history" WHERE "id" = 1 ORDER BY row_start_time; 88 | 89 | -- returns 0 rows if index is used / 1 row if seq scan is used 90 | SELECT id, revision FROM "issue11_history" WHERE "id" = 2 ORDER BY row_start_time; 91 | SET enable_seqscan = off; 92 | SELECT id, revision FROM "issue11_history" WHERE "id" = 2 ORDER BY row_start_time; 93 | RESET enable_seqscan; 94 | 95 | SELECT periods.drop_system_versioning('issue11', drop_behavior => 'CASCADE', purge => true); 96 | DROP TABLE "issue11"; 97 | -------------------------------------------------------------------------------- /sql/rename_following.sql: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | 4 | /* Run tests as unprivileged user */ 5 | SET ROLE TO periods_unprivileged_user; 6 | 7 | /* 8 | * If anything we store as "name" is renamed, we need to update our catalogs or 9 | * throw an error. 10 | */ 11 | 12 | /* periods */ 13 | CREATE TABLE rename_test(col1 text, col2 bigint, col3 time, s integer, e integer); 14 | SELECT periods.add_period('rename_test', 'p', 's', 'e'); 15 | TABLE periods.periods; 16 | ALTER TABLE rename_test RENAME s TO start; 17 | ALTER TABLE rename_test RENAME e TO "end"; 18 | TABLE periods.periods; 19 | ALTER TABLE rename_test RENAME start TO "s < e"; 20 | TABLE periods.periods; 21 | ALTER TABLE rename_test RENAME "end" TO "embedded "" symbols"; 22 | TABLE periods.periods; 23 | ALTER TABLE rename_test RENAME CONSTRAINT rename_test_p_check TO start_before_end; 24 | TABLE periods.periods; 25 | 26 | /* system_time_periods */ 27 | SELECT periods.add_system_time_period('rename_test', excluded_column_names => ARRAY['col3']); 28 | TABLE periods.system_time_periods; 29 | ALTER TABLE rename_test RENAME col3 TO "COLUMN3"; 30 | ALTER TABLE rename_test RENAME CONSTRAINT rename_test_system_time_end_infinity_check TO inf_check; 31 | ALTER TRIGGER rename_test_system_time_generated_always ON rename_test RENAME TO generated_always; 32 | ALTER TRIGGER rename_test_system_time_write_history ON rename_test RENAME TO write_history; 33 | ALTER TRIGGER rename_test_truncate ON rename_test RENAME TO trunc; 34 | TABLE periods.system_time_periods; 35 | 36 | /* for_portion_views */ 37 | ALTER TABLE rename_test ADD COLUMN id integer PRIMARY KEY; 38 | SELECT periods.add_for_portion_view('rename_test', 'p'); 39 | TABLE periods.for_portion_views; 40 | ALTER TRIGGER for_portion_of_p ON rename_test__for_portion_of_p RENAME TO portion_trigger; 41 | TABLE periods.for_portion_views; 42 | SELECT periods.drop_for_portion_view('rename_test', 'p'); 43 | ALTER TABLE rename_test DROP COLUMN id; 44 | 45 | /* unique_keys */ 46 | SELECT periods.add_unique_key('rename_test', ARRAY['col2', 'col1', 'col3'], 'p'); 47 | TABLE periods.unique_keys; 48 | ALTER TABLE rename_test RENAME COLUMN col1 TO "COLUMN1"; 49 | ALTER TABLE rename_test RENAME CONSTRAINT "rename_test_col2_col1_col3_s < e_embedded "" symbols_key" TO unconst; 50 | ALTER TABLE rename_test RENAME CONSTRAINT rename_test_col2_col1_col3_int4range_excl TO exconst; 51 | TABLE periods.unique_keys; 52 | 53 | /* foreign_keys */ 54 | CREATE TABLE rename_test_ref (LIKE rename_test); 55 | SELECT periods.add_period('rename_test_ref', 'q', 's < e', 'embedded " symbols'); 56 | SELECT periods.add_foreign_key('rename_test_ref', ARRAY['col2', 'COLUMN1', 'col3'], 'q', 'rename_test_col2_col1_col3_p'); 57 | TABLE periods.foreign_keys; 58 | ALTER TABLE rename_test_ref RENAME COLUMN "COLUMN1" TO col1; -- fails 59 | ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_fk_insert" ON rename_test_ref RENAME TO fk_insert; 60 | ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_fk_update" ON rename_test_ref RENAME TO fk_update; 61 | ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_uk_update" ON rename_test RENAME TO uk_update; 62 | ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_uk_delete" ON rename_test RENAME TO uk_delete; 63 | TABLE periods.foreign_keys; 64 | DROP TABLE rename_test_ref; 65 | 66 | /* system_versioning */ 67 | SELECT periods.add_system_versioning('rename_test'); 68 | ALTER FUNCTION rename_test__as_of(timestamp with time zone) RENAME TO bumble_bee; 69 | ALTER FUNCTION rename_test__between(timestamp with time zone, timestamp with time zone) RENAME TO bumble_bee; 70 | ALTER FUNCTION rename_test__between_symmetric(timestamp with time zone, timestamp with time zone) RENAME TO bumble_bee; 71 | ALTER FUNCTION rename_test__from_to(timestamp with time zone, timestamp with time zone) RENAME TO bumble_bee; 72 | SELECT periods.drop_system_versioning('rename_test', purge => true); 73 | 74 | DROP TABLE rename_test; 75 | -------------------------------------------------------------------------------- /sql/for_portion_of.sql: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 100000 AS pre_10, 2 | setting::integer < 120000 AS pre_12 3 | FROM pg_settings WHERE name = 'server_version_num'; 4 | 5 | /* Run tests as unprivileged user */ 6 | SET ROLE TO periods_unprivileged_user; 7 | 8 | /* 9 | * Create a sequence to test non-serial primary keys. This actually tests 10 | * things like uuid primary keys, but makes for reproducible test cases. 11 | */ 12 | CREATE SEQUENCE pricing_seq; 13 | 14 | CREATE TABLE pricing (id1 bigserial, 15 | id2 bigint PRIMARY KEY DEFAULT nextval('pricing_seq'), 16 | id3 bigint GENERATED ALWAYS AS IDENTITY, 17 | id4 bigint GENERATED ALWAYS AS (id1 + id2) STORED, 18 | product text, min_quantity integer, max_quantity integer, price numeric); 19 | CREATE TABLE pricing (id1 bigserial, 20 | id2 bigint PRIMARY KEY DEFAULT nextval('pricing_seq'), 21 | id3 bigint GENERATED ALWAYS AS IDENTITY, 22 | product text, min_quantity integer, max_quantity integer, price numeric); 23 | CREATE TABLE pricing (id1 bigserial, 24 | id2 bigint PRIMARY KEY DEFAULT nextval('pricing_seq'), 25 | product text, min_quantity integer, max_quantity integer, price numeric); 26 | SELECT periods.add_period('pricing', 'quantities', 'min_quantity', 'max_quantity'); 27 | SELECT periods.add_for_portion_view('pricing', 'quantities'); 28 | TABLE periods.for_portion_views; 29 | /* Test UPDATE FOR PORTION */ 30 | INSERT INTO pricing (product, min_quantity, max_quantity, price) VALUES ('Trinket', 1, 20, 200); 31 | TABLE pricing ORDER BY min_quantity; 32 | -- UPDATE fully preceding 33 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 0, max_quantity = 1, price = 0; 34 | TABLE pricing ORDER BY min_quantity; 35 | -- UPDATE fully succeeding 36 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 30, max_quantity = 50, price = 0; 37 | TABLE pricing ORDER BY min_quantity; 38 | -- UPDATE fully surrounding 39 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 0, max_quantity = 100, price = 100; 40 | TABLE pricing ORDER BY min_quantity; 41 | -- UPDATE portion 42 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 10, max_quantity = 20, price = 80; 43 | TABLE pricing ORDER BY min_quantity; 44 | -- UPDATE portion of multiple rows 45 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 5, max_quantity = 15, price = 90; 46 | TABLE pricing ORDER BY min_quantity; 47 | -- If we drop the period (without CASCADE) then the FOR PORTION views should be 48 | -- dropped, too. 49 | SELECT periods.drop_period('pricing', 'quantities'); 50 | TABLE periods.for_portion_views; 51 | -- Add it back to test the drop_for_portion_view function 52 | SELECT periods.add_period('pricing', 'quantities', 'min_quantity', 'max_quantity'); 53 | SELECT periods.add_for_portion_view('pricing', 'quantities'); 54 | -- We can't drop the the table without first dropping the FOR PORTION views 55 | -- because Postgres will complain about dependant objects (our views) before we 56 | -- get a chance to clean them up. 57 | DROP TABLE pricing; 58 | SELECT periods.drop_for_portion_view('pricing', NULL); 59 | TABLE periods.for_portion_views; 60 | DROP TABLE pricing; 61 | DROP SEQUENCE pricing_seq; 62 | 63 | /* Types without btree must be excluded, too */ 64 | -- v10+ 65 | CREATE TABLE bt ( 66 | id integer PRIMARY KEY GENERATED ALWAYS AS IDENTITY, 67 | pt point, -- something without btree 68 | t text, -- something with btree 69 | s integer, 70 | e integer 71 | ); 72 | -- pre v10 73 | CREATE TABLE bt ( 74 | id serial PRIMARY KEY, 75 | pt point, -- something without btree 76 | t text, -- something with btree 77 | s integer, 78 | e integer 79 | ); 80 | SELECT periods.add_period('bt', 'p', 's', 'e'); 81 | SELECT periods.add_for_portion_view('bt', 'p'); 82 | 83 | INSERT INTO bt (pt, t, s, e) VALUES ('(0, 0)', 'sample', 10, 40); 84 | TABLE bt ORDER BY s, e; 85 | UPDATE bt__for_portion_of_p SET t = 'simple', s = 20, e = 30; 86 | TABLE bt ORDER BY s, e; 87 | 88 | SELECT periods.drop_for_portion_view('bt', 'p'); 89 | DROP TABLE bt; 90 | -------------------------------------------------------------------------------- /expected/periods_1.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 130000 AS pre_13 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | pre_13 4 | -------- 5 | t 6 | (1 row) 7 | 8 | /* Run tests as unprivileged user */ 9 | SET ROLE TO periods_unprivileged_user; 10 | /* Basic period definitions with dates */ 11 | CREATE TABLE basic (val text, s date, e date); 12 | TABLE periods.periods; 13 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 14 | ------------+-------------+-------------------+-----------------+------------+------------------------- 15 | (0 rows) 16 | 17 | SELECT periods.add_period('basic', 'bp', 's', 'e'); 18 | add_period 19 | ------------ 20 | t 21 | (1 row) 22 | 23 | TABLE periods.periods; 24 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 25 | ------------+-------------+-------------------+-----------------+------------+------------------------- 26 | basic | bp | s | e | daterange | basic_bp_check 27 | (1 row) 28 | 29 | SELECT periods.drop_period('basic', 'bp'); 30 | drop_period 31 | ------------- 32 | t 33 | (1 row) 34 | 35 | TABLE periods.periods; 36 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 37 | ------------+-------------+-------------------+-----------------+------------+------------------------- 38 | (0 rows) 39 | 40 | SELECT periods.add_period('basic', 'bp', 's', 'e', bounds_check_constraint => 'c'); 41 | add_period 42 | ------------ 43 | t 44 | (1 row) 45 | 46 | TABLE periods.periods; 47 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 48 | ------------+-------------+-------------------+-----------------+------------+------------------------- 49 | basic | bp | s | e | daterange | c 50 | (1 row) 51 | 52 | SELECT periods.drop_period('basic', 'bp', purge => true); 53 | drop_period 54 | ------------- 55 | t 56 | (1 row) 57 | 58 | TABLE periods.periods; 59 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 60 | ------------+-------------+-------------------+-----------------+------------+------------------------- 61 | (0 rows) 62 | 63 | SELECT periods.add_period('basic', 'bp', 's', 'e'); 64 | add_period 65 | ------------ 66 | t 67 | (1 row) 68 | 69 | TABLE periods.periods; 70 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 71 | ------------+-------------+-------------------+-----------------+------------+------------------------- 72 | basic | bp | s | e | daterange | basic_bp_check 73 | (1 row) 74 | 75 | /* Test constraints */ 76 | INSERT INTO basic (val, s, e) VALUES ('x', null, null); --fail 77 | ERROR: null value in column "s" violates not-null constraint 78 | DETAIL: Failing row contains (x, null, null). 79 | INSERT INTO basic (val, s, e) VALUES ('x', '3000-01-01', null); --fail 80 | ERROR: null value in column "e" violates not-null constraint 81 | DETAIL: Failing row contains (x, 01-01-3000, null). 82 | INSERT INTO basic (val, s, e) VALUES ('x', null, '1000-01-01'); --fail 83 | ERROR: null value in column "s" violates not-null constraint 84 | DETAIL: Failing row contains (x, null, 01-01-1000). 85 | INSERT INTO basic (val, s, e) VALUES ('x', '3000-01-01', '1000-01-01'); --fail 86 | ERROR: new row for relation "basic" violates check constraint "basic_bp_check" 87 | DETAIL: Failing row contains (x, 01-01-3000, 01-01-1000). 88 | INSERT INTO basic (val, s, e) VALUES ('x', '1000-01-01', '3000-01-01'); --success 89 | TABLE basic; 90 | val | s | e 91 | -----+------------+------------ 92 | x | 01-01-1000 | 01-01-3000 93 | (1 row) 94 | 95 | /* Test dropping the whole thing */ 96 | DROP TABLE basic; 97 | TABLE periods.periods; 98 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 99 | ------------+-------------+-------------------+-----------------+------------+------------------------- 100 | (0 rows) 101 | 102 | -------------------------------------------------------------------------------- /expected/periods.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 130000 AS pre_13 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | pre_13 4 | -------- 5 | f 6 | (1 row) 7 | 8 | /* Run tests as unprivileged user */ 9 | SET ROLE TO periods_unprivileged_user; 10 | /* Basic period definitions with dates */ 11 | CREATE TABLE basic (val text, s date, e date); 12 | TABLE periods.periods; 13 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 14 | ------------+-------------+-------------------+-----------------+------------+------------------------- 15 | (0 rows) 16 | 17 | SELECT periods.add_period('basic', 'bp', 's', 'e'); 18 | add_period 19 | ------------ 20 | t 21 | (1 row) 22 | 23 | TABLE periods.periods; 24 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 25 | ------------+-------------+-------------------+-----------------+------------+------------------------- 26 | basic | bp | s | e | daterange | basic_bp_check 27 | (1 row) 28 | 29 | SELECT periods.drop_period('basic', 'bp'); 30 | drop_period 31 | ------------- 32 | t 33 | (1 row) 34 | 35 | TABLE periods.periods; 36 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 37 | ------------+-------------+-------------------+-----------------+------------+------------------------- 38 | (0 rows) 39 | 40 | SELECT periods.add_period('basic', 'bp', 's', 'e', bounds_check_constraint => 'c'); 41 | add_period 42 | ------------ 43 | t 44 | (1 row) 45 | 46 | TABLE periods.periods; 47 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 48 | ------------+-------------+-------------------+-----------------+------------+------------------------- 49 | basic | bp | s | e | daterange | c 50 | (1 row) 51 | 52 | SELECT periods.drop_period('basic', 'bp', purge => true); 53 | drop_period 54 | ------------- 55 | t 56 | (1 row) 57 | 58 | TABLE periods.periods; 59 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 60 | ------------+-------------+-------------------+-----------------+------------+------------------------- 61 | (0 rows) 62 | 63 | SELECT periods.add_period('basic', 'bp', 's', 'e'); 64 | add_period 65 | ------------ 66 | t 67 | (1 row) 68 | 69 | TABLE periods.periods; 70 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 71 | ------------+-------------+-------------------+-----------------+------------+------------------------- 72 | basic | bp | s | e | daterange | basic_bp_check 73 | (1 row) 74 | 75 | /* Test constraints */ 76 | INSERT INTO basic (val, s, e) VALUES ('x', null, null); --fail 77 | ERROR: null value in column "s" of relation "basic" violates not-null constraint 78 | DETAIL: Failing row contains (x, null, null). 79 | INSERT INTO basic (val, s, e) VALUES ('x', '3000-01-01', null); --fail 80 | ERROR: null value in column "e" of relation "basic" violates not-null constraint 81 | DETAIL: Failing row contains (x, 01-01-3000, null). 82 | INSERT INTO basic (val, s, e) VALUES ('x', null, '1000-01-01'); --fail 83 | ERROR: null value in column "s" of relation "basic" violates not-null constraint 84 | DETAIL: Failing row contains (x, null, 01-01-1000). 85 | INSERT INTO basic (val, s, e) VALUES ('x', '3000-01-01', '1000-01-01'); --fail 86 | ERROR: new row for relation "basic" violates check constraint "basic_bp_check" 87 | DETAIL: Failing row contains (x, 01-01-3000, 01-01-1000). 88 | INSERT INTO basic (val, s, e) VALUES ('x', '1000-01-01', '3000-01-01'); --success 89 | TABLE basic; 90 | val | s | e 91 | -----+------------+------------ 92 | x | 01-01-1000 | 01-01-3000 93 | (1 row) 94 | 95 | /* Test dropping the whole thing */ 96 | DROP TABLE basic; 97 | TABLE periods.periods; 98 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 99 | ------------+-------------+-------------------+-----------------+------------+------------------------- 100 | (0 rows) 101 | 102 | -------------------------------------------------------------------------------- /periods.vcxproj: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | 5 | Debug 6 | Win32 7 | 8 | 9 | Release 10 | Win32 11 | 12 | 13 | Debug 14 | x64 15 | 16 | 17 | Release 18 | x64 19 | 20 | 21 | 22 | Win32Proj 23 | periods 24 | v141 25 | 11 26 | $(ProgramFiles) 27 | true 28 | DynamicLibrary 29 | $(ProgramW6432) 30 | $(pf)\PostgreSQL\$(pgversion) 31 | {9B904FEA-1564-4CF0-970A-826E43DE2980} 32 | 33 | 34 | 35 | 36 | 37 | true 38 | Unicode 39 | $(pgroot)\include\server\port\win32_msvc;$(pgroot)\include\server\port\win32;$(pgroot)\include\server;$(pgroot)\include;$(IncludePath) 40 | $(pgroot)\lib;$(LibraryPath) 41 | false 42 | 43 | 44 | 45 | true 46 | 47 | 48 | false 49 | 50 | 51 | 52 | DebugSymbolsProjectOutputGroup 53 | 54 | 55 | 56 | Level3 57 | true 58 | CompileAsC 59 | false 60 | AdvancedVectorExtensions2 61 | WIN32;%(PreprocessorDefinitions) 62 | USE_ASSERT_CHECKING;%(PreprocessorDefinitions) 63 | 64 | 65 | Debug 66 | postgres.lib;%(AdditionalDependencies) 67 | true 68 | true 69 | 70 | 71 | 72 | 73 | MaxSpeed 74 | Speed 75 | true 76 | true 77 | AnySuitable 78 | true 79 | 80 | 81 | true 82 | true 83 | 84 | 85 | 86 | 87 | 88 | -------------------------------------------------------------------------------- /sql/system_versioning.sql: -------------------------------------------------------------------------------- 1 | /* 2 | * An alternative file for pre-v12 is necessary because LEAST() and GREATEST() 3 | * were not constant folded. It was actually while writing this extension that 4 | * the lack of optimization was noticed, and subsequently fixed. 5 | * 6 | * https://www.postgresql.org/message-id/flat/c6e8504c-4c43-35fa-6c8f-3c0b80a912cc%402ndquadrant.com 7 | */ 8 | 9 | SELECT setting::integer < 120000 AS pre_12 10 | FROM pg_settings WHERE name = 'server_version_num'; 11 | 12 | /* Run tests as unprivileged user */ 13 | SET ROLE TO periods_unprivileged_user; 14 | 15 | /* Basic SYSTEM VERSIONING */ 16 | 17 | CREATE TABLE sysver (val text, flap boolean); 18 | SELECT periods.add_system_time_period('sysver', excluded_column_names => ARRAY['flap']); 19 | TABLE periods.system_time_periods; 20 | TABLE periods.system_versioning; 21 | SELECT periods.add_system_versioning('sysver', 22 | history_table_name => 'custom_history_name', 23 | view_name => 'custom_view_name', 24 | function_as_of_name => 'custom_as_of', 25 | function_between_name => 'custom_between', 26 | function_between_symmetric_name => 'custom_between_symmetric', 27 | function_from_to_name => 'custom_from_to'); 28 | TABLE periods.system_versioning; 29 | SELECT periods.drop_system_versioning('sysver', drop_behavior => 'CASCADE'); 30 | DROP TABLE custom_history_name; 31 | SELECT periods.add_system_versioning('sysver'); 32 | TABLE periods.system_versioning; 33 | 34 | INSERT INTO sysver (val, flap) VALUES ('hello', false); 35 | SELECT val FROM sysver; 36 | SELECT val FROM sysver_history ORDER BY system_time_start; 37 | 38 | SELECT transaction_timestamp() AS ts1 \gset 39 | 40 | UPDATE sysver SET val = 'world'; 41 | SELECT val FROM sysver; 42 | SELECT val FROM sysver_history ORDER BY system_time_start; 43 | 44 | UPDATE sysver SET flap = not flap; 45 | UPDATE sysver SET flap = not flap; 46 | UPDATE sysver SET flap = not flap; 47 | UPDATE sysver SET flap = not flap; 48 | UPDATE sysver SET flap = not flap; 49 | SELECT val FROM sysver; 50 | SELECT val FROM sysver_history ORDER BY system_time_start; 51 | 52 | SELECT transaction_timestamp() AS ts2 \gset 53 | 54 | DELETE FROM sysver; 55 | SELECT val FROM sysver; 56 | SELECT val FROM sysver_history ORDER BY system_time_start; 57 | 58 | /* temporal queries */ 59 | 60 | SELECT val FROM sysver__as_of(:'ts1') ORDER BY system_time_start; 61 | SELECT val FROM sysver__as_of(:'ts2') ORDER BY system_time_start; 62 | 63 | SELECT val FROM sysver__from_to(:'ts1', :'ts2') ORDER BY system_time_start; 64 | SELECT val FROM sysver__from_to(:'ts2', :'ts1') ORDER BY system_time_start; 65 | 66 | SELECT val FROM sysver__between(:'ts1', :'ts2') ORDER BY system_time_start; 67 | SELECT val FROM sysver__between(:'ts2', :'ts1') ORDER BY system_time_start; 68 | 69 | SELECT val FROM sysver__between_symmetric(:'ts1', :'ts2') ORDER BY system_time_start; 70 | SELECT val FROM sysver__between_symmetric(:'ts2', :'ts1') ORDER BY system_time_start; 71 | 72 | /* Ensure functions are inlined */ 73 | 74 | SET TimeZone = 'UTC'; 75 | SET DateStyle = 'ISO'; 76 | EXPLAIN (COSTS OFF) SELECT * FROM sysver__as_of('2000-01-01'); 77 | EXPLAIN (COSTS OFF) SELECT * FROM sysver__from_to('1000-01-01', '3000-01-01'); 78 | EXPLAIN (COSTS OFF) SELECT * FROM sysver__between('1000-01-01', '3000-01-01'); 79 | EXPLAIN (COSTS OFF) SELECT * FROM sysver__between_symmetric('3000-01-01', '1000-01-01'); 80 | 81 | /* TRUNCATE should delete the history, too */ 82 | SELECT val FROM sysver_with_history; 83 | TRUNCATE sysver; 84 | SELECT val FROM sysver_with_history; --empty 85 | 86 | /* Try modifying several times in a transaction */ 87 | BEGIN; 88 | INSERT INTO sysver (val) VALUES ('hello'); 89 | INSERT INTO sysver (val) VALUES ('world'); 90 | ROLLBACK; 91 | SELECT val FROM sysver_with_history; --empty 92 | 93 | BEGIN; 94 | INSERT INTO sysver (val) VALUES ('hello'); 95 | UPDATE sysver SET val = 'world'; 96 | UPDATE sysver SET val = 'world2'; 97 | UPDATE sysver SET val = 'world3'; 98 | DELETE FROM sysver; 99 | COMMIT; 100 | SELECT val FROM sysver_with_history; --empty 101 | 102 | -- We can't drop the the table without first dropping SYSTEM VERSIONING because 103 | -- Postgres will complain about dependant objects (our view functions) before 104 | -- we get a chance to clean them up. 105 | DROP TABLE sysver; 106 | SELECT periods.drop_system_versioning('sysver', drop_behavior => 'CASCADE', purge => true); 107 | TABLE periods.system_versioning; 108 | DROP TABLE sysver; 109 | TABLE periods.periods; 110 | TABLE periods.system_time_periods; 111 | -------------------------------------------------------------------------------- /sql/predicates.sql: -------------------------------------------------------------------------------- 1 | /* Run tests as unprivileged user */ 2 | SET ROLE TO periods_unprivileged_user; 3 | 4 | CREATE TABLE preds (s integer, e integer); 5 | SELECT periods.add_period('preds', 'p', 's', 'e'); 6 | 7 | INSERT INTO preds (s, e) VALUES (100, 200); 8 | ANALYZE preds; 9 | 10 | /* Ensure the functions are inlined. */ 11 | 12 | EXPLAIN (COSTS OFF) SELECT * FROM preds WHERE periods.contains(s, e, 100); 13 | EXPLAIN (COSTS OFF) SELECT * FROM preds WHERE periods.contains(s, e, 100, 200); 14 | EXPLAIN (COSTS OFF) SELECT * FROM preds WHERE periods.equals(s, e, 100, 200); 15 | EXPLAIN (COSTS OFF) SELECT * FROM preds WHERE periods.overlaps(s, e, 100, 200); 16 | EXPLAIN (COSTS OFF) SELECT * FROM preds WHERE periods.precedes(s, e, 100, 200); 17 | EXPLAIN (COSTS OFF) SELECT * FROM preds WHERE periods.succeeds(s, e, 100, 200); 18 | EXPLAIN (COSTS OFF) SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 100, 200); 19 | EXPLAIN (COSTS OFF) SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 100, 200); 20 | 21 | /* Now make sure they work! */ 22 | 23 | SELECT * FROM preds WHERE periods.contains(s, e, 0); 24 | SELECT * FROM preds WHERE periods.contains(s, e, 150); 25 | SELECT * FROM preds WHERE periods.contains(s, e, 300); 26 | 27 | SELECT * FROM preds WHERE periods.contains(s, e, 0, 50); 28 | SELECT * FROM preds WHERE periods.contains(s, e, 50, 100); 29 | SELECT * FROM preds WHERE periods.contains(s, e, 100, 150); 30 | SELECT * FROM preds WHERE periods.contains(s, e, 150, 200); 31 | SELECT * FROM preds WHERE periods.contains(s, e, 200, 250); 32 | SELECT * FROM preds WHERE periods.contains(s, e, 250, 300); 33 | SELECT * FROM preds WHERE periods.contains(s, e, 125, 175); 34 | SELECT * FROM preds WHERE periods.contains(s, e, 0, 300); 35 | 36 | SELECT * FROM preds WHERE periods.equals(s, e, 0, 100); 37 | SELECT * FROM preds WHERE periods.equals(s, e, 100, 200); 38 | SELECT * FROM preds WHERE periods.equals(s, e, 200, 300); 39 | 40 | SELECT * FROM preds WHERE periods.overlaps(s, e, 0, 50); 41 | SELECT * FROM preds WHERE periods.overlaps(s, e, 50, 100); 42 | SELECT * FROM preds WHERE periods.overlaps(s, e, 100, 150); 43 | SELECT * FROM preds WHERE periods.overlaps(s, e, 150, 200); 44 | SELECT * FROM preds WHERE periods.overlaps(s, e, 200, 250); 45 | SELECT * FROM preds WHERE periods.overlaps(s, e, 250, 300); 46 | SELECT * FROM preds WHERE periods.overlaps(s, e, 125, 175); 47 | SELECT * FROM preds WHERE periods.overlaps(s, e, 0, 300); 48 | 49 | SELECT * FROM preds WHERE periods.precedes(s, e, 0, 50); 50 | SELECT * FROM preds WHERE periods.precedes(s, e, 50, 100); 51 | SELECT * FROM preds WHERE periods.precedes(s, e, 100, 150); 52 | SELECT * FROM preds WHERE periods.precedes(s, e, 150, 200); 53 | SELECT * FROM preds WHERE periods.precedes(s, e, 200, 250); 54 | SELECT * FROM preds WHERE periods.precedes(s, e, 250, 300); 55 | SELECT * FROM preds WHERE periods.precedes(s, e, 125, 175); 56 | SELECT * FROM preds WHERE periods.precedes(s, e, 0, 300); 57 | 58 | SELECT * FROM preds WHERE periods.succeeds(s, e, 0, 50); 59 | SELECT * FROM preds WHERE periods.succeeds(s, e, 50, 100); 60 | SELECT * FROM preds WHERE periods.succeeds(s, e, 100, 150); 61 | SELECT * FROM preds WHERE periods.succeeds(s, e, 150, 200); 62 | SELECT * FROM preds WHERE periods.succeeds(s, e, 200, 250); 63 | SELECT * FROM preds WHERE periods.succeeds(s, e, 250, 300); 64 | SELECT * FROM preds WHERE periods.succeeds(s, e, 125, 175); 65 | SELECT * FROM preds WHERE periods.succeeds(s, e, 0, 300); 66 | 67 | SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 0, 50); 68 | SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 50, 100); 69 | SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 100, 150); 70 | SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 150, 200); 71 | SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 200, 250); 72 | SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 250, 300); 73 | SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 125, 175); 74 | SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 0, 300); 75 | 76 | SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 0, 50); 77 | SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 50, 100); 78 | SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 100, 150); 79 | SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 150, 200); 80 | SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 200, 250); 81 | SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 250, 300); 82 | SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 125, 175); 83 | SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 0, 300); 84 | 85 | DROP TABLE preds; 86 | -------------------------------------------------------------------------------- /expected/issues.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 100000 AS pre_10 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | pre_10 4 | -------- 5 | f 6 | (1 row) 7 | 8 | /* Run tests as unprivileged user */ 9 | SET ROLE TO periods_unprivileged_user; 10 | /* https://github.com/xocolatl/periods/issues/5 */ 11 | CREATE TABLE issue5 ( 12 | id integer GENERATED ALWAYS AS IDENTITY PRIMARY KEY, 13 | value VARCHAR NOT NULL 14 | ); 15 | CREATE TABLE IF NOT EXISTS issue5 ( 16 | id serial PRIMARY KEY, 17 | value VARCHAR NOT NULL 18 | ); 19 | NOTICE: relation "issue5" already exists, skipping 20 | ALTER TABLE issue5 21 | DROP COLUMN value; 22 | ALTER TABLE issue5 23 | ADD COLUMN value2 varchar NOT NULL; 24 | INSERT INTO issue5 (value2) 25 | VALUES ('hello'), ('world'); 26 | SELECT periods.add_system_time_period ('issue5'); 27 | add_system_time_period 28 | ------------------------ 29 | t 30 | (1 row) 31 | 32 | SELECT periods.add_system_versioning ('issue5'); 33 | NOTICE: history table "issue5_history" created for "issue5", be sure to index it properly 34 | add_system_versioning 35 | ----------------------- 36 | 37 | (1 row) 38 | 39 | BEGIN; 40 | SELECT now() AS ts \gset 41 | UPDATE issue5 42 | SET value2 = 'goodbye' 43 | WHERE id = 2; 44 | SELECT id, value2, system_time_start, system_time_end 45 | FROM issue5_with_history 46 | EXCEPT ALL 47 | VALUES (1::integer, 'hello'::varchar, '-infinity'::timestamptz, 'infinity'::timestamptz), 48 | (2, 'goodbye', :'ts', 'infinity'), 49 | (2, 'world', '-infinity', :'ts'); 50 | id | value2 | system_time_start | system_time_end 51 | ----+--------+-------------------+----------------- 52 | (0 rows) 53 | 54 | COMMIT; 55 | SELECT periods.drop_system_versioning('issue5', drop_behavior => 'CASCADE', purge => true); 56 | drop_system_versioning 57 | ------------------------ 58 | t 59 | (1 row) 60 | 61 | DROP TABLE issue5; 62 | /* Check PostgreSQL Bug #16242 */ 63 | CREATE TABLE pg16242 (value text); 64 | INSERT INTO pg16242 (value) VALUES ('helloworld'); 65 | SELECT periods.add_system_time_period('pg16242'); 66 | add_system_time_period 67 | ------------------------ 68 | t 69 | (1 row) 70 | 71 | SELECT periods.add_system_versioning('pg16242'); 72 | NOTICE: history table "pg16242_history" created for "pg16242", be sure to index it properly 73 | add_system_versioning 74 | ----------------------- 75 | 76 | (1 row) 77 | 78 | UPDATE pg16242 SET value = 'hello world'; 79 | SELECT system_time_start FROM pg16242_history; 80 | system_time_start 81 | ------------------- 82 | -infinity 83 | (1 row) 84 | 85 | SELECT periods.drop_system_versioning('pg16242', drop_behavior => 'CASCADE', purge => true); 86 | drop_system_versioning 87 | ------------------------ 88 | t 89 | (1 row) 90 | 91 | DROP TABLE pg16242; 92 | /* https://github.com/xocolatl/periods/issues/11 */ 93 | CREATE TABLE "issue11" ( 94 | "id" BIGINT GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, 95 | "revision" INTEGER NOT NULL 96 | ); 97 | -- for versions pre-10: 98 | CREATE TABLE "issue11" ( 99 | "id" bigserial PRIMARY KEY, 100 | "revision" INTEGER NOT NULL 101 | ); 102 | ERROR: relation "issue11" already exists 103 | SELECT periods.add_system_time_period('issue11', 'row_start_time', 'row_end_time'); 104 | add_system_time_period 105 | ------------------------ 106 | t 107 | (1 row) 108 | 109 | SELECT periods.add_system_versioning('issue11'); 110 | NOTICE: history table "issue11_history" created for "issue11", be sure to index it properly 111 | add_system_versioning 112 | ----------------------- 113 | 114 | (1 row) 115 | 116 | INSERT INTO "issue11" ("revision") VALUES (1); 117 | INSERT INTO "issue11" ("revision") VALUES (10); 118 | UPDATE "issue11" SET "revision" = 2 WHERE ("id" = 1); 119 | UPDATE "issue11" SET "revision" = 3 WHERE ("id" = 1); 120 | CREATE INDEX "yolo" ON "issue11_history" ("id", "revision"); 121 | UPDATE "issue11" SET "revision" = 11 WHERE ("id" = 2); 122 | -- returns 2 rows 123 | SELECT id, revision FROM "issue11_history" WHERE "id" = 1 ORDER BY row_start_time; 124 | id | revision 125 | ----+---------- 126 | 1 | 1 127 | 1 | 2 128 | (2 rows) 129 | 130 | -- returns 0 rows if index is used / 1 row if seq scan is used 131 | SELECT id, revision FROM "issue11_history" WHERE "id" = 2 ORDER BY row_start_time; 132 | id | revision 133 | ----+---------- 134 | 2 | 10 135 | (1 row) 136 | 137 | SET enable_seqscan = off; 138 | SELECT id, revision FROM "issue11_history" WHERE "id" = 2 ORDER BY row_start_time; 139 | id | revision 140 | ----+---------- 141 | 2 | 10 142 | (1 row) 143 | 144 | RESET enable_seqscan; 145 | SELECT periods.drop_system_versioning('issue11', drop_behavior => 'CASCADE', purge => true); 146 | drop_system_versioning 147 | ------------------------ 148 | t 149 | (1 row) 150 | 151 | DROP TABLE "issue11"; 152 | -------------------------------------------------------------------------------- /sql/system_time_periods.sql: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | 4 | /* Run tests as unprivileged user */ 5 | SET ROLE TO periods_unprivileged_user; 6 | 7 | /* SYSTEM_TIME with date */ 8 | 9 | BEGIN; 10 | SELECT transaction_timestamp()::date AS xd, 11 | transaction_timestamp()::timestamp AS xts, 12 | transaction_timestamp() AS xtstz 13 | \gset 14 | 15 | CREATE TABLE sysver_date (val text, start_date date, end_date date); 16 | SELECT periods.add_system_time_period('sysver_date', 'start_date', 'end_date'); 17 | TABLE periods.periods; 18 | INSERT INTO sysver_date DEFAULT VALUES; 19 | SELECT val, start_date = :'xd' AS start_date_eq, end_date FROM sysver_date; 20 | DROP TABLE sysver_date; 21 | 22 | /* SYSTEM_TIME with timestamp without time zone */ 23 | 24 | CREATE TABLE sysver_ts (val text, start_ts timestamp without time zone, end_ts timestamp without time zone); 25 | SELECT periods.add_system_time_period('sysver_ts', 'start_ts', 'end_ts'); 26 | TABLE periods.periods; 27 | INSERT INTO sysver_ts DEFAULT VALUES; 28 | SELECT val, start_ts = :'xts' AS start_ts_eq, end_ts FROM sysver_ts; 29 | DROP TABLE sysver_ts; 30 | 31 | /* SYSTEM_TIME with timestamp with time zone */ 32 | 33 | CREATE TABLE sysver_tstz (val text, start_tstz timestamp with time zone, end_tstz timestamp with time zone); 34 | SELECT periods.add_system_time_period('sysver_tstz', 'start_tstz', 'end_tstz'); 35 | TABLE periods.periods; 36 | INSERT INTO sysver_tstz DEFAULT VALUES; 37 | SELECT val, start_tstz = :'xtstz' AS start_tstz_eq, end_tstz FROM sysver_tstz; 38 | DROP TABLE sysver_tstz; 39 | 40 | COMMIT; 41 | 42 | 43 | /* Basic SYSTEM_TIME periods with CASCADE/purge */ 44 | 45 | CREATE TABLE sysver (val text); 46 | SELECT periods.add_system_time_period('sysver', 'startname'); 47 | SELECT periods.drop_period('sysver', 'system_time', drop_behavior => 'CASCADE', purge => true); 48 | SELECT periods.add_system_time_period('sysver', end_column_name => 'endname'); 49 | SELECT periods.drop_period('sysver', 'system_time', drop_behavior => 'CASCADE', purge => true); 50 | SELECT periods.add_system_time_period('sysver', 'startname', 'endname'); 51 | TABLE periods.periods; 52 | TABLE periods.system_time_periods; 53 | SELECT periods.drop_system_time_period('sysver', drop_behavior => 'CASCADE', purge => true); 54 | SELECT periods.add_system_time_period('sysver', 'endname', 'startname', 55 | bounds_check_constraint => 'b', 56 | infinity_check_constraint => 'i', 57 | generated_always_trigger => 'g', 58 | write_history_trigger => 'w', 59 | truncate_trigger => 't'); 60 | TABLE periods.periods; 61 | TABLE periods.system_time_periods; 62 | SELECT periods.drop_system_time_period('sysver', drop_behavior => 'CASCADE', purge => true); 63 | SELECT periods.add_system_time_period('sysver'); 64 | DROP TABLE sysver; 65 | TABLE periods.periods; 66 | TABLE periods.system_time_periods; 67 | 68 | 69 | /* Forbid UNIQUE keys on system_time columns */ 70 | CREATE TABLE no_unique (col1 timestamp with time zone, s bigint, e bigint); 71 | SELECT periods.add_period('no_unique', 'p', 's', 'e'); 72 | SELECT periods.add_unique_key('no_unique', ARRAY['col1'], 'p'); -- passes 73 | SELECT periods.add_system_time_period('no_unique'); 74 | SELECT periods.add_unique_key('no_unique', ARRAY['system_time_start'], 'p'); -- fails 75 | SELECT periods.add_unique_key('no_unique', ARRAY['system_time_end'], 'p'); -- fails 76 | SELECT periods.add_unique_key('no_unique', ARRAY['col1'], 'system_time'); -- fails 77 | SELECT periods.drop_system_time_period('no_unique'); 78 | SELECT periods.add_unique_key('no_unique', ARRAY['system_time_start'], 'p'); -- passes 79 | SELECT periods.add_unique_key('no_unique', ARRAY['system_time_end'], 'p'); -- passes 80 | SELECT periods.add_system_time_period('no_unique'); -- fails 81 | SELECT periods.drop_unique_key('no_unique', 'no_unique_system_time_start_p'); 82 | SELECT periods.drop_unique_key('no_unique', 'no_unique_system_time_end_p'); 83 | /* Forbid foreign keys on system_time columns */ 84 | CREATE TABLE no_unique_ref (LIKE no_unique); 85 | SELECT periods.add_period('no_unique_ref', 'q', 's', 'e'); 86 | SELECT periods.add_system_time_period('no_unique_ref'); 87 | SELECT periods.add_foreign_key('no_unique_ref', ARRAY['system_time_start'], 'q', 'no_unique_col1_p'); -- fails 88 | SELECT periods.add_foreign_key('no_unique_ref', ARRAY['system_time_end'], 'q', 'no_unique_col1_p'); -- fails 89 | SELECT periods.add_foreign_key('no_unique_ref', ARRAY['col1'], 'system_time', 'no_unique_col1_p'); -- fails 90 | SELECT periods.drop_system_time_period('no_unique_ref'); 91 | SELECT periods.add_foreign_key('no_unique_ref', ARRAY['system_time_start'], 'q', 'no_unique_col1_p'); -- passes 92 | SELECT periods.add_foreign_key('no_unique_ref', ARRAY['system_time_end'], 'q', 'no_unique_col1_p'); -- passes 93 | SELECT periods.add_system_time_period('no_unique_ref'); -- fails 94 | DROP TABLE no_unique, no_unique_ref; 95 | -------------------------------------------------------------------------------- /expected/issues_1.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 100000 AS pre_10 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | pre_10 4 | -------- 5 | t 6 | (1 row) 7 | 8 | /* Run tests as unprivileged user */ 9 | SET ROLE TO periods_unprivileged_user; 10 | /* https://github.com/xocolatl/periods/issues/5 */ 11 | CREATE TABLE issue5 ( 12 | id integer GENERATED ALWAYS AS IDENTITY PRIMARY KEY, 13 | value VARCHAR NOT NULL 14 | ); 15 | ERROR: syntax error at or near "GENERATED" 16 | LINE 3: id integer GENERATED ALWAYS AS IDENTITY PRIMARY KEY, 17 | ^ 18 | CREATE TABLE IF NOT EXISTS issue5 ( 19 | id serial PRIMARY KEY, 20 | value VARCHAR NOT NULL 21 | ); 22 | ALTER TABLE issue5 23 | DROP COLUMN value; 24 | ALTER TABLE issue5 25 | ADD COLUMN value2 varchar NOT NULL; 26 | INSERT INTO issue5 (value2) 27 | VALUES ('hello'), ('world'); 28 | SELECT periods.add_system_time_period ('issue5'); 29 | add_system_time_period 30 | ------------------------ 31 | t 32 | (1 row) 33 | 34 | SELECT periods.add_system_versioning ('issue5'); 35 | NOTICE: history table "issue5_history" created for "issue5", be sure to index it properly 36 | add_system_versioning 37 | ----------------------- 38 | 39 | (1 row) 40 | 41 | BEGIN; 42 | SELECT now() AS ts \gset 43 | UPDATE issue5 44 | SET value2 = 'goodbye' 45 | WHERE id = 2; 46 | SELECT id, value2, system_time_start, system_time_end 47 | FROM issue5_with_history 48 | EXCEPT ALL 49 | VALUES (1::integer, 'hello'::varchar, '-infinity'::timestamptz, 'infinity'::timestamptz), 50 | (2, 'goodbye', :'ts', 'infinity'), 51 | (2, 'world', '-infinity', :'ts'); 52 | id | value2 | system_time_start | system_time_end 53 | ----+--------+-------------------+----------------- 54 | (0 rows) 55 | 56 | COMMIT; 57 | SELECT periods.drop_system_versioning('issue5', drop_behavior => 'CASCADE', purge => true); 58 | drop_system_versioning 59 | ------------------------ 60 | t 61 | (1 row) 62 | 63 | DROP TABLE issue5; 64 | /* Check PostgreSQL Bug #16242 */ 65 | CREATE TABLE pg16242 (value text); 66 | INSERT INTO pg16242 (value) VALUES ('helloworld'); 67 | SELECT periods.add_system_time_period('pg16242'); 68 | add_system_time_period 69 | ------------------------ 70 | t 71 | (1 row) 72 | 73 | SELECT periods.add_system_versioning('pg16242'); 74 | NOTICE: history table "pg16242_history" created for "pg16242", be sure to index it properly 75 | add_system_versioning 76 | ----------------------- 77 | 78 | (1 row) 79 | 80 | UPDATE pg16242 SET value = 'hello world'; 81 | SELECT system_time_start FROM pg16242_history; 82 | system_time_start 83 | ------------------- 84 | -infinity 85 | (1 row) 86 | 87 | SELECT periods.drop_system_versioning('pg16242', drop_behavior => 'CASCADE', purge => true); 88 | drop_system_versioning 89 | ------------------------ 90 | t 91 | (1 row) 92 | 93 | DROP TABLE pg16242; 94 | /* https://github.com/xocolatl/periods/issues/11 */ 95 | CREATE TABLE "issue11" ( 96 | "id" BIGINT GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, 97 | "revision" INTEGER NOT NULL 98 | ); 99 | ERROR: syntax error at or near "GENERATED" 100 | LINE 3: "id" BIGINT GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY... 101 | ^ 102 | -- for versions pre-10: 103 | CREATE TABLE "issue11" ( 104 | "id" bigserial PRIMARY KEY, 105 | "revision" INTEGER NOT NULL 106 | ); 107 | SELECT periods.add_system_time_period('issue11', 'row_start_time', 'row_end_time'); 108 | add_system_time_period 109 | ------------------------ 110 | t 111 | (1 row) 112 | 113 | SELECT periods.add_system_versioning('issue11'); 114 | NOTICE: history table "issue11_history" created for "issue11", be sure to index it properly 115 | add_system_versioning 116 | ----------------------- 117 | 118 | (1 row) 119 | 120 | INSERT INTO "issue11" ("revision") VALUES (1); 121 | INSERT INTO "issue11" ("revision") VALUES (10); 122 | UPDATE "issue11" SET "revision" = 2 WHERE ("id" = 1); 123 | UPDATE "issue11" SET "revision" = 3 WHERE ("id" = 1); 124 | CREATE INDEX "yolo" ON "issue11_history" ("id", "revision"); 125 | UPDATE "issue11" SET "revision" = 11 WHERE ("id" = 2); 126 | -- returns 2 rows 127 | SELECT id, revision FROM "issue11_history" WHERE "id" = 1 ORDER BY row_start_time; 128 | id | revision 129 | ----+---------- 130 | 1 | 1 131 | 1 | 2 132 | (2 rows) 133 | 134 | -- returns 0 rows if index is used / 1 row if seq scan is used 135 | SELECT id, revision FROM "issue11_history" WHERE "id" = 2 ORDER BY row_start_time; 136 | id | revision 137 | ----+---------- 138 | 2 | 10 139 | (1 row) 140 | 141 | SET enable_seqscan = off; 142 | SELECT id, revision FROM "issue11_history" WHERE "id" = 2 ORDER BY row_start_time; 143 | id | revision 144 | ----+---------- 145 | 2 | 10 146 | (1 row) 147 | 148 | RESET enable_seqscan; 149 | SELECT periods.drop_system_versioning('issue11', drop_behavior => 'CASCADE', purge => true); 150 | drop_system_versioning 151 | ------------------------ 152 | t 153 | (1 row) 154 | 155 | DROP TABLE "issue11"; 156 | -------------------------------------------------------------------------------- /expected/unique_foreign_1.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | pre_96 4 | -------- 5 | t 6 | (1 row) 7 | 8 | /* Run tests as unprivileged user */ 9 | SET ROLE TO periods_unprivileged_user; 10 | -- Unique keys are already pretty much guaranteed by the underlying features of 11 | -- PostgreSQL, but test them anyway. 12 | CREATE TABLE uk (id integer, s integer, e integer, CONSTRAINT uk_pkey PRIMARY KEY (id, s, e)); 13 | SELECT periods.add_period('uk', 'p', 's', 'e'); 14 | add_period 15 | ------------ 16 | t 17 | (1 row) 18 | 19 | SELECT periods.add_unique_key('uk', ARRAY['id'], 'p', key_name => 'uk_id_p', unique_constraint => 'uk_pkey'); 20 | add_unique_key 21 | ---------------- 22 | uk_id_p 23 | (1 row) 24 | 25 | TABLE periods.unique_keys; 26 | key_name | table_name | column_names | period_name | unique_constraint | exclude_constraint 27 | ----------+------------+--------------+-------------+-------------------+---------------------- 28 | uk_id_p | uk | {id} | p | uk_pkey | uk_id_int4range_excl 29 | (1 row) 30 | 31 | INSERT INTO uk (id, s, e) VALUES (100, 1, 3), (100, 3, 4), (100, 4, 10); -- success 32 | INSERT INTO uk (id, s, e) VALUES (200, 1, 3), (200, 3, 4), (200, 5, 10); -- success 33 | INSERT INTO uk (id, s, e) VALUES (300, 1, 3), (300, 3, 5), (300, 4, 10); -- fail 34 | ERROR: conflicting key value violates exclusion constraint "uk_id_int4range_excl" 35 | DETAIL: Key (id, int4range(s, e, '[)'::text))=(300, [4,10)) conflicts with existing key (id, int4range(s, e, '[)'::text))=(300, [3,5)). 36 | CREATE TABLE fk (id integer, uk_id integer, s integer, e integer, PRIMARY KEY (id)); 37 | SELECT periods.add_period('fk', 'q', 's', 'e'); 38 | add_period 39 | ------------ 40 | t 41 | (1 row) 42 | 43 | SELECT periods.add_foreign_key('fk', ARRAY['uk_id'], 'q', 'uk_id_p', 44 | key_name => 'fk_uk_id_q', 45 | fk_insert_trigger => 'fki', 46 | fk_update_trigger => 'fku', 47 | uk_update_trigger => 'uku', 48 | uk_delete_trigger => 'ukd'); 49 | add_foreign_key 50 | ----------------- 51 | fk_uk_id_q 52 | (1 row) 53 | 54 | TABLE periods.foreign_keys; 55 | key_name | table_name | column_names | period_name | unique_key | match_type | delete_action | update_action | fk_insert_trigger | fk_update_trigger | uk_update_trigger | uk_delete_trigger 56 | ------------+------------+--------------+-------------+------------+------------+---------------+---------------+-------------------+-------------------+-------------------+------------------- 57 | fk_uk_id_q | fk | {uk_id} | q | uk_id_p | SIMPLE | NO ACTION | NO ACTION | fki | fku | uku | ukd 58 | (1 row) 59 | 60 | SELECT periods.drop_foreign_key('fk', 'fk_uk_id_q'); 61 | drop_foreign_key 62 | ------------------ 63 | t 64 | (1 row) 65 | 66 | SELECT periods.add_foreign_key('fk', ARRAY['uk_id'], 'q', 'uk_id_p', key_name => 'fk_uk_id_q'); 67 | add_foreign_key 68 | ----------------- 69 | fk_uk_id_q 70 | (1 row) 71 | 72 | TABLE periods.foreign_keys; 73 | key_name | table_name | column_names | period_name | unique_key | match_type | delete_action | update_action | fk_insert_trigger | fk_update_trigger | uk_update_trigger | uk_delete_trigger 74 | ------------+------------+--------------+-------------+------------+------------+---------------+---------------+----------------------+----------------------+----------------------+---------------------- 75 | fk_uk_id_q | fk | {uk_id} | q | uk_id_p | SIMPLE | NO ACTION | NO ACTION | fk_uk_id_q_fk_insert | fk_uk_id_q_fk_update | fk_uk_id_q_uk_update | fk_uk_id_q_uk_delete 76 | (1 row) 77 | 78 | -- INSERT 79 | INSERT INTO fk VALUES (0, 100, 0, 1); -- fail 80 | ERROR: insert or update on table "fk" violates foreign key constraint "fk_uk_id_q" 81 | CONTEXT: SQL statement "SELECT periods.validate_foreign_key_new_row(TG_ARGV[0], jnew)" 82 | PL/pgSQL function periods.fk_insert_check() line 20 at PERFORM 83 | INSERT INTO fk VALUES (0, 100, 0, 10); -- fail 84 | ERROR: insert or update on table "fk" violates foreign key constraint "fk_uk_id_q" 85 | CONTEXT: SQL statement "SELECT periods.validate_foreign_key_new_row(TG_ARGV[0], jnew)" 86 | PL/pgSQL function periods.fk_insert_check() line 20 at PERFORM 87 | INSERT INTO fk VALUES (0, 100, 1, 11); -- fail 88 | ERROR: insert or update on table "fk" violates foreign key constraint "fk_uk_id_q" 89 | CONTEXT: SQL statement "SELECT periods.validate_foreign_key_new_row(TG_ARGV[0], jnew)" 90 | PL/pgSQL function periods.fk_insert_check() line 20 at PERFORM 91 | INSERT INTO fk VALUES (1, 100, 1, 3); -- success 92 | INSERT INTO fk VALUES (2, 100, 1, 10); -- success 93 | -- UPDATE 94 | UPDATE fk SET e = 20 WHERE id = 1; -- fail 95 | ERROR: insert or update on table "fk" violates foreign key constraint "fk_uk_id_q" 96 | CONTEXT: SQL statement "SELECT periods.validate_foreign_key_new_row(TG_ARGV[0], jnew)" 97 | PL/pgSQL function periods.fk_update_check() line 19 at PERFORM 98 | UPDATE fk SET e = 6 WHERE id = 1; -- success 99 | UPDATE uk SET s = 2 WHERE (id, s, e) = (100, 1, 3); -- fail 100 | ERROR: update or delete on table "uk" violates foreign key constraint "fk_uk_id_q" on table "fk" 101 | CONTEXT: SQL statement "SELECT periods.validate_foreign_key_old_row(TG_ARGV[0], jold, true)" 102 | PL/pgSQL function periods.uk_update_check() line 23 at PERFORM 103 | UPDATE uk SET s = 0 WHERE (id, s, e) = (100, 1, 3); -- success 104 | -- DELETE 105 | DELETE FROM uk WHERE (id, s, e) = (100, 3, 4); -- fail 106 | ERROR: update or delete on table "uk" violates foreign key constraint "fk_uk_id_q" on table "fk" 107 | CONTEXT: SQL statement "SELECT periods.validate_foreign_key_old_row(TG_ARGV[0], jold, false)" 108 | PL/pgSQL function periods.uk_delete_check() line 22 at PERFORM 109 | DELETE FROM uk WHERE (id, s, e) = (200, 3, 5); -- success 110 | DROP TABLE fk; 111 | DROP TABLE uk; 112 | -------------------------------------------------------------------------------- /expected/excluded_columns_1.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | pre_96 4 | -------- 5 | t 6 | (1 row) 7 | 8 | /* Run tests as unprivileged user */ 9 | SET ROLE TO periods_unprivileged_user; 10 | CREATE TABLE excl ( 11 | value text NOT NULL, 12 | null_value integer, 13 | flap text NOT NULL 14 | ); 15 | SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['xmin']); -- fails 16 | ERROR: cannot exclude system column "xmin" 17 | SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['none']); -- fails 18 | ERROR: column "none" does not exist 19 | SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['flap']); -- passes 20 | add_system_time_period 21 | ------------------------ 22 | t 23 | (1 row) 24 | 25 | SELECT periods.add_system_versioning('excl'); 26 | NOTICE: history table "excl_history" created for "excl", be sure to index it properly 27 | add_system_versioning 28 | ----------------------- 29 | 30 | (1 row) 31 | 32 | TABLE periods.periods; 33 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 34 | ------------+-------------+-------------------+-----------------+------------+------------------------- 35 | excl | system_time | system_time_start | system_time_end | tstzrange | excl_system_time_check 36 | (1 row) 37 | 38 | TABLE periods.system_time_periods; 39 | table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names 40 | ------------+-------------+-------------------------------------+-----------------------------------+--------------------------------+------------------+----------------------- 41 | excl | system_time | excl_system_time_end_infinity_check | excl_system_time_generated_always | excl_system_time_write_history | excl_truncate | {flap} 42 | (1 row) 43 | 44 | TABLE periods.system_versioning; 45 | table_name | period_name | history_table_name | view_name | func_as_of | func_between | func_between_symmetric | func_from_to 46 | ------------+-------------+--------------------+-------------------+----------------------------------------------+-------------------------------------------------------------------------+-----------------------------------------------------------------------------------+------------------------------------------------------------------------- 47 | excl | system_time | excl_history | excl_with_history | public.excl__as_of(timestamp with time zone) | public.excl__between(timestamp with time zone,timestamp with time zone) | public.excl__between_symmetric(timestamp with time zone,timestamp with time zone) | public.excl__from_to(timestamp with time zone,timestamp with time zone) 48 | (1 row) 49 | 50 | BEGIN; 51 | SELECT CURRENT_TIMESTAMP AS now \gset 52 | INSERT INTO excl (value, flap) VALUES ('hello world', 'off'); 53 | COMMIT; 54 | SELECT value, null_value, flap, system_time_start <> :'now' AS changed FROM excl; 55 | value | null_value | flap | changed 56 | -------------+------------+------+--------- 57 | hello world | | off | f 58 | (1 row) 59 | 60 | UPDATE excl SET flap = 'off'; 61 | UPDATE excl SET flap = 'on'; 62 | UPDATE excl SET flap = 'off'; 63 | UPDATE excl SET flap = 'on'; 64 | SELECT value, null_value, flap, system_time_start <> :'now' AS changed FROM excl; 65 | value | null_value | flap | changed 66 | -------------+------------+------+--------- 67 | hello world | | on | f 68 | (1 row) 69 | 70 | BEGIN; 71 | SELECT CURRENT_TIMESTAMP AS now2 \gset 72 | UPDATE excl SET value = 'howdy folks!'; 73 | COMMIT; 74 | SELECT value, null_value, flap, system_time_start <> :'now' AS changed FROM excl; 75 | value | null_value | flap | changed 76 | --------------+------------+------+--------- 77 | howdy folks! | | on | t 78 | (1 row) 79 | 80 | UPDATE excl SET null_value = 0; 81 | SELECT value, null_value, flap, system_time_start <> :'now2' AS changed FROM excl; 82 | value | null_value | flap | changed 83 | --------------+------------+------+--------- 84 | howdy folks! | 0 | on | t 85 | (1 row) 86 | 87 | /* Test directly setting the excluded columns */ 88 | SELECT periods.drop_system_versioning('excl'); 89 | drop_system_versioning 90 | ------------------------ 91 | t 92 | (1 row) 93 | 94 | ALTER TABLE excl ADD COLUMN flop text; 95 | ALTER TABLE excl_history ADD COLUMN flop text; 96 | SELECT periods.add_system_versioning('excl'); 97 | add_system_versioning 98 | ----------------------- 99 | 100 | (1 row) 101 | 102 | SELECT periods.set_system_time_period_excluded_columns('excl', ARRAY['flap', 'flop']); 103 | set_system_time_period_excluded_columns 104 | ----------------------------------------- 105 | 106 | (1 row) 107 | 108 | TABLE periods.system_time_periods; 109 | table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names 110 | ------------+-------------+-------------------------------------+-----------------------------------+--------------------------------+------------------+----------------------- 111 | excl | system_time | excl_system_time_end_infinity_check | excl_system_time_generated_always | excl_system_time_write_history | excl_truncate | {flap,flop} 112 | (1 row) 113 | 114 | UPDATE excl SET flop = 'flop'; 115 | SELECT value, null_value, flap, flop FROM excl; 116 | value | null_value | flap | flop 117 | --------------+------------+------+------ 118 | howdy folks! | 0 | on | flop 119 | (1 row) 120 | 121 | SELECT value, null_value, flap, flop FROM excl_history ORDER BY system_time_start; 122 | value | null_value | flap | flop 123 | --------------+------------+------+------ 124 | hello world | | on | 125 | howdy folks! | | on | 126 | (2 rows) 127 | 128 | SELECT periods.drop_system_versioning('excl', drop_behavior => 'CASCADE', purge => true); 129 | drop_system_versioning 130 | ------------------------ 131 | t 132 | (1 row) 133 | 134 | DROP TABLE excl; 135 | -------------------------------------------------------------------------------- /expected/unique_foreign.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | pre_96 4 | -------- 5 | f 6 | (1 row) 7 | 8 | /* Run tests as unprivileged user */ 9 | SET ROLE TO periods_unprivileged_user; 10 | -- Unique keys are already pretty much guaranteed by the underlying features of 11 | -- PostgreSQL, but test them anyway. 12 | CREATE TABLE uk (id integer, s integer, e integer, CONSTRAINT uk_pkey PRIMARY KEY (id, s, e)); 13 | SELECT periods.add_period('uk', 'p', 's', 'e'); 14 | add_period 15 | ------------ 16 | t 17 | (1 row) 18 | 19 | SELECT periods.add_unique_key('uk', ARRAY['id'], 'p', key_name => 'uk_id_p', unique_constraint => 'uk_pkey'); 20 | add_unique_key 21 | ---------------- 22 | uk_id_p 23 | (1 row) 24 | 25 | TABLE periods.unique_keys; 26 | key_name | table_name | column_names | period_name | unique_constraint | exclude_constraint 27 | ----------+------------+--------------+-------------+-------------------+---------------------- 28 | uk_id_p | uk | {id} | p | uk_pkey | uk_id_int4range_excl 29 | (1 row) 30 | 31 | INSERT INTO uk (id, s, e) VALUES (100, 1, 3), (100, 3, 4), (100, 4, 10); -- success 32 | INSERT INTO uk (id, s, e) VALUES (200, 1, 3), (200, 3, 4), (200, 5, 10); -- success 33 | INSERT INTO uk (id, s, e) VALUES (300, 1, 3), (300, 3, 5), (300, 4, 10); -- fail 34 | ERROR: conflicting key value violates exclusion constraint "uk_id_int4range_excl" 35 | DETAIL: Key (id, int4range(s, e, '[)'::text))=(300, [4,10)) conflicts with existing key (id, int4range(s, e, '[)'::text))=(300, [3,5)). 36 | CREATE TABLE fk (id integer, uk_id integer, s integer, e integer, PRIMARY KEY (id)); 37 | SELECT periods.add_period('fk', 'q', 's', 'e'); 38 | add_period 39 | ------------ 40 | t 41 | (1 row) 42 | 43 | SELECT periods.add_foreign_key('fk', ARRAY['uk_id'], 'q', 'uk_id_p', 44 | key_name => 'fk_uk_id_q', 45 | fk_insert_trigger => 'fki', 46 | fk_update_trigger => 'fku', 47 | uk_update_trigger => 'uku', 48 | uk_delete_trigger => 'ukd'); 49 | add_foreign_key 50 | ----------------- 51 | fk_uk_id_q 52 | (1 row) 53 | 54 | TABLE periods.foreign_keys; 55 | key_name | table_name | column_names | period_name | unique_key | match_type | delete_action | update_action | fk_insert_trigger | fk_update_trigger | uk_update_trigger | uk_delete_trigger 56 | ------------+------------+--------------+-------------+------------+------------+---------------+---------------+-------------------+-------------------+-------------------+------------------- 57 | fk_uk_id_q | fk | {uk_id} | q | uk_id_p | SIMPLE | NO ACTION | NO ACTION | fki | fku | uku | ukd 58 | (1 row) 59 | 60 | SELECT periods.drop_foreign_key('fk', 'fk_uk_id_q'); 61 | drop_foreign_key 62 | ------------------ 63 | t 64 | (1 row) 65 | 66 | SELECT periods.add_foreign_key('fk', ARRAY['uk_id'], 'q', 'uk_id_p', key_name => 'fk_uk_id_q'); 67 | add_foreign_key 68 | ----------------- 69 | fk_uk_id_q 70 | (1 row) 71 | 72 | TABLE periods.foreign_keys; 73 | key_name | table_name | column_names | period_name | unique_key | match_type | delete_action | update_action | fk_insert_trigger | fk_update_trigger | uk_update_trigger | uk_delete_trigger 74 | ------------+------------+--------------+-------------+------------+------------+---------------+---------------+----------------------+----------------------+----------------------+---------------------- 75 | fk_uk_id_q | fk | {uk_id} | q | uk_id_p | SIMPLE | NO ACTION | NO ACTION | fk_uk_id_q_fk_insert | fk_uk_id_q_fk_update | fk_uk_id_q_uk_update | fk_uk_id_q_uk_delete 76 | (1 row) 77 | 78 | -- INSERT 79 | INSERT INTO fk VALUES (0, 100, 0, 1); -- fail 80 | ERROR: insert or update on table "fk" violates foreign key constraint "fk_uk_id_q" 81 | CONTEXT: PL/pgSQL function periods.validate_foreign_key_new_row(name,jsonb) line 130 at RAISE 82 | SQL statement "SELECT periods.validate_foreign_key_new_row(TG_ARGV[0], jnew)" 83 | PL/pgSQL function periods.fk_insert_check() line 20 at PERFORM 84 | INSERT INTO fk VALUES (0, 100, 0, 10); -- fail 85 | ERROR: insert or update on table "fk" violates foreign key constraint "fk_uk_id_q" 86 | CONTEXT: PL/pgSQL function periods.validate_foreign_key_new_row(name,jsonb) line 130 at RAISE 87 | SQL statement "SELECT periods.validate_foreign_key_new_row(TG_ARGV[0], jnew)" 88 | PL/pgSQL function periods.fk_insert_check() line 20 at PERFORM 89 | INSERT INTO fk VALUES (0, 100, 1, 11); -- fail 90 | ERROR: insert or update on table "fk" violates foreign key constraint "fk_uk_id_q" 91 | CONTEXT: PL/pgSQL function periods.validate_foreign_key_new_row(name,jsonb) line 130 at RAISE 92 | SQL statement "SELECT periods.validate_foreign_key_new_row(TG_ARGV[0], jnew)" 93 | PL/pgSQL function periods.fk_insert_check() line 20 at PERFORM 94 | INSERT INTO fk VALUES (1, 100, 1, 3); -- success 95 | INSERT INTO fk VALUES (2, 100, 1, 10); -- success 96 | -- UPDATE 97 | UPDATE fk SET e = 20 WHERE id = 1; -- fail 98 | ERROR: insert or update on table "fk" violates foreign key constraint "fk_uk_id_q" 99 | CONTEXT: PL/pgSQL function periods.validate_foreign_key_new_row(name,jsonb) line 130 at RAISE 100 | SQL statement "SELECT periods.validate_foreign_key_new_row(TG_ARGV[0], jnew)" 101 | PL/pgSQL function periods.fk_update_check() line 19 at PERFORM 102 | UPDATE fk SET e = 6 WHERE id = 1; -- success 103 | UPDATE uk SET s = 2 WHERE (id, s, e) = (100, 1, 3); -- fail 104 | ERROR: update or delete on table "uk" violates foreign key constraint "fk_uk_id_q" on table "fk" 105 | CONTEXT: PL/pgSQL function periods.validate_foreign_key_old_row(name,jsonb,boolean) line 103 at RAISE 106 | SQL statement "SELECT periods.validate_foreign_key_old_row(TG_ARGV[0], jold, true)" 107 | PL/pgSQL function periods.uk_update_check() line 23 at PERFORM 108 | UPDATE uk SET s = 0 WHERE (id, s, e) = (100, 1, 3); -- success 109 | -- DELETE 110 | DELETE FROM uk WHERE (id, s, e) = (100, 3, 4); -- fail 111 | ERROR: update or delete on table "uk" violates foreign key constraint "fk_uk_id_q" on table "fk" 112 | CONTEXT: PL/pgSQL function periods.validate_foreign_key_old_row(name,jsonb,boolean) line 103 at RAISE 113 | SQL statement "SELECT periods.validate_foreign_key_old_row(TG_ARGV[0], jold, false)" 114 | PL/pgSQL function periods.uk_delete_check() line 22 at PERFORM 115 | DELETE FROM uk WHERE (id, s, e) = (200, 3, 5); -- success 116 | DROP TABLE fk; 117 | DROP TABLE uk; 118 | -------------------------------------------------------------------------------- /expected/excluded_columns.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | pre_96 4 | -------- 5 | f 6 | (1 row) 7 | 8 | /* Run tests as unprivileged user */ 9 | SET ROLE TO periods_unprivileged_user; 10 | CREATE TABLE excl ( 11 | value text NOT NULL, 12 | null_value integer, 13 | flap text NOT NULL 14 | ); 15 | SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['xmin']); -- fails 16 | ERROR: cannot exclude system column "xmin" 17 | CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name,name[]) line 316 at RAISE 18 | SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['none']); -- fails 19 | ERROR: column "none" does not exist 20 | CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name,name[]) line 306 at RAISE 21 | SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['flap']); -- passes 22 | add_system_time_period 23 | ------------------------ 24 | t 25 | (1 row) 26 | 27 | SELECT periods.add_system_versioning('excl'); 28 | NOTICE: history table "excl_history" created for "excl", be sure to index it properly 29 | add_system_versioning 30 | ----------------------- 31 | 32 | (1 row) 33 | 34 | TABLE periods.periods; 35 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 36 | ------------+-------------+-------------------+-----------------+------------+------------------------- 37 | excl | system_time | system_time_start | system_time_end | tstzrange | excl_system_time_check 38 | (1 row) 39 | 40 | TABLE periods.system_time_periods; 41 | table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names 42 | ------------+-------------+-------------------------------------+-----------------------------------+--------------------------------+------------------+----------------------- 43 | excl | system_time | excl_system_time_end_infinity_check | excl_system_time_generated_always | excl_system_time_write_history | excl_truncate | {flap} 44 | (1 row) 45 | 46 | TABLE periods.system_versioning; 47 | table_name | period_name | history_table_name | view_name | func_as_of | func_between | func_between_symmetric | func_from_to 48 | ------------+-------------+--------------------+-------------------+----------------------------------------------+-------------------------------------------------------------------------+-----------------------------------------------------------------------------------+------------------------------------------------------------------------- 49 | excl | system_time | excl_history | excl_with_history | public.excl__as_of(timestamp with time zone) | public.excl__between(timestamp with time zone,timestamp with time zone) | public.excl__between_symmetric(timestamp with time zone,timestamp with time zone) | public.excl__from_to(timestamp with time zone,timestamp with time zone) 50 | (1 row) 51 | 52 | BEGIN; 53 | SELECT CURRENT_TIMESTAMP AS now \gset 54 | INSERT INTO excl (value, flap) VALUES ('hello world', 'off'); 55 | COMMIT; 56 | SELECT value, null_value, flap, system_time_start <> :'now' AS changed FROM excl; 57 | value | null_value | flap | changed 58 | -------------+------------+------+--------- 59 | hello world | | off | f 60 | (1 row) 61 | 62 | UPDATE excl SET flap = 'off'; 63 | UPDATE excl SET flap = 'on'; 64 | UPDATE excl SET flap = 'off'; 65 | UPDATE excl SET flap = 'on'; 66 | SELECT value, null_value, flap, system_time_start <> :'now' AS changed FROM excl; 67 | value | null_value | flap | changed 68 | -------------+------------+------+--------- 69 | hello world | | on | f 70 | (1 row) 71 | 72 | BEGIN; 73 | SELECT CURRENT_TIMESTAMP AS now2 \gset 74 | UPDATE excl SET value = 'howdy folks!'; 75 | COMMIT; 76 | SELECT value, null_value, flap, system_time_start <> :'now' AS changed FROM excl; 77 | value | null_value | flap | changed 78 | --------------+------------+------+--------- 79 | howdy folks! | | on | t 80 | (1 row) 81 | 82 | UPDATE excl SET null_value = 0; 83 | SELECT value, null_value, flap, system_time_start <> :'now2' AS changed FROM excl; 84 | value | null_value | flap | changed 85 | --------------+------------+------+--------- 86 | howdy folks! | 0 | on | t 87 | (1 row) 88 | 89 | /* Test directly setting the excluded columns */ 90 | SELECT periods.drop_system_versioning('excl'); 91 | drop_system_versioning 92 | ------------------------ 93 | t 94 | (1 row) 95 | 96 | ALTER TABLE excl ADD COLUMN flop text; 97 | ALTER TABLE excl_history ADD COLUMN flop text; 98 | SELECT periods.add_system_versioning('excl'); 99 | add_system_versioning 100 | ----------------------- 101 | 102 | (1 row) 103 | 104 | SELECT periods.set_system_time_period_excluded_columns('excl', ARRAY['flap', 'flop']); 105 | set_system_time_period_excluded_columns 106 | ----------------------------------------- 107 | 108 | (1 row) 109 | 110 | TABLE periods.system_time_periods; 111 | table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names 112 | ------------+-------------+-------------------------------------+-----------------------------------+--------------------------------+------------------+----------------------- 113 | excl | system_time | excl_system_time_end_infinity_check | excl_system_time_generated_always | excl_system_time_write_history | excl_truncate | {flap,flop} 114 | (1 row) 115 | 116 | UPDATE excl SET flop = 'flop'; 117 | SELECT value, null_value, flap, flop FROM excl; 118 | value | null_value | flap | flop 119 | --------------+------------+------+------ 120 | howdy folks! | 0 | on | flop 121 | (1 row) 122 | 123 | SELECT value, null_value, flap, flop FROM excl_history ORDER BY system_time_start; 124 | value | null_value | flap | flop 125 | --------------+------------+------+------ 126 | hello world | | on | 127 | howdy folks! | | on | 128 | (2 rows) 129 | 130 | SELECT periods.drop_system_versioning('excl', drop_behavior => 'CASCADE', purge => true); 131 | drop_system_versioning 132 | ------------------------ 133 | t 134 | (1 row) 135 | 136 | DROP TABLE excl; 137 | -------------------------------------------------------------------------------- /expected/drop_protection_1.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | pre_96 4 | -------- 5 | t 6 | (1 row) 7 | 8 | /* Run tests as unprivileged user */ 9 | SET ROLE TO periods_unprivileged_user; 10 | /* Make sure nobody drops the objects we keep track of in our catalogs. */ 11 | CREATE TYPE integerrange AS RANGE (SUBTYPE = integer); 12 | CREATE TABLE dp ( 13 | id bigint, 14 | s integer, 15 | e integer, 16 | x boolean 17 | ); 18 | /* periods */ 19 | SELECT periods.add_period('dp', 'p', 's', 'e', 'integerrange'); 20 | add_period 21 | ------------ 22 | t 23 | (1 row) 24 | 25 | DROP TYPE integerrange; 26 | ERROR: cannot drop rangetype "public.integerrange" because it is used in period "p" on table "dp" 27 | /* system_time_periods */ 28 | SELECT periods.add_system_time_period('dp', excluded_column_names => ARRAY['x']); 29 | add_system_time_period 30 | ------------------------ 31 | t 32 | (1 row) 33 | 34 | ALTER TABLE dp DROP COLUMN x; -- fails 35 | ERROR: cannot drop or rename column "x" on table "dp" because it is excluded from SYSTEM VERSIONING 36 | ALTER TABLE dp DROP CONSTRAINT dp_system_time_end_infinity_check; -- fails 37 | ERROR: cannot drop constraint "dp_system_time_end_infinity_check" on table "dp" because it is used in SYSTEM_TIME period 38 | DROP TRIGGER dp_system_time_generated_always ON dp; -- fails 39 | ERROR: cannot drop trigger "dp_system_time_generated_always" on table "dp" because it is used in SYSTEM_TIME period 40 | DROP TRIGGER dp_system_time_write_history ON dp; -- fails 41 | ERROR: cannot drop trigger "dp_system_time_write_history" on table "dp" because it is used in SYSTEM_TIME period 42 | DROP TRIGGER dp_truncate ON dp; -- fails 43 | ERROR: cannot drop trigger "dp_truncate" on table "dp" because it is used in SYSTEM_TIME period 44 | /* for_portion_views */ 45 | ALTER TABLE dp ADD CONSTRAINT dp_pkey PRIMARY KEY (id); 46 | SELECT periods.add_for_portion_view('dp', 'p'); 47 | add_for_portion_view 48 | ---------------------- 49 | t 50 | (1 row) 51 | 52 | DROP VIEW dp__for_portion_of_p; 53 | ERROR: cannot drop view "public.dp__for_portion_of_p", call "periods.drop_for_portion_view()" instead 54 | DROP TRIGGER for_portion_of_p ON dp__for_portion_of_p; 55 | ERROR: cannot drop trigger "for_portion_of_p" on view "dp__for_portion_of_p" because it is used in FOR PORTION OF view for period "p" on table "dp" 56 | ALTER TABLE dp DROP CONSTRAINT dp_pkey; 57 | ERROR: cannot drop primary key on table "dp" because it has a FOR PORTION OF view for period "p" 58 | SELECT periods.drop_for_portion_view('dp', 'p'); 59 | drop_for_portion_view 60 | ----------------------- 61 | t 62 | (1 row) 63 | 64 | ALTER TABLE dp DROP CONSTRAINT dp_pkey; 65 | /* unique_keys */ 66 | ALTER TABLE dp 67 | ADD CONSTRAINT u UNIQUE (id, s, e), 68 | ADD CONSTRAINT x EXCLUDE USING gist (id WITH =, integerrange(s, e, '[)') WITH &&); 69 | SELECT periods.add_unique_key('dp', ARRAY['id'], 'p', 'k', 'u', 'x'); 70 | add_unique_key 71 | ---------------- 72 | k 73 | (1 row) 74 | 75 | ALTER TABLE dp DROP CONSTRAINT u; -- fails 76 | ERROR: cannot drop constraint "u" on table "dp" because it is used in period unique key "k" 77 | ALTER TABLE dp DROP CONSTRAINT x; -- fails 78 | ERROR: cannot drop constraint "x" on table "dp" because it is used in period unique key "k" 79 | ALTER TABLE dp DROP CONSTRAINT dp_p_check; -- fails 80 | /* foreign_keys */ 81 | CREATE TABLE dp_ref (LIKE dp); 82 | SELECT periods.add_period('dp_ref', 'p', 's', 'e', 'integerrange'); 83 | add_period 84 | ------------ 85 | t 86 | (1 row) 87 | 88 | SELECT periods.add_foreign_key('dp_ref', ARRAY['id'], 'p', 'k', key_name => 'f'); 89 | add_foreign_key 90 | ----------------- 91 | f 92 | (1 row) 93 | 94 | DROP TRIGGER f_fk_insert ON dp_ref; -- fails 95 | ERROR: cannot drop trigger "f_fk_insert" on table "dp_ref" because it is used in period foreign key "f" 96 | DROP TRIGGER f_fk_update ON dp_ref; -- fails 97 | ERROR: cannot drop trigger "f_fk_update" on table "dp_ref" because it is used in period foreign key "f" 98 | DROP TRIGGER f_uk_update ON dp; -- fails 99 | ERROR: cannot drop trigger "f_uk_update" on table "dp" because it is used in period foreign key "f" 100 | DROP TRIGGER f_uk_delete ON dp; -- fails 101 | ERROR: cannot drop trigger "f_uk_delete" on table "dp" because it is used in period foreign key "f" 102 | SELECT periods.drop_foreign_key('dp_ref', 'f'); 103 | drop_foreign_key 104 | ------------------ 105 | t 106 | (1 row) 107 | 108 | DROP TABLE dp_ref; 109 | /* system_versioning */ 110 | SELECT periods.add_system_versioning('dp'); 111 | NOTICE: history table "dp_history" created for "dp", be sure to index it properly 112 | add_system_versioning 113 | ----------------------- 114 | 115 | (1 row) 116 | 117 | -- Note: The history table is protected by the history view and the history 118 | -- view is protected by the temporal functions. 119 | DROP TABLE dp_history CASCADE; 120 | NOTICE: drop cascades to 5 other objects 121 | DETAIL: drop cascades to view dp_with_history 122 | drop cascades to function dp__as_of(timestamp with time zone) 123 | drop cascades to function dp__between(timestamp with time zone,timestamp with time zone) 124 | drop cascades to function dp__between_symmetric(timestamp with time zone,timestamp with time zone) 125 | drop cascades to function dp__from_to(timestamp with time zone,timestamp with time zone) 126 | ERROR: cannot drop table "public.dp_history" because it is used in SYSTEM VERSIONING for table "dp" 127 | DROP VIEW dp_with_history CASCADE; 128 | NOTICE: drop cascades to 4 other objects 129 | DETAIL: drop cascades to function dp__as_of(timestamp with time zone) 130 | drop cascades to function dp__between(timestamp with time zone,timestamp with time zone) 131 | drop cascades to function dp__between_symmetric(timestamp with time zone,timestamp with time zone) 132 | drop cascades to function dp__from_to(timestamp with time zone,timestamp with time zone) 133 | ERROR: cannot drop view "public.dp_with_history" because it is used in SYSTEM VERSIONING for table "dp" 134 | DROP FUNCTION dp__as_of(timestamp with time zone); 135 | ERROR: cannot drop function "public.dp__as_of(timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "dp" 136 | DROP FUNCTION dp__between(timestamp with time zone,timestamp with time zone); 137 | ERROR: cannot drop function "public.dp__between(timestamp with time zone,timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "dp" 138 | DROP FUNCTION dp__between_symmetric(timestamp with time zone,timestamp with time zone); 139 | ERROR: cannot drop function "public.dp__between_symmetric(timestamp with time zone,timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "dp" 140 | DROP FUNCTION dp__from_to(timestamp with time zone,timestamp with time zone); 141 | ERROR: cannot drop function "public.dp__from_to(timestamp with time zone,timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "dp" 142 | SELECT periods.drop_system_versioning('dp', purge => true); 143 | drop_system_versioning 144 | ------------------------ 145 | t 146 | (1 row) 147 | 148 | DROP TABLE dp; 149 | DROP TYPE integerrange; 150 | -------------------------------------------------------------------------------- /expected/for_portion_of.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 100000 AS pre_10, 2 | setting::integer < 120000 AS pre_12 3 | FROM pg_settings WHERE name = 'server_version_num'; 4 | pre_10 | pre_12 5 | --------+-------- 6 | f | f 7 | (1 row) 8 | 9 | /* Run tests as unprivileged user */ 10 | SET ROLE TO periods_unprivileged_user; 11 | /* 12 | * Create a sequence to test non-serial primary keys. This actually tests 13 | * things like uuid primary keys, but makes for reproducible test cases. 14 | */ 15 | CREATE SEQUENCE pricing_seq; 16 | CREATE TABLE pricing (id1 bigserial, 17 | id2 bigint PRIMARY KEY DEFAULT nextval('pricing_seq'), 18 | id3 bigint GENERATED ALWAYS AS IDENTITY, 19 | id4 bigint GENERATED ALWAYS AS (id1 + id2) STORED, 20 | product text, min_quantity integer, max_quantity integer, price numeric); 21 | CREATE TABLE pricing (id1 bigserial, 22 | id2 bigint PRIMARY KEY DEFAULT nextval('pricing_seq'), 23 | id3 bigint GENERATED ALWAYS AS IDENTITY, 24 | product text, min_quantity integer, max_quantity integer, price numeric); 25 | ERROR: relation "pricing" already exists 26 | CREATE TABLE pricing (id1 bigserial, 27 | id2 bigint PRIMARY KEY DEFAULT nextval('pricing_seq'), 28 | product text, min_quantity integer, max_quantity integer, price numeric); 29 | ERROR: relation "pricing" already exists 30 | SELECT periods.add_period('pricing', 'quantities', 'min_quantity', 'max_quantity'); 31 | add_period 32 | ------------ 33 | t 34 | (1 row) 35 | 36 | SELECT periods.add_for_portion_view('pricing', 'quantities'); 37 | add_for_portion_view 38 | ---------------------- 39 | t 40 | (1 row) 41 | 42 | TABLE periods.for_portion_views; 43 | table_name | period_name | view_name | trigger_name 44 | ------------+-------------+------------------------------------+--------------------------- 45 | pricing | quantities | pricing__for_portion_of_quantities | for_portion_of_quantities 46 | (1 row) 47 | 48 | /* Test UPDATE FOR PORTION */ 49 | INSERT INTO pricing (product, min_quantity, max_quantity, price) VALUES ('Trinket', 1, 20, 200); 50 | TABLE pricing ORDER BY min_quantity; 51 | id1 | id2 | id3 | id4 | product | min_quantity | max_quantity | price 52 | -----+-----+-----+-----+---------+--------------+--------------+------- 53 | 1 | 1 | 1 | 2 | Trinket | 1 | 20 | 200 54 | (1 row) 55 | 56 | -- UPDATE fully preceding 57 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 0, max_quantity = 1, price = 0; 58 | TABLE pricing ORDER BY min_quantity; 59 | id1 | id2 | id3 | id4 | product | min_quantity | max_quantity | price 60 | -----+-----+-----+-----+---------+--------------+--------------+------- 61 | 1 | 1 | 1 | 2 | Trinket | 1 | 20 | 200 62 | (1 row) 63 | 64 | -- UPDATE fully succeeding 65 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 30, max_quantity = 50, price = 0; 66 | TABLE pricing ORDER BY min_quantity; 67 | id1 | id2 | id3 | id4 | product | min_quantity | max_quantity | price 68 | -----+-----+-----+-----+---------+--------------+--------------+------- 69 | 1 | 1 | 1 | 2 | Trinket | 1 | 20 | 200 70 | (1 row) 71 | 72 | -- UPDATE fully surrounding 73 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 0, max_quantity = 100, price = 100; 74 | TABLE pricing ORDER BY min_quantity; 75 | id1 | id2 | id3 | id4 | product | min_quantity | max_quantity | price 76 | -----+-----+-----+-----+---------+--------------+--------------+------- 77 | 1 | 1 | 1 | 2 | Trinket | 1 | 20 | 100 78 | (1 row) 79 | 80 | -- UPDATE portion 81 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 10, max_quantity = 20, price = 80; 82 | TABLE pricing ORDER BY min_quantity; 83 | id1 | id2 | id3 | id4 | product | min_quantity | max_quantity | price 84 | -----+-----+-----+-----+---------+--------------+--------------+------- 85 | 2 | 2 | 2 | 4 | Trinket | 1 | 10 | 100 86 | 1 | 1 | 1 | 2 | Trinket | 10 | 20 | 80 87 | (2 rows) 88 | 89 | -- UPDATE portion of multiple rows 90 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 5, max_quantity = 15, price = 90; 91 | TABLE pricing ORDER BY min_quantity; 92 | id1 | id2 | id3 | id4 | product | min_quantity | max_quantity | price 93 | -----+-----+-----+-----+---------+--------------+--------------+------- 94 | 3 | 3 | 3 | 6 | Trinket | 1 | 5 | 100 95 | 2 | 2 | 2 | 4 | Trinket | 5 | 10 | 90 96 | 1 | 1 | 1 | 2 | Trinket | 10 | 15 | 90 97 | 4 | 4 | 4 | 8 | Trinket | 15 | 20 | 80 98 | (4 rows) 99 | 100 | -- If we drop the period (without CASCADE) then the FOR PORTION views should be 101 | -- dropped, too. 102 | SELECT periods.drop_period('pricing', 'quantities'); 103 | drop_period 104 | ------------- 105 | t 106 | (1 row) 107 | 108 | TABLE periods.for_portion_views; 109 | table_name | period_name | view_name | trigger_name 110 | ------------+-------------+-----------+-------------- 111 | (0 rows) 112 | 113 | -- Add it back to test the drop_for_portion_view function 114 | SELECT periods.add_period('pricing', 'quantities', 'min_quantity', 'max_quantity'); 115 | add_period 116 | ------------ 117 | t 118 | (1 row) 119 | 120 | SELECT periods.add_for_portion_view('pricing', 'quantities'); 121 | add_for_portion_view 122 | ---------------------- 123 | t 124 | (1 row) 125 | 126 | -- We can't drop the the table without first dropping the FOR PORTION views 127 | -- because Postgres will complain about dependant objects (our views) before we 128 | -- get a chance to clean them up. 129 | DROP TABLE pricing; 130 | ERROR: cannot drop table pricing because other objects depend on it 131 | DETAIL: view pricing__for_portion_of_quantities depends on table pricing 132 | HINT: Use DROP ... CASCADE to drop the dependent objects too. 133 | SELECT periods.drop_for_portion_view('pricing', NULL); 134 | drop_for_portion_view 135 | ----------------------- 136 | t 137 | (1 row) 138 | 139 | TABLE periods.for_portion_views; 140 | table_name | period_name | view_name | trigger_name 141 | ------------+-------------+-----------+-------------- 142 | (0 rows) 143 | 144 | DROP TABLE pricing; 145 | DROP SEQUENCE pricing_seq; 146 | /* Types without btree must be excluded, too */ 147 | -- v10+ 148 | CREATE TABLE bt ( 149 | id integer PRIMARY KEY GENERATED ALWAYS AS IDENTITY, 150 | pt point, -- something without btree 151 | t text, -- something with btree 152 | s integer, 153 | e integer 154 | ); 155 | -- pre v10 156 | CREATE TABLE bt ( 157 | id serial PRIMARY KEY, 158 | pt point, -- something without btree 159 | t text, -- something with btree 160 | s integer, 161 | e integer 162 | ); 163 | ERROR: relation "bt" already exists 164 | SELECT periods.add_period('bt', 'p', 's', 'e'); 165 | add_period 166 | ------------ 167 | t 168 | (1 row) 169 | 170 | SELECT periods.add_for_portion_view('bt', 'p'); 171 | add_for_portion_view 172 | ---------------------- 173 | t 174 | (1 row) 175 | 176 | INSERT INTO bt (pt, t, s, e) VALUES ('(0, 0)', 'sample', 10, 40); 177 | TABLE bt ORDER BY s, e; 178 | id | pt | t | s | e 179 | ----+-------+--------+----+---- 180 | 1 | (0,0) | sample | 10 | 40 181 | (1 row) 182 | 183 | UPDATE bt__for_portion_of_p SET t = 'simple', s = 20, e = 30; 184 | TABLE bt ORDER BY s, e; 185 | id | pt | t | s | e 186 | ----+-------+--------+----+---- 187 | 2 | (0,0) | sample | 10 | 20 188 | 1 | (0,0) | simple | 20 | 30 189 | 3 | (0,0) | sample | 30 | 40 190 | (3 rows) 191 | 192 | SELECT periods.drop_for_portion_view('bt', 'p'); 193 | drop_for_portion_view 194 | ----------------------- 195 | t 196 | (1 row) 197 | 198 | DROP TABLE bt; 199 | -------------------------------------------------------------------------------- /expected/for_portion_of_1.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 100000 AS pre_10, 2 | setting::integer < 120000 AS pre_12 3 | FROM pg_settings WHERE name = 'server_version_num'; 4 | pre_10 | pre_12 5 | --------+-------- 6 | f | t 7 | (1 row) 8 | 9 | /* Run tests as unprivileged user */ 10 | SET ROLE TO periods_unprivileged_user; 11 | /* 12 | * Create a sequence to test non-serial primary keys. This actually tests 13 | * things like uuid primary keys, but makes for reproducible test cases. 14 | */ 15 | CREATE SEQUENCE pricing_seq; 16 | CREATE TABLE pricing (id1 bigserial, 17 | id2 bigint PRIMARY KEY DEFAULT nextval('pricing_seq'), 18 | id3 bigint GENERATED ALWAYS AS IDENTITY, 19 | id4 bigint GENERATED ALWAYS AS (id1 + id2) STORED, 20 | product text, min_quantity integer, max_quantity integer, price numeric); 21 | ERROR: syntax error at or near "(" 22 | LINE 4: ... id4 bigint GENERATED ALWAYS AS (id1 + id2... 23 | ^ 24 | CREATE TABLE pricing (id1 bigserial, 25 | id2 bigint PRIMARY KEY DEFAULT nextval('pricing_seq'), 26 | id3 bigint GENERATED ALWAYS AS IDENTITY, 27 | product text, min_quantity integer, max_quantity integer, price numeric); 28 | CREATE TABLE pricing (id1 bigserial, 29 | id2 bigint PRIMARY KEY DEFAULT nextval('pricing_seq'), 30 | product text, min_quantity integer, max_quantity integer, price numeric); 31 | ERROR: relation "pricing" already exists 32 | SELECT periods.add_period('pricing', 'quantities', 'min_quantity', 'max_quantity'); 33 | add_period 34 | ------------ 35 | t 36 | (1 row) 37 | 38 | SELECT periods.add_for_portion_view('pricing', 'quantities'); 39 | add_for_portion_view 40 | ---------------------- 41 | t 42 | (1 row) 43 | 44 | TABLE periods.for_portion_views; 45 | table_name | period_name | view_name | trigger_name 46 | ------------+-------------+------------------------------------+--------------------------- 47 | pricing | quantities | pricing__for_portion_of_quantities | for_portion_of_quantities 48 | (1 row) 49 | 50 | /* Test UPDATE FOR PORTION */ 51 | INSERT INTO pricing (product, min_quantity, max_quantity, price) VALUES ('Trinket', 1, 20, 200); 52 | TABLE pricing ORDER BY min_quantity; 53 | id1 | id2 | id3 | product | min_quantity | max_quantity | price 54 | -----+-----+-----+---------+--------------+--------------+------- 55 | 1 | 1 | 1 | Trinket | 1 | 20 | 200 56 | (1 row) 57 | 58 | -- UPDATE fully preceding 59 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 0, max_quantity = 1, price = 0; 60 | TABLE pricing ORDER BY min_quantity; 61 | id1 | id2 | id3 | product | min_quantity | max_quantity | price 62 | -----+-----+-----+---------+--------------+--------------+------- 63 | 1 | 1 | 1 | Trinket | 1 | 20 | 200 64 | (1 row) 65 | 66 | -- UPDATE fully succeeding 67 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 30, max_quantity = 50, price = 0; 68 | TABLE pricing ORDER BY min_quantity; 69 | id1 | id2 | id3 | product | min_quantity | max_quantity | price 70 | -----+-----+-----+---------+--------------+--------------+------- 71 | 1 | 1 | 1 | Trinket | 1 | 20 | 200 72 | (1 row) 73 | 74 | -- UPDATE fully surrounding 75 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 0, max_quantity = 100, price = 100; 76 | TABLE pricing ORDER BY min_quantity; 77 | id1 | id2 | id3 | product | min_quantity | max_quantity | price 78 | -----+-----+-----+---------+--------------+--------------+------- 79 | 1 | 1 | 1 | Trinket | 1 | 20 | 100 80 | (1 row) 81 | 82 | -- UPDATE portion 83 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 10, max_quantity = 20, price = 80; 84 | TABLE pricing ORDER BY min_quantity; 85 | id1 | id2 | id3 | product | min_quantity | max_quantity | price 86 | -----+-----+-----+---------+--------------+--------------+------- 87 | 2 | 2 | 2 | Trinket | 1 | 10 | 100 88 | 1 | 1 | 1 | Trinket | 10 | 20 | 80 89 | (2 rows) 90 | 91 | -- UPDATE portion of multiple rows 92 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 5, max_quantity = 15, price = 90; 93 | TABLE pricing ORDER BY min_quantity; 94 | id1 | id2 | id3 | product | min_quantity | max_quantity | price 95 | -----+-----+-----+---------+--------------+--------------+------- 96 | 3 | 3 | 3 | Trinket | 1 | 5 | 100 97 | 2 | 2 | 2 | Trinket | 5 | 10 | 90 98 | 1 | 1 | 1 | Trinket | 10 | 15 | 90 99 | 4 | 4 | 4 | Trinket | 15 | 20 | 80 100 | (4 rows) 101 | 102 | -- If we drop the period (without CASCADE) then the FOR PORTION views should be 103 | -- dropped, too. 104 | SELECT periods.drop_period('pricing', 'quantities'); 105 | drop_period 106 | ------------- 107 | t 108 | (1 row) 109 | 110 | TABLE periods.for_portion_views; 111 | table_name | period_name | view_name | trigger_name 112 | ------------+-------------+-----------+-------------- 113 | (0 rows) 114 | 115 | -- Add it back to test the drop_for_portion_view function 116 | SELECT periods.add_period('pricing', 'quantities', 'min_quantity', 'max_quantity'); 117 | add_period 118 | ------------ 119 | t 120 | (1 row) 121 | 122 | SELECT periods.add_for_portion_view('pricing', 'quantities'); 123 | add_for_portion_view 124 | ---------------------- 125 | t 126 | (1 row) 127 | 128 | -- We can't drop the the table without first dropping the FOR PORTION views 129 | -- because Postgres will complain about dependant objects (our views) before we 130 | -- get a chance to clean them up. 131 | DROP TABLE pricing; 132 | ERROR: cannot drop table pricing because other objects depend on it 133 | DETAIL: view pricing__for_portion_of_quantities depends on table pricing 134 | HINT: Use DROP ... CASCADE to drop the dependent objects too. 135 | SELECT periods.drop_for_portion_view('pricing', NULL); 136 | drop_for_portion_view 137 | ----------------------- 138 | t 139 | (1 row) 140 | 141 | TABLE periods.for_portion_views; 142 | table_name | period_name | view_name | trigger_name 143 | ------------+-------------+-----------+-------------- 144 | (0 rows) 145 | 146 | DROP TABLE pricing; 147 | DROP SEQUENCE pricing_seq; 148 | /* Types without btree must be excluded, too */ 149 | -- v10+ 150 | CREATE TABLE bt ( 151 | id integer PRIMARY KEY GENERATED ALWAYS AS IDENTITY, 152 | pt point, -- something without btree 153 | t text, -- something with btree 154 | s integer, 155 | e integer 156 | ); 157 | -- pre v10 158 | CREATE TABLE bt ( 159 | id serial PRIMARY KEY, 160 | pt point, -- something without btree 161 | t text, -- something with btree 162 | s integer, 163 | e integer 164 | ); 165 | ERROR: relation "bt" already exists 166 | SELECT periods.add_period('bt', 'p', 's', 'e'); 167 | add_period 168 | ------------ 169 | t 170 | (1 row) 171 | 172 | SELECT periods.add_for_portion_view('bt', 'p'); 173 | add_for_portion_view 174 | ---------------------- 175 | t 176 | (1 row) 177 | 178 | INSERT INTO bt (pt, t, s, e) VALUES ('(0, 0)', 'sample', 10, 40); 179 | TABLE bt ORDER BY s, e; 180 | id | pt | t | s | e 181 | ----+-------+--------+----+---- 182 | 1 | (0,0) | sample | 10 | 40 183 | (1 row) 184 | 185 | UPDATE bt__for_portion_of_p SET t = 'simple', s = 20, e = 30; 186 | TABLE bt ORDER BY s, e; 187 | id | pt | t | s | e 188 | ----+-------+--------+----+---- 189 | 2 | (0,0) | sample | 10 | 20 190 | 1 | (0,0) | simple | 20 | 30 191 | 3 | (0,0) | sample | 30 | 40 192 | (3 rows) 193 | 194 | SELECT periods.drop_for_portion_view('bt', 'p'); 195 | drop_for_portion_view 196 | ----------------------- 197 | t 198 | (1 row) 199 | 200 | DROP TABLE bt; 201 | -------------------------------------------------------------------------------- /expected/for_portion_of_2.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 100000 AS pre_10, 2 | setting::integer < 120000 AS pre_12 3 | FROM pg_settings WHERE name = 'server_version_num'; 4 | pre_10 | pre_12 5 | --------+-------- 6 | t | t 7 | (1 row) 8 | 9 | /* Run tests as unprivileged user */ 10 | SET ROLE TO periods_unprivileged_user; 11 | /* 12 | * Create a sequence to test non-serial primary keys. This actually tests 13 | * things like uuid primary keys, but makes for reproducible test cases. 14 | */ 15 | CREATE SEQUENCE pricing_seq; 16 | CREATE TABLE pricing (id1 bigserial, 17 | id2 bigint PRIMARY KEY DEFAULT nextval('pricing_seq'), 18 | id3 bigint GENERATED ALWAYS AS IDENTITY, 19 | id4 bigint GENERATED ALWAYS AS (id1 + id2) STORED, 20 | product text, min_quantity integer, max_quantity integer, price numeric); 21 | ERROR: syntax error at or near "GENERATED" 22 | LINE 3: id3 bigint GENERATED ALWAYS AS IDENTIT... 23 | ^ 24 | CREATE TABLE pricing (id1 bigserial, 25 | id2 bigint PRIMARY KEY DEFAULT nextval('pricing_seq'), 26 | id3 bigint GENERATED ALWAYS AS IDENTITY, 27 | product text, min_quantity integer, max_quantity integer, price numeric); 28 | ERROR: syntax error at or near "GENERATED" 29 | LINE 3: id3 bigint GENERATED ALWAYS AS IDENTIT... 30 | ^ 31 | CREATE TABLE pricing (id1 bigserial, 32 | id2 bigint PRIMARY KEY DEFAULT nextval('pricing_seq'), 33 | product text, min_quantity integer, max_quantity integer, price numeric); 34 | SELECT periods.add_period('pricing', 'quantities', 'min_quantity', 'max_quantity'); 35 | add_period 36 | ------------ 37 | t 38 | (1 row) 39 | 40 | SELECT periods.add_for_portion_view('pricing', 'quantities'); 41 | add_for_portion_view 42 | ---------------------- 43 | t 44 | (1 row) 45 | 46 | TABLE periods.for_portion_views; 47 | table_name | period_name | view_name | trigger_name 48 | ------------+-------------+------------------------------------+--------------------------- 49 | pricing | quantities | pricing__for_portion_of_quantities | for_portion_of_quantities 50 | (1 row) 51 | 52 | /* Test UPDATE FOR PORTION */ 53 | INSERT INTO pricing (product, min_quantity, max_quantity, price) VALUES ('Trinket', 1, 20, 200); 54 | TABLE pricing ORDER BY min_quantity; 55 | id1 | id2 | product | min_quantity | max_quantity | price 56 | -----+-----+---------+--------------+--------------+------- 57 | 1 | 1 | Trinket | 1 | 20 | 200 58 | (1 row) 59 | 60 | -- UPDATE fully preceding 61 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 0, max_quantity = 1, price = 0; 62 | TABLE pricing ORDER BY min_quantity; 63 | id1 | id2 | product | min_quantity | max_quantity | price 64 | -----+-----+---------+--------------+--------------+------- 65 | 1 | 1 | Trinket | 1 | 20 | 200 66 | (1 row) 67 | 68 | -- UPDATE fully succeeding 69 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 30, max_quantity = 50, price = 0; 70 | TABLE pricing ORDER BY min_quantity; 71 | id1 | id2 | product | min_quantity | max_quantity | price 72 | -----+-----+---------+--------------+--------------+------- 73 | 1 | 1 | Trinket | 1 | 20 | 200 74 | (1 row) 75 | 76 | -- UPDATE fully surrounding 77 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 0, max_quantity = 100, price = 100; 78 | TABLE pricing ORDER BY min_quantity; 79 | id1 | id2 | product | min_quantity | max_quantity | price 80 | -----+-----+---------+--------------+--------------+------- 81 | 1 | 1 | Trinket | 1 | 20 | 100 82 | (1 row) 83 | 84 | -- UPDATE portion 85 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 10, max_quantity = 20, price = 80; 86 | TABLE pricing ORDER BY min_quantity; 87 | id1 | id2 | product | min_quantity | max_quantity | price 88 | -----+-----+---------+--------------+--------------+------- 89 | 2 | 2 | Trinket | 1 | 10 | 100 90 | 1 | 1 | Trinket | 10 | 20 | 80 91 | (2 rows) 92 | 93 | -- UPDATE portion of multiple rows 94 | UPDATE pricing__for_portion_of_quantities SET min_quantity = 5, max_quantity = 15, price = 90; 95 | TABLE pricing ORDER BY min_quantity; 96 | id1 | id2 | product | min_quantity | max_quantity | price 97 | -----+-----+---------+--------------+--------------+------- 98 | 3 | 3 | Trinket | 1 | 5 | 100 99 | 2 | 2 | Trinket | 5 | 10 | 90 100 | 1 | 1 | Trinket | 10 | 15 | 90 101 | 4 | 4 | Trinket | 15 | 20 | 80 102 | (4 rows) 103 | 104 | -- If we drop the period (without CASCADE) then the FOR PORTION views should be 105 | -- dropped, too. 106 | SELECT periods.drop_period('pricing', 'quantities'); 107 | drop_period 108 | ------------- 109 | t 110 | (1 row) 111 | 112 | TABLE periods.for_portion_views; 113 | table_name | period_name | view_name | trigger_name 114 | ------------+-------------+-----------+-------------- 115 | (0 rows) 116 | 117 | -- Add it back to test the drop_for_portion_view function 118 | SELECT periods.add_period('pricing', 'quantities', 'min_quantity', 'max_quantity'); 119 | add_period 120 | ------------ 121 | t 122 | (1 row) 123 | 124 | SELECT periods.add_for_portion_view('pricing', 'quantities'); 125 | add_for_portion_view 126 | ---------------------- 127 | t 128 | (1 row) 129 | 130 | -- We can't drop the the table without first dropping the FOR PORTION views 131 | -- because Postgres will complain about dependant objects (our views) before we 132 | -- get a chance to clean them up. 133 | DROP TABLE pricing; 134 | ERROR: cannot drop table pricing because other objects depend on it 135 | DETAIL: view pricing__for_portion_of_quantities depends on table pricing 136 | HINT: Use DROP ... CASCADE to drop the dependent objects too. 137 | SELECT periods.drop_for_portion_view('pricing', NULL); 138 | drop_for_portion_view 139 | ----------------------- 140 | t 141 | (1 row) 142 | 143 | TABLE periods.for_portion_views; 144 | table_name | period_name | view_name | trigger_name 145 | ------------+-------------+-----------+-------------- 146 | (0 rows) 147 | 148 | DROP TABLE pricing; 149 | DROP SEQUENCE pricing_seq; 150 | /* Types without btree must be excluded, too */ 151 | -- v10+ 152 | CREATE TABLE bt ( 153 | id integer PRIMARY KEY GENERATED ALWAYS AS IDENTITY, 154 | pt point, -- something without btree 155 | t text, -- something with btree 156 | s integer, 157 | e integer 158 | ); 159 | ERROR: syntax error at or near "GENERATED" 160 | LINE 4: id integer PRIMARY KEY GENERATED ALWAYS AS IDENTITY, 161 | ^ 162 | -- pre v10 163 | CREATE TABLE bt ( 164 | id serial PRIMARY KEY, 165 | pt point, -- something without btree 166 | t text, -- something with btree 167 | s integer, 168 | e integer 169 | ); 170 | SELECT periods.add_period('bt', 'p', 's', 'e'); 171 | add_period 172 | ------------ 173 | t 174 | (1 row) 175 | 176 | SELECT periods.add_for_portion_view('bt', 'p'); 177 | add_for_portion_view 178 | ---------------------- 179 | t 180 | (1 row) 181 | 182 | INSERT INTO bt (pt, t, s, e) VALUES ('(0, 0)', 'sample', 10, 40); 183 | TABLE bt ORDER BY s, e; 184 | id | pt | t | s | e 185 | ----+-------+--------+----+---- 186 | 1 | (0,0) | sample | 10 | 40 187 | (1 row) 188 | 189 | UPDATE bt__for_portion_of_p SET t = 'simple', s = 20, e = 30; 190 | TABLE bt ORDER BY s, e; 191 | id | pt | t | s | e 192 | ----+-------+--------+----+---- 193 | 2 | (0,0) | sample | 10 | 20 194 | 1 | (0,0) | simple | 20 | 30 195 | 3 | (0,0) | sample | 30 | 40 196 | (3 rows) 197 | 198 | SELECT periods.drop_for_portion_view('bt', 'p'); 199 | drop_for_portion_view 200 | ----------------------- 201 | t 202 | (1 row) 203 | 204 | DROP TABLE bt; 205 | -------------------------------------------------------------------------------- /expected/drop_protection.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | pre_96 4 | -------- 5 | f 6 | (1 row) 7 | 8 | /* Run tests as unprivileged user */ 9 | SET ROLE TO periods_unprivileged_user; 10 | /* Make sure nobody drops the objects we keep track of in our catalogs. */ 11 | CREATE TYPE integerrange AS RANGE (SUBTYPE = integer); 12 | CREATE TABLE dp ( 13 | id bigint, 14 | s integer, 15 | e integer, 16 | x boolean 17 | ); 18 | /* periods */ 19 | SELECT periods.add_period('dp', 'p', 's', 'e', 'integerrange'); 20 | add_period 21 | ------------ 22 | t 23 | (1 row) 24 | 25 | DROP TYPE integerrange; 26 | ERROR: cannot drop rangetype "public.integerrange" because it is used in period "p" on table "dp" 27 | CONTEXT: PL/pgSQL function periods.drop_protection() line 56 at RAISE 28 | /* system_time_periods */ 29 | SELECT periods.add_system_time_period('dp', excluded_column_names => ARRAY['x']); 30 | add_system_time_period 31 | ------------------------ 32 | t 33 | (1 row) 34 | 35 | ALTER TABLE dp DROP COLUMN x; -- fails 36 | ERROR: cannot drop or rename column "x" on table "dp" because it is excluded from SYSTEM VERSIONING 37 | CONTEXT: PL/pgSQL function periods.drop_protection() line 124 at RAISE 38 | ALTER TABLE dp DROP CONSTRAINT dp_system_time_end_infinity_check; -- fails 39 | ERROR: cannot drop constraint "dp_system_time_end_infinity_check" on table "dp" because it is used in SYSTEM_TIME period 40 | CONTEXT: PL/pgSQL function periods.drop_protection() line 72 at RAISE 41 | DROP TRIGGER dp_system_time_generated_always ON dp; -- fails 42 | ERROR: cannot drop trigger "dp_system_time_generated_always" on table "dp" because it is used in SYSTEM_TIME period 43 | CONTEXT: PL/pgSQL function periods.drop_protection() line 84 at RAISE 44 | DROP TRIGGER dp_system_time_write_history ON dp; -- fails 45 | ERROR: cannot drop trigger "dp_system_time_write_history" on table "dp" because it is used in SYSTEM_TIME period 46 | CONTEXT: PL/pgSQL function periods.drop_protection() line 96 at RAISE 47 | DROP TRIGGER dp_truncate ON dp; -- fails 48 | ERROR: cannot drop trigger "dp_truncate" on table "dp" because it is used in SYSTEM_TIME period 49 | CONTEXT: PL/pgSQL function periods.drop_protection() line 108 at RAISE 50 | /* for_portion_views */ 51 | ALTER TABLE dp ADD CONSTRAINT dp_pkey PRIMARY KEY (id); 52 | SELECT periods.add_for_portion_view('dp', 'p'); 53 | add_for_portion_view 54 | ---------------------- 55 | t 56 | (1 row) 57 | 58 | DROP VIEW dp__for_portion_of_p; 59 | ERROR: cannot drop view "public.dp__for_portion_of_p", call "periods.drop_for_portion_view()" instead 60 | CONTEXT: PL/pgSQL function periods.drop_protection() line 141 at RAISE 61 | DROP TRIGGER for_portion_of_p ON dp__for_portion_of_p; 62 | ERROR: cannot drop trigger "for_portion_of_p" on view "dp__for_portion_of_p" because it is used in FOR PORTION OF view for period "p" on table "dp" 63 | CONTEXT: PL/pgSQL function periods.drop_protection() line 153 at RAISE 64 | ALTER TABLE dp DROP CONSTRAINT dp_pkey; 65 | ERROR: cannot drop primary key on table "dp" because it has a FOR PORTION OF view for period "p" 66 | CONTEXT: PL/pgSQL function periods.drop_protection() line 165 at RAISE 67 | SELECT periods.drop_for_portion_view('dp', 'p'); 68 | drop_for_portion_view 69 | ----------------------- 70 | t 71 | (1 row) 72 | 73 | ALTER TABLE dp DROP CONSTRAINT dp_pkey; 74 | /* unique_keys */ 75 | ALTER TABLE dp 76 | ADD CONSTRAINT u UNIQUE (id, s, e), 77 | ADD CONSTRAINT x EXCLUDE USING gist (id WITH =, integerrange(s, e, '[)') WITH &&); 78 | SELECT periods.add_unique_key('dp', ARRAY['id'], 'p', 'k', 'u', 'x'); 79 | add_unique_key 80 | ---------------- 81 | k 82 | (1 row) 83 | 84 | ALTER TABLE dp DROP CONSTRAINT u; -- fails 85 | ERROR: cannot drop constraint "u" on table "dp" because it is used in period unique key "k" 86 | CONTEXT: PL/pgSQL function periods.drop_protection() line 186 at RAISE 87 | ALTER TABLE dp DROP CONSTRAINT x; -- fails 88 | ERROR: cannot drop constraint "x" on table "dp" because it is used in period unique key "k" 89 | CONTEXT: PL/pgSQL function periods.drop_protection() line 197 at RAISE 90 | ALTER TABLE dp DROP CONSTRAINT dp_p_check; -- fails 91 | /* foreign_keys */ 92 | CREATE TABLE dp_ref (LIKE dp); 93 | SELECT periods.add_period('dp_ref', 'p', 's', 'e', 'integerrange'); 94 | add_period 95 | ------------ 96 | t 97 | (1 row) 98 | 99 | SELECT periods.add_foreign_key('dp_ref', ARRAY['id'], 'p', 'k', key_name => 'f'); 100 | add_foreign_key 101 | ----------------- 102 | f 103 | (1 row) 104 | 105 | DROP TRIGGER f_fk_insert ON dp_ref; -- fails 106 | ERROR: cannot drop trigger "f_fk_insert" on table "dp_ref" because it is used in period foreign key "f" 107 | CONTEXT: PL/pgSQL function periods.drop_protection() line 213 at RAISE 108 | DROP TRIGGER f_fk_update ON dp_ref; -- fails 109 | ERROR: cannot drop trigger "f_fk_update" on table "dp_ref" because it is used in period foreign key "f" 110 | CONTEXT: PL/pgSQL function periods.drop_protection() line 224 at RAISE 111 | DROP TRIGGER f_uk_update ON dp; -- fails 112 | ERROR: cannot drop trigger "f_uk_update" on table "dp" because it is used in period foreign key "f" 113 | CONTEXT: PL/pgSQL function periods.drop_protection() line 236 at RAISE 114 | DROP TRIGGER f_uk_delete ON dp; -- fails 115 | ERROR: cannot drop trigger "f_uk_delete" on table "dp" because it is used in period foreign key "f" 116 | CONTEXT: PL/pgSQL function periods.drop_protection() line 248 at RAISE 117 | SELECT periods.drop_foreign_key('dp_ref', 'f'); 118 | drop_foreign_key 119 | ------------------ 120 | t 121 | (1 row) 122 | 123 | DROP TABLE dp_ref; 124 | /* system_versioning */ 125 | SELECT periods.add_system_versioning('dp'); 126 | NOTICE: history table "dp_history" created for "dp", be sure to index it properly 127 | add_system_versioning 128 | ----------------------- 129 | 130 | (1 row) 131 | 132 | -- Note: The history table is protected by the history view and the history 133 | -- view is protected by the temporal functions. 134 | DROP TABLE dp_history CASCADE; 135 | NOTICE: drop cascades to 5 other objects 136 | DETAIL: drop cascades to view dp_with_history 137 | drop cascades to function dp__as_of(timestamp with time zone) 138 | drop cascades to function dp__between(timestamp with time zone,timestamp with time zone) 139 | drop cascades to function dp__between_symmetric(timestamp with time zone,timestamp with time zone) 140 | drop cascades to function dp__from_to(timestamp with time zone,timestamp with time zone) 141 | ERROR: cannot drop table "public.dp_history" because it is used in SYSTEM VERSIONING for table "dp" 142 | CONTEXT: PL/pgSQL function periods.drop_protection() line 264 at RAISE 143 | DROP VIEW dp_with_history CASCADE; 144 | NOTICE: drop cascades to 4 other objects 145 | DETAIL: drop cascades to function dp__as_of(timestamp with time zone) 146 | drop cascades to function dp__between(timestamp with time zone,timestamp with time zone) 147 | drop cascades to function dp__between_symmetric(timestamp with time zone,timestamp with time zone) 148 | drop cascades to function dp__from_to(timestamp with time zone,timestamp with time zone) 149 | ERROR: cannot drop view "public.dp_with_history" because it is used in SYSTEM VERSIONING for table "dp" 150 | CONTEXT: PL/pgSQL function periods.drop_protection() line 276 at RAISE 151 | DROP FUNCTION dp__as_of(timestamp with time zone); 152 | ERROR: cannot drop function "public.dp__as_of(timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "dp" 153 | CONTEXT: PL/pgSQL function periods.drop_protection() line 288 at RAISE 154 | DROP FUNCTION dp__between(timestamp with time zone,timestamp with time zone); 155 | ERROR: cannot drop function "public.dp__between(timestamp with time zone,timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "dp" 156 | CONTEXT: PL/pgSQL function periods.drop_protection() line 288 at RAISE 157 | DROP FUNCTION dp__between_symmetric(timestamp with time zone,timestamp with time zone); 158 | ERROR: cannot drop function "public.dp__between_symmetric(timestamp with time zone,timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "dp" 159 | CONTEXT: PL/pgSQL function periods.drop_protection() line 288 at RAISE 160 | DROP FUNCTION dp__from_to(timestamp with time zone,timestamp with time zone); 161 | ERROR: cannot drop function "public.dp__from_to(timestamp with time zone,timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "dp" 162 | CONTEXT: PL/pgSQL function periods.drop_protection() line 288 at RAISE 163 | SELECT periods.drop_system_versioning('dp', purge => true); 164 | drop_system_versioning 165 | ------------------------ 166 | t 167 | (1 row) 168 | 169 | DROP TABLE dp; 170 | DROP TYPE integerrange; 171 | -------------------------------------------------------------------------------- /expected/predicates.out: -------------------------------------------------------------------------------- 1 | /* Run tests as unprivileged user */ 2 | SET ROLE TO periods_unprivileged_user; 3 | CREATE TABLE preds (s integer, e integer); 4 | SELECT periods.add_period('preds', 'p', 's', 'e'); 5 | add_period 6 | ------------ 7 | t 8 | (1 row) 9 | 10 | INSERT INTO preds (s, e) VALUES (100, 200); 11 | ANALYZE preds; 12 | /* Ensure the functions are inlined. */ 13 | EXPLAIN (COSTS OFF) SELECT * FROM preds WHERE periods.contains(s, e, 100); 14 | QUERY PLAN 15 | -------------------------------------- 16 | Seq Scan on preds 17 | Filter: ((s <= 100) AND (e > 100)) 18 | (2 rows) 19 | 20 | EXPLAIN (COSTS OFF) SELECT * FROM preds WHERE periods.contains(s, e, 100, 200); 21 | QUERY PLAN 22 | --------------------------------------- 23 | Seq Scan on preds 24 | Filter: ((s <= 100) AND (e >= 200)) 25 | (2 rows) 26 | 27 | EXPLAIN (COSTS OFF) SELECT * FROM preds WHERE periods.equals(s, e, 100, 200); 28 | QUERY PLAN 29 | ------------------------------------- 30 | Seq Scan on preds 31 | Filter: ((s = 100) AND (e = 200)) 32 | (2 rows) 33 | 34 | EXPLAIN (COSTS OFF) SELECT * FROM preds WHERE periods.overlaps(s, e, 100, 200); 35 | QUERY PLAN 36 | ------------------------------------- 37 | Seq Scan on preds 38 | Filter: ((s < 200) AND (e > 100)) 39 | (2 rows) 40 | 41 | EXPLAIN (COSTS OFF) SELECT * FROM preds WHERE periods.precedes(s, e, 100, 200); 42 | QUERY PLAN 43 | ---------------------- 44 | Seq Scan on preds 45 | Filter: (e <= 100) 46 | (2 rows) 47 | 48 | EXPLAIN (COSTS OFF) SELECT * FROM preds WHERE periods.succeeds(s, e, 100, 200); 49 | QUERY PLAN 50 | ---------------------- 51 | Seq Scan on preds 52 | Filter: (s >= 200) 53 | (2 rows) 54 | 55 | EXPLAIN (COSTS OFF) SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 100, 200); 56 | QUERY PLAN 57 | --------------------- 58 | Seq Scan on preds 59 | Filter: (e = 100) 60 | (2 rows) 61 | 62 | EXPLAIN (COSTS OFF) SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 100, 200); 63 | QUERY PLAN 64 | --------------------- 65 | Seq Scan on preds 66 | Filter: (s = 200) 67 | (2 rows) 68 | 69 | /* Now make sure they work! */ 70 | SELECT * FROM preds WHERE periods.contains(s, e, 0); 71 | s | e 72 | ---+--- 73 | (0 rows) 74 | 75 | SELECT * FROM preds WHERE periods.contains(s, e, 150); 76 | s | e 77 | -----+----- 78 | 100 | 200 79 | (1 row) 80 | 81 | SELECT * FROM preds WHERE periods.contains(s, e, 300); 82 | s | e 83 | ---+--- 84 | (0 rows) 85 | 86 | SELECT * FROM preds WHERE periods.contains(s, e, 0, 50); 87 | s | e 88 | ---+--- 89 | (0 rows) 90 | 91 | SELECT * FROM preds WHERE periods.contains(s, e, 50, 100); 92 | s | e 93 | ---+--- 94 | (0 rows) 95 | 96 | SELECT * FROM preds WHERE periods.contains(s, e, 100, 150); 97 | s | e 98 | -----+----- 99 | 100 | 200 100 | (1 row) 101 | 102 | SELECT * FROM preds WHERE periods.contains(s, e, 150, 200); 103 | s | e 104 | -----+----- 105 | 100 | 200 106 | (1 row) 107 | 108 | SELECT * FROM preds WHERE periods.contains(s, e, 200, 250); 109 | s | e 110 | ---+--- 111 | (0 rows) 112 | 113 | SELECT * FROM preds WHERE periods.contains(s, e, 250, 300); 114 | s | e 115 | ---+--- 116 | (0 rows) 117 | 118 | SELECT * FROM preds WHERE periods.contains(s, e, 125, 175); 119 | s | e 120 | -----+----- 121 | 100 | 200 122 | (1 row) 123 | 124 | SELECT * FROM preds WHERE periods.contains(s, e, 0, 300); 125 | s | e 126 | ---+--- 127 | (0 rows) 128 | 129 | SELECT * FROM preds WHERE periods.equals(s, e, 0, 100); 130 | s | e 131 | ---+--- 132 | (0 rows) 133 | 134 | SELECT * FROM preds WHERE periods.equals(s, e, 100, 200); 135 | s | e 136 | -----+----- 137 | 100 | 200 138 | (1 row) 139 | 140 | SELECT * FROM preds WHERE periods.equals(s, e, 200, 300); 141 | s | e 142 | ---+--- 143 | (0 rows) 144 | 145 | SELECT * FROM preds WHERE periods.overlaps(s, e, 0, 50); 146 | s | e 147 | ---+--- 148 | (0 rows) 149 | 150 | SELECT * FROM preds WHERE periods.overlaps(s, e, 50, 100); 151 | s | e 152 | ---+--- 153 | (0 rows) 154 | 155 | SELECT * FROM preds WHERE periods.overlaps(s, e, 100, 150); 156 | s | e 157 | -----+----- 158 | 100 | 200 159 | (1 row) 160 | 161 | SELECT * FROM preds WHERE periods.overlaps(s, e, 150, 200); 162 | s | e 163 | -----+----- 164 | 100 | 200 165 | (1 row) 166 | 167 | SELECT * FROM preds WHERE periods.overlaps(s, e, 200, 250); 168 | s | e 169 | ---+--- 170 | (0 rows) 171 | 172 | SELECT * FROM preds WHERE periods.overlaps(s, e, 250, 300); 173 | s | e 174 | ---+--- 175 | (0 rows) 176 | 177 | SELECT * FROM preds WHERE periods.overlaps(s, e, 125, 175); 178 | s | e 179 | -----+----- 180 | 100 | 200 181 | (1 row) 182 | 183 | SELECT * FROM preds WHERE periods.overlaps(s, e, 0, 300); 184 | s | e 185 | -----+----- 186 | 100 | 200 187 | (1 row) 188 | 189 | SELECT * FROM preds WHERE periods.precedes(s, e, 0, 50); 190 | s | e 191 | ---+--- 192 | (0 rows) 193 | 194 | SELECT * FROM preds WHERE periods.precedes(s, e, 50, 100); 195 | s | e 196 | ---+--- 197 | (0 rows) 198 | 199 | SELECT * FROM preds WHERE periods.precedes(s, e, 100, 150); 200 | s | e 201 | ---+--- 202 | (0 rows) 203 | 204 | SELECT * FROM preds WHERE periods.precedes(s, e, 150, 200); 205 | s | e 206 | ---+--- 207 | (0 rows) 208 | 209 | SELECT * FROM preds WHERE periods.precedes(s, e, 200, 250); 210 | s | e 211 | -----+----- 212 | 100 | 200 213 | (1 row) 214 | 215 | SELECT * FROM preds WHERE periods.precedes(s, e, 250, 300); 216 | s | e 217 | -----+----- 218 | 100 | 200 219 | (1 row) 220 | 221 | SELECT * FROM preds WHERE periods.precedes(s, e, 125, 175); 222 | s | e 223 | ---+--- 224 | (0 rows) 225 | 226 | SELECT * FROM preds WHERE periods.precedes(s, e, 0, 300); 227 | s | e 228 | ---+--- 229 | (0 rows) 230 | 231 | SELECT * FROM preds WHERE periods.succeeds(s, e, 0, 50); 232 | s | e 233 | -----+----- 234 | 100 | 200 235 | (1 row) 236 | 237 | SELECT * FROM preds WHERE periods.succeeds(s, e, 50, 100); 238 | s | e 239 | -----+----- 240 | 100 | 200 241 | (1 row) 242 | 243 | SELECT * FROM preds WHERE periods.succeeds(s, e, 100, 150); 244 | s | e 245 | ---+--- 246 | (0 rows) 247 | 248 | SELECT * FROM preds WHERE periods.succeeds(s, e, 150, 200); 249 | s | e 250 | ---+--- 251 | (0 rows) 252 | 253 | SELECT * FROM preds WHERE periods.succeeds(s, e, 200, 250); 254 | s | e 255 | ---+--- 256 | (0 rows) 257 | 258 | SELECT * FROM preds WHERE periods.succeeds(s, e, 250, 300); 259 | s | e 260 | ---+--- 261 | (0 rows) 262 | 263 | SELECT * FROM preds WHERE periods.succeeds(s, e, 125, 175); 264 | s | e 265 | ---+--- 266 | (0 rows) 267 | 268 | SELECT * FROM preds WHERE periods.succeeds(s, e, 0, 300); 269 | s | e 270 | ---+--- 271 | (0 rows) 272 | 273 | SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 0, 50); 274 | s | e 275 | ---+--- 276 | (0 rows) 277 | 278 | SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 50, 100); 279 | s | e 280 | ---+--- 281 | (0 rows) 282 | 283 | SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 100, 150); 284 | s | e 285 | ---+--- 286 | (0 rows) 287 | 288 | SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 150, 200); 289 | s | e 290 | ---+--- 291 | (0 rows) 292 | 293 | SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 200, 250); 294 | s | e 295 | -----+----- 296 | 100 | 200 297 | (1 row) 298 | 299 | SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 250, 300); 300 | s | e 301 | ---+--- 302 | (0 rows) 303 | 304 | SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 125, 175); 305 | s | e 306 | ---+--- 307 | (0 rows) 308 | 309 | SELECT * FROM preds WHERE periods.immediately_precedes(s, e, 0, 300); 310 | s | e 311 | ---+--- 312 | (0 rows) 313 | 314 | SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 0, 50); 315 | s | e 316 | ---+--- 317 | (0 rows) 318 | 319 | SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 50, 100); 320 | s | e 321 | -----+----- 322 | 100 | 200 323 | (1 row) 324 | 325 | SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 100, 150); 326 | s | e 327 | ---+--- 328 | (0 rows) 329 | 330 | SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 150, 200); 331 | s | e 332 | ---+--- 333 | (0 rows) 334 | 335 | SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 200, 250); 336 | s | e 337 | ---+--- 338 | (0 rows) 339 | 340 | SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 250, 300); 341 | s | e 342 | ---+--- 343 | (0 rows) 344 | 345 | SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 125, 175); 346 | s | e 347 | ---+--- 348 | (0 rows) 349 | 350 | SELECT * FROM preds WHERE periods.immediately_succeeds(s, e, 0, 300); 351 | s | e 352 | ---+--- 353 | (0 rows) 354 | 355 | DROP TABLE preds; 356 | -------------------------------------------------------------------------------- /sql/acl.sql: -------------------------------------------------------------------------------- 1 | SELECT CASE 2 | WHEN setting::integer >= 170000 THEN '17 ..'::text 3 | WHEN setting::integer >= 110000 THEN '11 .. 16' 4 | WHEN setting::integer >= 90600 THEN '9.6 .. 10' 5 | ELSE '.. 9.5' END 6 | FROM pg_settings WHERE name = 'server_version_num'; 7 | 8 | /* Tests for access control on the history tables */ 9 | 10 | CREATE ROLE periods_acl_1; 11 | CREATE ROLE periods_acl_2; 12 | CREATE ROLE periods_acl_3; 13 | 14 | /* OWNER */ 15 | 16 | -- We call this query several times, so make it a view for eaiser maintenance 17 | CREATE VIEW show_owners AS 18 | SELECT c.relnamespace::regnamespace AS schema_name, 19 | c.relname AS object_name, 20 | CASE c.relkind 21 | WHEN 'r' THEN 'table' 22 | WHEN 'v' THEN 'view' 23 | END AS object_type, 24 | c.relowner::regrole AS owner 25 | FROM pg_class AS c 26 | WHERE c.relnamespace = 'public'::regnamespace 27 | AND c.relname = ANY (ARRAY['owner_test', 'owner_test_history', 'owner_test_with_history', 'owner_test__for_portion_of_p']) 28 | UNION ALL 29 | SELECT p.pronamespace, p.proname, 'function', p.proowner 30 | FROM pg_proc AS p 31 | WHERE p.pronamespace = 'public'::regnamespace 32 | AND p.proname = ANY (ARRAY['owner_test__as_of', 'owner_test__between', 'owner_test__between_symmetric', 'owner_test__from_to']); 33 | 34 | CREATE TABLE owner_test (col text PRIMARY KEY, s integer, e integer); 35 | ALTER TABLE owner_test OWNER TO periods_acl_1; 36 | SELECT periods.add_period('owner_test', 'p', 's', 'e'); 37 | SELECT periods.add_for_portion_view('owner_test', 'p'); 38 | SELECT periods.add_system_time_period('owner_test'); 39 | SELECT periods.add_system_versioning('owner_test'); 40 | TABLE show_owners ORDER BY object_name; 41 | 42 | -- This should change everything 43 | ALTER TABLE owner_test OWNER TO periods_acl_2; 44 | TABLE show_owners ORDER BY object_name; 45 | 46 | -- These should change nothing 47 | ALTER TABLE owner_test_history OWNER TO periods_acl_3; 48 | ALTER VIEW owner_test_with_history OWNER TO periods_acl_3; 49 | ALTER FUNCTION owner_test__as_of(timestamp with time zone) OWNER TO periods_acl_3; 50 | ALTER FUNCTION owner_test__between(timestamp with time zone, timestamp with time zone) OWNER TO periods_acl_3; 51 | ALTER FUNCTION owner_test__between_symmetric(timestamp with time zone, timestamp with time zone) OWNER TO periods_acl_3; 52 | ALTER FUNCTION owner_test__from_to(timestamp with time zone, timestamp with time zone) OWNER TO periods_acl_3; 53 | TABLE show_owners ORDER BY object_name; 54 | 55 | -- This should put the owner back to the base table's owner 56 | SELECT periods.drop_system_versioning('owner_test'); 57 | ALTER TABLE owner_test_history OWNER TO periods_acl_3; 58 | TABLE show_owners ORDER BY object_name; 59 | SELECT periods.add_system_versioning('owner_test'); 60 | TABLE show_owners ORDER BY object_name; 61 | 62 | SELECT periods.drop_system_versioning('owner_test', drop_behavior => 'CASCADE', purge => true); 63 | SELECT periods.drop_for_portion_view('owner_test', NULL); 64 | DROP TABLE owner_test CASCADE; 65 | DROP VIEW show_owners; 66 | 67 | /* FOR PORTION OF ACL */ 68 | 69 | -- We call this query several times, so make it a view for eaiser maintenance 70 | CREATE VIEW show_acls AS 71 | SELECT row_number() OVER (ORDER BY array_position(ARRAY['table', 'view', 'function'], object_type), 72 | schema_name, object_name, grantee, privilege_type) AS sort_order, 73 | * 74 | FROM ( 75 | SELECT c.relnamespace::regnamespace AS schema_name, 76 | c.relname AS object_name, 77 | CASE c.relkind 78 | WHEN 'r' THEN 'table' 79 | WHEN 'v' THEN 'view' 80 | END AS object_type, 81 | acl.grantee::regrole::text AS grantee, 82 | acl.privilege_type 83 | FROM pg_class AS c 84 | CROSS JOIN LATERAL aclexplode(COALESCE(c.relacl, acldefault('r', c.relowner))) AS acl 85 | WHERE c.relname IN ('fpacl', 'fpacl__for_portion_of_p') 86 | ) AS _; 87 | 88 | CREATE TABLE fpacl (col text PRIMARY KEY, s integer, e integer); 89 | ALTER TABLE fpacl OWNER TO periods_acl_1; 90 | SELECT periods.add_period('fpacl', 'p', 's', 'e'); 91 | SELECT periods.add_for_portion_view('fpacl', 'p'); 92 | TABLE show_acls ORDER BY sort_order; 93 | 94 | GRANT SELECT, UPDATE ON TABLE fpacl__for_portion_of_p TO periods_acl_2; -- fail 95 | GRANT SELECT, UPDATE ON TABLE fpacl TO periods_acl_2; 96 | TABLE show_acls ORDER BY sort_order; 97 | 98 | REVOKE UPDATE ON TABLE fpacl__for_portion_of_p FROM periods_acl_2; -- fail 99 | REVOKE UPDATE ON TABLE fpacl FROM periods_acl_2; 100 | TABLE show_acls ORDER BY sort_order; 101 | 102 | SELECT periods.drop_for_portion_view('fpacl', 'p'); 103 | DROP TABLE fpacl CASCADE; 104 | DROP VIEW show_acls; 105 | 106 | /* History ACL */ 107 | 108 | -- We call this query several times, so make it a view for eaiser maintenance 109 | CREATE VIEW show_acls AS 110 | SELECT row_number() OVER (ORDER BY array_position(ARRAY['table', 'view', 'function'], object_type), 111 | schema_name, object_name, grantee, privilege_type) AS sort_order, 112 | * 113 | FROM ( 114 | SELECT c.relnamespace::regnamespace AS schema_name, 115 | c.relname AS object_name, 116 | CASE c.relkind 117 | WHEN 'r' THEN 'table' 118 | WHEN 'v' THEN 'view' 119 | END AS object_type, 120 | acl.grantee::regrole::text AS grantee, 121 | acl.privilege_type 122 | FROM pg_class AS c 123 | CROSS JOIN LATERAL aclexplode(COALESCE(c.relacl, acldefault('r', c.relowner))) AS acl 124 | WHERE c.relname IN ('histacl', 'histacl_history', 'histacl_with_history') 125 | 126 | UNION ALL 127 | 128 | SELECT p.pronamespace::regnamespace, 129 | p.proname, 130 | 'function', 131 | acl.grantee::regrole::text, 132 | acl.privilege_type 133 | FROM pg_proc AS p 134 | CROSS JOIN LATERAL aclexplode(COALESCE(p.proacl, acldefault('f', p.proowner))) AS acl 135 | WHERE p.proname IN ('histacl__as_of', 'histacl__between', 'histacl__between_symmetric', 'histacl__from_to') 136 | ) AS _; 137 | 138 | CREATE TABLE histacl (col text); 139 | ALTER TABLE histacl OWNER TO periods_acl_1; 140 | SELECT periods.add_system_time_period('histacl'); 141 | SELECT periods.add_system_versioning('histacl'); 142 | TABLE show_acls ORDER BY sort_order; 143 | 144 | -- Disconnect, add some privs to the history table, and reconnect 145 | SELECT periods.drop_system_versioning('histacl'); 146 | GRANT ALL ON TABLE histacl_history TO periods_acl_3; 147 | TABLE show_acls ORDER BY sort_order; 148 | SELECT periods.add_system_versioning('histacl'); 149 | TABLE show_acls ORDER BY sort_order; 150 | 151 | -- These next 6 blocks should fail 152 | GRANT ALL ON TABLE histacl_history TO periods_acl_3; -- fail 153 | GRANT SELECT ON TABLE histacl_history TO periods_acl_3; -- fail 154 | REVOKE ALL ON TABLE histacl_history FROM periods_acl_1; -- fail 155 | TABLE show_acls ORDER BY sort_order; 156 | 157 | GRANT ALL ON TABLE histacl_with_history TO periods_acl_3; -- fail 158 | GRANT SELECT ON TABLE histacl_with_history TO periods_acl_3; -- fail 159 | REVOKE ALL ON TABLE histacl_with_history FROM periods_acl_1; -- fail 160 | TABLE show_acls ORDER BY sort_order; 161 | 162 | GRANT ALL ON FUNCTION histacl__as_of(timestamp with time zone) TO periods_acl_3; -- fail 163 | GRANT EXECUTE ON FUNCTION histacl__as_of(timestamp with time zone) TO periods_acl_3; -- fail 164 | REVOKE ALL ON FUNCTION histacl__as_of(timestamp with time zone) FROM periods_acl_1; -- fail 165 | TABLE show_acls ORDER BY sort_order; 166 | 167 | GRANT ALL ON FUNCTION histacl__between(timestamp with time zone, timestamp with time zone) TO periods_acl_3; -- fail 168 | GRANT EXECUTE ON FUNCTION histacl__between(timestamp with time zone, timestamp with time zone) TO periods_acl_3; -- fail 169 | REVOKE ALL ON FUNCTION histacl__between(timestamp with time zone, timestamp with time zone) FROM periods_acl_1; -- fail 170 | TABLE show_acls ORDER BY sort_order; 171 | 172 | GRANT ALL ON FUNCTION histacl__between_symmetric(timestamp with time zone, timestamp with time zone) TO periods_acl_3; -- fail 173 | GRANT EXECUTE ON FUNCTION histacl__between_symmetric(timestamp with time zone, timestamp with time zone) TO periods_acl_3; -- fail 174 | REVOKE ALL ON FUNCTION histacl__between_symmetric(timestamp with time zone, timestamp with time zone) FROM periods_acl_1; -- fail 175 | TABLE show_acls ORDER BY sort_order; 176 | 177 | GRANT ALL ON FUNCTION histacl__from_to(timestamp with time zone, timestamp with time zone) TO periods_acl_3; -- fail 178 | GRANT EXECUTE ON FUNCTION histacl__from_to(timestamp with time zone, timestamp with time zone) TO periods_acl_3; -- fail 179 | REVOKE ALL ON FUNCTION histacl__from_to(timestamp with time zone, timestamp with time zone) FROM periods_acl_1; -- fail 180 | TABLE show_acls ORDER BY sort_order; 181 | 182 | -- This one should work and propagate 183 | GRANT ALL ON TABLE histacl TO periods_acl_2; 184 | TABLE show_acls ORDER BY sort_order; 185 | REVOKE SELECT ON TABLE histacl FROM periods_acl_2; 186 | TABLE show_acls ORDER BY sort_order; 187 | 188 | SELECT periods.drop_system_versioning('histacl', drop_behavior => 'CASCADE', purge => true); 189 | DROP TABLE histacl CASCADE; 190 | DROP VIEW show_acls; 191 | 192 | /* Who can modify the history table? */ 193 | 194 | CREATE TABLE retention (value integer); 195 | ALTER TABLE retention OWNER TO periods_acl_1; 196 | REVOKE ALL ON TABLE retention FROM PUBLIC; 197 | GRANT ALL ON TABLE retention TO periods_acl_2; 198 | GRANT SELECT ON TABLE retention TO periods_acl_3; 199 | SELECT periods.add_system_time_period('retention'); 200 | SELECT periods.add_system_versioning('retention'); 201 | 202 | INSERT INTO retention (value) VALUES (1); 203 | UPDATE retention SET value = 2; 204 | 205 | SET ROLE TO periods_acl_3; 206 | DELETE FROM retention_history; -- fail 207 | SET ROLE TO periods_acl_2; 208 | DELETE FROM retention_history; -- fail 209 | SET ROLE TO periods_acl_1; 210 | DELETE FROM retention_history; -- fail 211 | 212 | -- test what the docs say to do 213 | BEGIN; 214 | SELECT periods.drop_system_versioning('retention'); 215 | GRANT DELETE ON TABLE retention_history TO CURRENT_USER; 216 | DELETE FROM retention_history; 217 | SELECT periods.add_system_versioning('retention'); 218 | COMMIT; 219 | 220 | -- superuser can do anything 221 | RESET ROLE; 222 | DELETE FROM retention_history; 223 | 224 | SELECT periods.drop_system_versioning('retention', drop_behavior => 'CASCADE', purge => true); 225 | DROP TABLE retention CASCADE; 226 | 227 | /* Clean up */ 228 | 229 | DROP ROLE periods_acl_1; 230 | DROP ROLE periods_acl_2; 231 | DROP ROLE periods_acl_3; 232 | -------------------------------------------------------------------------------- /expected/system_time_periods_1.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | pre_96 4 | -------- 5 | t 6 | (1 row) 7 | 8 | /* Run tests as unprivileged user */ 9 | SET ROLE TO periods_unprivileged_user; 10 | /* SYSTEM_TIME with date */ 11 | BEGIN; 12 | SELECT transaction_timestamp()::date AS xd, 13 | transaction_timestamp()::timestamp AS xts, 14 | transaction_timestamp() AS xtstz 15 | \gset 16 | CREATE TABLE sysver_date (val text, start_date date, end_date date); 17 | SELECT periods.add_system_time_period('sysver_date', 'start_date', 'end_date'); 18 | add_system_time_period 19 | ------------------------ 20 | t 21 | (1 row) 22 | 23 | TABLE periods.periods; 24 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 25 | -------------+-------------+-------------------+-----------------+------------+------------------------------- 26 | sysver_date | system_time | start_date | end_date | daterange | sysver_date_system_time_check 27 | (1 row) 28 | 29 | INSERT INTO sysver_date DEFAULT VALUES; 30 | SELECT val, start_date = :'xd' AS start_date_eq, end_date FROM sysver_date; 31 | val | start_date_eq | end_date 32 | -----+---------------+---------- 33 | | t | infinity 34 | (1 row) 35 | 36 | DROP TABLE sysver_date; 37 | /* SYSTEM_TIME with timestamp without time zone */ 38 | CREATE TABLE sysver_ts (val text, start_ts timestamp without time zone, end_ts timestamp without time zone); 39 | SELECT periods.add_system_time_period('sysver_ts', 'start_ts', 'end_ts'); 40 | add_system_time_period 41 | ------------------------ 42 | t 43 | (1 row) 44 | 45 | TABLE periods.periods; 46 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 47 | ------------+-------------+-------------------+-----------------+------------+----------------------------- 48 | sysver_ts | system_time | start_ts | end_ts | tsrange | sysver_ts_system_time_check 49 | (1 row) 50 | 51 | INSERT INTO sysver_ts DEFAULT VALUES; 52 | SELECT val, start_ts = :'xts' AS start_ts_eq, end_ts FROM sysver_ts; 53 | val | start_ts_eq | end_ts 54 | -----+-------------+---------- 55 | | t | infinity 56 | (1 row) 57 | 58 | DROP TABLE sysver_ts; 59 | /* SYSTEM_TIME with timestamp with time zone */ 60 | CREATE TABLE sysver_tstz (val text, start_tstz timestamp with time zone, end_tstz timestamp with time zone); 61 | SELECT periods.add_system_time_period('sysver_tstz', 'start_tstz', 'end_tstz'); 62 | add_system_time_period 63 | ------------------------ 64 | t 65 | (1 row) 66 | 67 | TABLE periods.periods; 68 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 69 | -------------+-------------+-------------------+-----------------+------------+------------------------------- 70 | sysver_tstz | system_time | start_tstz | end_tstz | tstzrange | sysver_tstz_system_time_check 71 | (1 row) 72 | 73 | INSERT INTO sysver_tstz DEFAULT VALUES; 74 | SELECT val, start_tstz = :'xtstz' AS start_tstz_eq, end_tstz FROM sysver_tstz; 75 | val | start_tstz_eq | end_tstz 76 | -----+---------------+---------- 77 | | t | infinity 78 | (1 row) 79 | 80 | DROP TABLE sysver_tstz; 81 | COMMIT; 82 | /* Basic SYSTEM_TIME periods with CASCADE/purge */ 83 | CREATE TABLE sysver (val text); 84 | SELECT periods.add_system_time_period('sysver', 'startname'); 85 | add_system_time_period 86 | ------------------------ 87 | t 88 | (1 row) 89 | 90 | SELECT periods.drop_period('sysver', 'system_time', drop_behavior => 'CASCADE', purge => true); 91 | drop_period 92 | ------------- 93 | t 94 | (1 row) 95 | 96 | SELECT periods.add_system_time_period('sysver', end_column_name => 'endname'); 97 | add_system_time_period 98 | ------------------------ 99 | t 100 | (1 row) 101 | 102 | SELECT periods.drop_period('sysver', 'system_time', drop_behavior => 'CASCADE', purge => true); 103 | drop_period 104 | ------------- 105 | t 106 | (1 row) 107 | 108 | SELECT periods.add_system_time_period('sysver', 'startname', 'endname'); 109 | add_system_time_period 110 | ------------------------ 111 | t 112 | (1 row) 113 | 114 | TABLE periods.periods; 115 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 116 | ------------+-------------+-------------------+-----------------+------------+-------------------------- 117 | sysver | system_time | startname | endname | tstzrange | sysver_system_time_check 118 | (1 row) 119 | 120 | TABLE periods.system_time_periods; 121 | table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names 122 | ------------+-------------+-------------------------------+-------------------------------------+----------------------------------+------------------+----------------------- 123 | sysver | system_time | sysver_endname_infinity_check | sysver_system_time_generated_always | sysver_system_time_write_history | sysver_truncate | {} 124 | (1 row) 125 | 126 | SELECT periods.drop_system_time_period('sysver', drop_behavior => 'CASCADE', purge => true); 127 | drop_system_time_period 128 | ------------------------- 129 | t 130 | (1 row) 131 | 132 | SELECT periods.add_system_time_period('sysver', 'endname', 'startname', 133 | bounds_check_constraint => 'b', 134 | infinity_check_constraint => 'i', 135 | generated_always_trigger => 'g', 136 | write_history_trigger => 'w', 137 | truncate_trigger => 't'); 138 | add_system_time_period 139 | ------------------------ 140 | t 141 | (1 row) 142 | 143 | TABLE periods.periods; 144 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 145 | ------------+-------------+-------------------+-----------------+------------+------------------------- 146 | sysver | system_time | endname | startname | tstzrange | b 147 | (1 row) 148 | 149 | TABLE periods.system_time_periods; 150 | table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names 151 | ------------+-------------+---------------------------+--------------------------+-----------------------+------------------+----------------------- 152 | sysver | system_time | i | g | w | t | {} 153 | (1 row) 154 | 155 | SELECT periods.drop_system_time_period('sysver', drop_behavior => 'CASCADE', purge => true); 156 | drop_system_time_period 157 | ------------------------- 158 | t 159 | (1 row) 160 | 161 | SELECT periods.add_system_time_period('sysver'); 162 | add_system_time_period 163 | ------------------------ 164 | t 165 | (1 row) 166 | 167 | DROP TABLE sysver; 168 | TABLE periods.periods; 169 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 170 | ------------+-------------+-------------------+-----------------+------------+------------------------- 171 | (0 rows) 172 | 173 | TABLE periods.system_time_periods; 174 | table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names 175 | ------------+-------------+---------------------------+--------------------------+-----------------------+------------------+----------------------- 176 | (0 rows) 177 | 178 | /* Forbid UNIQUE keys on system_time columns */ 179 | CREATE TABLE no_unique (col1 timestamp with time zone, s bigint, e bigint); 180 | SELECT periods.add_period('no_unique', 'p', 's', 'e'); 181 | add_period 182 | ------------ 183 | t 184 | (1 row) 185 | 186 | SELECT periods.add_unique_key('no_unique', ARRAY['col1'], 'p'); -- passes 187 | add_unique_key 188 | ------------------ 189 | no_unique_col1_p 190 | (1 row) 191 | 192 | SELECT periods.add_system_time_period('no_unique'); 193 | add_system_time_period 194 | ------------------------ 195 | t 196 | (1 row) 197 | 198 | SELECT periods.add_unique_key('no_unique', ARRAY['system_time_start'], 'p'); -- fails 199 | ERROR: columns in period for SYSTEM_TIME are not allowed in UNIQUE keys 200 | SELECT periods.add_unique_key('no_unique', ARRAY['system_time_end'], 'p'); -- fails 201 | ERROR: columns in period for SYSTEM_TIME are not allowed in UNIQUE keys 202 | SELECT periods.add_unique_key('no_unique', ARRAY['col1'], 'system_time'); -- fails 203 | ERROR: periods for SYSTEM_TIME are not allowed in UNIQUE keys 204 | SELECT periods.drop_system_time_period('no_unique'); 205 | drop_system_time_period 206 | ------------------------- 207 | t 208 | (1 row) 209 | 210 | SELECT periods.add_unique_key('no_unique', ARRAY['system_time_start'], 'p'); -- passes 211 | add_unique_key 212 | ------------------------------- 213 | no_unique_system_time_start_p 214 | (1 row) 215 | 216 | SELECT periods.add_unique_key('no_unique', ARRAY['system_time_end'], 'p'); -- passes 217 | add_unique_key 218 | ----------------------------- 219 | no_unique_system_time_end_p 220 | (1 row) 221 | 222 | SELECT periods.add_system_time_period('no_unique'); -- fails 223 | ERROR: columns in period for SYSTEM_TIME are not allowed in UNIQUE keys 224 | SELECT periods.drop_unique_key('no_unique', 'no_unique_system_time_start_p'); 225 | drop_unique_key 226 | ----------------- 227 | 228 | (1 row) 229 | 230 | SELECT periods.drop_unique_key('no_unique', 'no_unique_system_time_end_p'); 231 | drop_unique_key 232 | ----------------- 233 | 234 | (1 row) 235 | 236 | /* Forbid foreign keys on system_time columns */ 237 | CREATE TABLE no_unique_ref (LIKE no_unique); 238 | SELECT periods.add_period('no_unique_ref', 'q', 's', 'e'); 239 | add_period 240 | ------------ 241 | t 242 | (1 row) 243 | 244 | SELECT periods.add_system_time_period('no_unique_ref'); 245 | add_system_time_period 246 | ------------------------ 247 | t 248 | (1 row) 249 | 250 | SELECT periods.add_foreign_key('no_unique_ref', ARRAY['system_time_start'], 'q', 'no_unique_col1_p'); -- fails 251 | ERROR: columns in period for SYSTEM_TIME are not allowed in UNIQUE keys 252 | SELECT periods.add_foreign_key('no_unique_ref', ARRAY['system_time_end'], 'q', 'no_unique_col1_p'); -- fails 253 | ERROR: columns in period for SYSTEM_TIME are not allowed in UNIQUE keys 254 | SELECT periods.add_foreign_key('no_unique_ref', ARRAY['col1'], 'system_time', 'no_unique_col1_p'); -- fails 255 | ERROR: periods for SYSTEM_TIME are not allowed in foreign keys 256 | SELECT periods.drop_system_time_period('no_unique_ref'); 257 | drop_system_time_period 258 | ------------------------- 259 | t 260 | (1 row) 261 | 262 | SELECT periods.add_foreign_key('no_unique_ref', ARRAY['system_time_start'], 'q', 'no_unique_col1_p'); -- passes 263 | add_foreign_key 264 | ----------------------------------- 265 | no_unique_ref_system_time_start_q 266 | (1 row) 267 | 268 | SELECT periods.add_foreign_key('no_unique_ref', ARRAY['system_time_end'], 'q', 'no_unique_col1_p'); -- passes 269 | add_foreign_key 270 | --------------------------------- 271 | no_unique_ref_system_time_end_q 272 | (1 row) 273 | 274 | SELECT periods.add_system_time_period('no_unique_ref'); -- fails 275 | ERROR: columns for SYSTEM_TIME must not be part of foreign keys 276 | DROP TABLE no_unique, no_unique_ref; 277 | -------------------------------------------------------------------------------- /expected/system_time_periods.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | pre_96 4 | -------- 5 | f 6 | (1 row) 7 | 8 | /* Run tests as unprivileged user */ 9 | SET ROLE TO periods_unprivileged_user; 10 | /* SYSTEM_TIME with date */ 11 | BEGIN; 12 | SELECT transaction_timestamp()::date AS xd, 13 | transaction_timestamp()::timestamp AS xts, 14 | transaction_timestamp() AS xtstz 15 | \gset 16 | CREATE TABLE sysver_date (val text, start_date date, end_date date); 17 | SELECT periods.add_system_time_period('sysver_date', 'start_date', 'end_date'); 18 | add_system_time_period 19 | ------------------------ 20 | t 21 | (1 row) 22 | 23 | TABLE periods.periods; 24 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 25 | -------------+-------------+-------------------+-----------------+------------+------------------------------- 26 | sysver_date | system_time | start_date | end_date | daterange | sysver_date_system_time_check 27 | (1 row) 28 | 29 | INSERT INTO sysver_date DEFAULT VALUES; 30 | SELECT val, start_date = :'xd' AS start_date_eq, end_date FROM sysver_date; 31 | val | start_date_eq | end_date 32 | -----+---------------+---------- 33 | | t | infinity 34 | (1 row) 35 | 36 | DROP TABLE sysver_date; 37 | /* SYSTEM_TIME with timestamp without time zone */ 38 | CREATE TABLE sysver_ts (val text, start_ts timestamp without time zone, end_ts timestamp without time zone); 39 | SELECT periods.add_system_time_period('sysver_ts', 'start_ts', 'end_ts'); 40 | add_system_time_period 41 | ------------------------ 42 | t 43 | (1 row) 44 | 45 | TABLE periods.periods; 46 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 47 | ------------+-------------+-------------------+-----------------+------------+----------------------------- 48 | sysver_ts | system_time | start_ts | end_ts | tsrange | sysver_ts_system_time_check 49 | (1 row) 50 | 51 | INSERT INTO sysver_ts DEFAULT VALUES; 52 | SELECT val, start_ts = :'xts' AS start_ts_eq, end_ts FROM sysver_ts; 53 | val | start_ts_eq | end_ts 54 | -----+-------------+---------- 55 | | t | infinity 56 | (1 row) 57 | 58 | DROP TABLE sysver_ts; 59 | /* SYSTEM_TIME with timestamp with time zone */ 60 | CREATE TABLE sysver_tstz (val text, start_tstz timestamp with time zone, end_tstz timestamp with time zone); 61 | SELECT periods.add_system_time_period('sysver_tstz', 'start_tstz', 'end_tstz'); 62 | add_system_time_period 63 | ------------------------ 64 | t 65 | (1 row) 66 | 67 | TABLE periods.periods; 68 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 69 | -------------+-------------+-------------------+-----------------+------------+------------------------------- 70 | sysver_tstz | system_time | start_tstz | end_tstz | tstzrange | sysver_tstz_system_time_check 71 | (1 row) 72 | 73 | INSERT INTO sysver_tstz DEFAULT VALUES; 74 | SELECT val, start_tstz = :'xtstz' AS start_tstz_eq, end_tstz FROM sysver_tstz; 75 | val | start_tstz_eq | end_tstz 76 | -----+---------------+---------- 77 | | t | infinity 78 | (1 row) 79 | 80 | DROP TABLE sysver_tstz; 81 | COMMIT; 82 | /* Basic SYSTEM_TIME periods with CASCADE/purge */ 83 | CREATE TABLE sysver (val text); 84 | SELECT periods.add_system_time_period('sysver', 'startname'); 85 | add_system_time_period 86 | ------------------------ 87 | t 88 | (1 row) 89 | 90 | SELECT periods.drop_period('sysver', 'system_time', drop_behavior => 'CASCADE', purge => true); 91 | drop_period 92 | ------------- 93 | t 94 | (1 row) 95 | 96 | SELECT periods.add_system_time_period('sysver', end_column_name => 'endname'); 97 | add_system_time_period 98 | ------------------------ 99 | t 100 | (1 row) 101 | 102 | SELECT periods.drop_period('sysver', 'system_time', drop_behavior => 'CASCADE', purge => true); 103 | drop_period 104 | ------------- 105 | t 106 | (1 row) 107 | 108 | SELECT periods.add_system_time_period('sysver', 'startname', 'endname'); 109 | add_system_time_period 110 | ------------------------ 111 | t 112 | (1 row) 113 | 114 | TABLE periods.periods; 115 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 116 | ------------+-------------+-------------------+-----------------+------------+-------------------------- 117 | sysver | system_time | startname | endname | tstzrange | sysver_system_time_check 118 | (1 row) 119 | 120 | TABLE periods.system_time_periods; 121 | table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names 122 | ------------+-------------+-------------------------------+-------------------------------------+----------------------------------+------------------+----------------------- 123 | sysver | system_time | sysver_endname_infinity_check | sysver_system_time_generated_always | sysver_system_time_write_history | sysver_truncate | {} 124 | (1 row) 125 | 126 | SELECT periods.drop_system_time_period('sysver', drop_behavior => 'CASCADE', purge => true); 127 | drop_system_time_period 128 | ------------------------- 129 | t 130 | (1 row) 131 | 132 | SELECT periods.add_system_time_period('sysver', 'endname', 'startname', 133 | bounds_check_constraint => 'b', 134 | infinity_check_constraint => 'i', 135 | generated_always_trigger => 'g', 136 | write_history_trigger => 'w', 137 | truncate_trigger => 't'); 138 | add_system_time_period 139 | ------------------------ 140 | t 141 | (1 row) 142 | 143 | TABLE periods.periods; 144 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 145 | ------------+-------------+-------------------+-----------------+------------+------------------------- 146 | sysver | system_time | endname | startname | tstzrange | b 147 | (1 row) 148 | 149 | TABLE periods.system_time_periods; 150 | table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names 151 | ------------+-------------+---------------------------+--------------------------+-----------------------+------------------+----------------------- 152 | sysver | system_time | i | g | w | t | {} 153 | (1 row) 154 | 155 | SELECT periods.drop_system_time_period('sysver', drop_behavior => 'CASCADE', purge => true); 156 | drop_system_time_period 157 | ------------------------- 158 | t 159 | (1 row) 160 | 161 | SELECT periods.add_system_time_period('sysver'); 162 | add_system_time_period 163 | ------------------------ 164 | t 165 | (1 row) 166 | 167 | DROP TABLE sysver; 168 | TABLE periods.periods; 169 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 170 | ------------+-------------+-------------------+-----------------+------------+------------------------- 171 | (0 rows) 172 | 173 | TABLE periods.system_time_periods; 174 | table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names 175 | ------------+-------------+---------------------------+--------------------------+-----------------------+------------------+----------------------- 176 | (0 rows) 177 | 178 | /* Forbid UNIQUE keys on system_time columns */ 179 | CREATE TABLE no_unique (col1 timestamp with time zone, s bigint, e bigint); 180 | SELECT periods.add_period('no_unique', 'p', 's', 'e'); 181 | add_period 182 | ------------ 183 | t 184 | (1 row) 185 | 186 | SELECT periods.add_unique_key('no_unique', ARRAY['col1'], 'p'); -- passes 187 | add_unique_key 188 | ------------------ 189 | no_unique_col1_p 190 | (1 row) 191 | 192 | SELECT periods.add_system_time_period('no_unique'); 193 | add_system_time_period 194 | ------------------------ 195 | t 196 | (1 row) 197 | 198 | SELECT periods.add_unique_key('no_unique', ARRAY['system_time_start'], 'p'); -- fails 199 | ERROR: columns in period for SYSTEM_TIME are not allowed in UNIQUE keys 200 | CONTEXT: PL/pgSQL function periods.add_unique_key(regclass,name[],name,name,name,name) line 78 at RAISE 201 | SELECT periods.add_unique_key('no_unique', ARRAY['system_time_end'], 'p'); -- fails 202 | ERROR: columns in period for SYSTEM_TIME are not allowed in UNIQUE keys 203 | CONTEXT: PL/pgSQL function periods.add_unique_key(regclass,name[],name,name,name,name) line 78 at RAISE 204 | SELECT periods.add_unique_key('no_unique', ARRAY['col1'], 'system_time'); -- fails 205 | ERROR: periods for SYSTEM_TIME are not allowed in UNIQUE keys 206 | CONTEXT: PL/pgSQL function periods.add_unique_key(regclass,name[],name,name,name,name) line 35 at RAISE 207 | SELECT periods.drop_system_time_period('no_unique'); 208 | drop_system_time_period 209 | ------------------------- 210 | t 211 | (1 row) 212 | 213 | SELECT periods.add_unique_key('no_unique', ARRAY['system_time_start'], 'p'); -- passes 214 | add_unique_key 215 | ------------------------------- 216 | no_unique_system_time_start_p 217 | (1 row) 218 | 219 | SELECT periods.add_unique_key('no_unique', ARRAY['system_time_end'], 'p'); -- passes 220 | add_unique_key 221 | ----------------------------- 222 | no_unique_system_time_end_p 223 | (1 row) 224 | 225 | SELECT periods.add_system_time_period('no_unique'); -- fails 226 | ERROR: columns in period for SYSTEM_TIME are not allowed in UNIQUE keys 227 | CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name,name[]) line 48 at RAISE 228 | SELECT periods.drop_unique_key('no_unique', 'no_unique_system_time_start_p'); 229 | drop_unique_key 230 | ----------------- 231 | 232 | (1 row) 233 | 234 | SELECT periods.drop_unique_key('no_unique', 'no_unique_system_time_end_p'); 235 | drop_unique_key 236 | ----------------- 237 | 238 | (1 row) 239 | 240 | /* Forbid foreign keys on system_time columns */ 241 | CREATE TABLE no_unique_ref (LIKE no_unique); 242 | SELECT periods.add_period('no_unique_ref', 'q', 's', 'e'); 243 | add_period 244 | ------------ 245 | t 246 | (1 row) 247 | 248 | SELECT periods.add_system_time_period('no_unique_ref'); 249 | add_system_time_period 250 | ------------------------ 251 | t 252 | (1 row) 253 | 254 | SELECT periods.add_foreign_key('no_unique_ref', ARRAY['system_time_start'], 'q', 'no_unique_col1_p'); -- fails 255 | ERROR: columns in period for SYSTEM_TIME are not allowed in UNIQUE keys 256 | CONTEXT: PL/pgSQL function periods.add_foreign_key(regclass,name[],name,name,periods.fk_match_types,periods.fk_actions,periods.fk_actions,name,name,name,name,name) line 46 at RAISE 257 | SELECT periods.add_foreign_key('no_unique_ref', ARRAY['system_time_end'], 'q', 'no_unique_col1_p'); -- fails 258 | ERROR: columns in period for SYSTEM_TIME are not allowed in UNIQUE keys 259 | CONTEXT: PL/pgSQL function periods.add_foreign_key(regclass,name[],name,name,periods.fk_match_types,periods.fk_actions,periods.fk_actions,name,name,name,name,name) line 46 at RAISE 260 | SELECT periods.add_foreign_key('no_unique_ref', ARRAY['col1'], 'system_time', 'no_unique_col1_p'); -- fails 261 | ERROR: periods for SYSTEM_TIME are not allowed in foreign keys 262 | CONTEXT: PL/pgSQL function periods.add_foreign_key(regclass,name[],name,name,periods.fk_match_types,periods.fk_actions,periods.fk_actions,name,name,name,name,name) line 34 at RAISE 263 | SELECT periods.drop_system_time_period('no_unique_ref'); 264 | drop_system_time_period 265 | ------------------------- 266 | t 267 | (1 row) 268 | 269 | SELECT periods.add_foreign_key('no_unique_ref', ARRAY['system_time_start'], 'q', 'no_unique_col1_p'); -- passes 270 | add_foreign_key 271 | ----------------------------------- 272 | no_unique_ref_system_time_start_q 273 | (1 row) 274 | 275 | SELECT periods.add_foreign_key('no_unique_ref', ARRAY['system_time_end'], 'q', 'no_unique_col1_p'); -- passes 276 | add_foreign_key 277 | --------------------------------- 278 | no_unique_ref_system_time_end_q 279 | (1 row) 280 | 281 | SELECT periods.add_system_time_period('no_unique_ref'); -- fails 282 | ERROR: columns for SYSTEM_TIME must not be part of foreign keys 283 | CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name,name[]) line 168 at RAISE 284 | DROP TABLE no_unique, no_unique_ref; 285 | -------------------------------------------------------------------------------- /expected/rename_following_1.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | pre_96 4 | -------- 5 | t 6 | (1 row) 7 | 8 | /* Run tests as unprivileged user */ 9 | SET ROLE TO periods_unprivileged_user; 10 | /* 11 | * If anything we store as "name" is renamed, we need to update our catalogs or 12 | * throw an error. 13 | */ 14 | /* periods */ 15 | CREATE TABLE rename_test(col1 text, col2 bigint, col3 time, s integer, e integer); 16 | SELECT periods.add_period('rename_test', 'p', 's', 'e'); 17 | add_period 18 | ------------ 19 | t 20 | (1 row) 21 | 22 | TABLE periods.periods; 23 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 24 | -------------+-------------+-------------------+-----------------+------------+------------------------- 25 | rename_test | p | s | e | int4range | rename_test_p_check 26 | (1 row) 27 | 28 | ALTER TABLE rename_test RENAME s TO start; 29 | ALTER TABLE rename_test RENAME e TO "end"; 30 | TABLE periods.periods; 31 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 32 | -------------+-------------+-------------------+-----------------+------------+------------------------- 33 | rename_test | p | start | end | int4range | rename_test_p_check 34 | (1 row) 35 | 36 | ALTER TABLE rename_test RENAME start TO "s < e"; 37 | TABLE periods.periods; 38 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 39 | -------------+-------------+-------------------+-----------------+------------+------------------------- 40 | rename_test | p | s < e | end | int4range | rename_test_p_check 41 | (1 row) 42 | 43 | ALTER TABLE rename_test RENAME "end" TO "embedded "" symbols"; 44 | TABLE periods.periods; 45 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 46 | -------------+-------------+-------------------+--------------------+------------+------------------------- 47 | rename_test | p | s < e | embedded " symbols | int4range | rename_test_p_check 48 | (1 row) 49 | 50 | ALTER TABLE rename_test RENAME CONSTRAINT rename_test_p_check TO start_before_end; 51 | TABLE periods.periods; 52 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 53 | -------------+-------------+-------------------+--------------------+------------+------------------------- 54 | rename_test | p | s < e | embedded " symbols | int4range | start_before_end 55 | (1 row) 56 | 57 | /* system_time_periods */ 58 | SELECT periods.add_system_time_period('rename_test', excluded_column_names => ARRAY['col3']); 59 | add_system_time_period 60 | ------------------------ 61 | t 62 | (1 row) 63 | 64 | TABLE periods.system_time_periods; 65 | table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names 66 | -------------+-------------+--------------------------------------------+------------------------------------------+---------------------------------------+----------------------+----------------------- 67 | rename_test | system_time | rename_test_system_time_end_infinity_check | rename_test_system_time_generated_always | rename_test_system_time_write_history | rename_test_truncate | {col3} 68 | (1 row) 69 | 70 | ALTER TABLE rename_test RENAME col3 TO "COLUMN3"; 71 | ERROR: cannot drop or rename column "col3" on table "rename_test" because it is excluded from SYSTEM VERSIONING 72 | ALTER TABLE rename_test RENAME CONSTRAINT rename_test_system_time_end_infinity_check TO inf_check; 73 | ALTER TRIGGER rename_test_system_time_generated_always ON rename_test RENAME TO generated_always; 74 | ALTER TRIGGER rename_test_system_time_write_history ON rename_test RENAME TO write_history; 75 | ALTER TRIGGER rename_test_truncate ON rename_test RENAME TO trunc; 76 | TABLE periods.system_time_periods; 77 | table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names 78 | -------------+-------------+---------------------------+--------------------------+-----------------------+------------------+----------------------- 79 | rename_test | system_time | inf_check | generated_always | write_history | trunc | {col3} 80 | (1 row) 81 | 82 | /* for_portion_views */ 83 | ALTER TABLE rename_test ADD COLUMN id integer PRIMARY KEY; 84 | SELECT periods.add_for_portion_view('rename_test', 'p'); 85 | add_for_portion_view 86 | ---------------------- 87 | t 88 | (1 row) 89 | 90 | TABLE periods.for_portion_views; 91 | table_name | period_name | view_name | trigger_name 92 | -------------+-------------+-------------------------------+------------------ 93 | rename_test | p | rename_test__for_portion_of_p | for_portion_of_p 94 | (1 row) 95 | 96 | ALTER TRIGGER for_portion_of_p ON rename_test__for_portion_of_p RENAME TO portion_trigger; 97 | TABLE periods.for_portion_views; 98 | table_name | period_name | view_name | trigger_name 99 | -------------+-------------+-------------------------------+----------------- 100 | rename_test | p | rename_test__for_portion_of_p | portion_trigger 101 | (1 row) 102 | 103 | SELECT periods.drop_for_portion_view('rename_test', 'p'); 104 | drop_for_portion_view 105 | ----------------------- 106 | t 107 | (1 row) 108 | 109 | ALTER TABLE rename_test DROP COLUMN id; 110 | /* unique_keys */ 111 | SELECT periods.add_unique_key('rename_test', ARRAY['col2', 'col1', 'col3'], 'p'); 112 | add_unique_key 113 | ------------------------------ 114 | rename_test_col2_col1_col3_p 115 | (1 row) 116 | 117 | TABLE periods.unique_keys; 118 | key_name | table_name | column_names | period_name | unique_constraint | exclude_constraint 119 | ------------------------------+-------------+------------------+-------------+---------------------------------------------------------+------------------------------------------- 120 | rename_test_col2_col1_col3_p | rename_test | {col2,col1,col3} | p | rename_test_col2_col1_col3_s < e_embedded " symbols_key | rename_test_col2_col1_col3_int4range_excl 121 | (1 row) 122 | 123 | ALTER TABLE rename_test RENAME COLUMN col1 TO "COLUMN1"; 124 | ALTER TABLE rename_test RENAME CONSTRAINT "rename_test_col2_col1_col3_s < e_embedded "" symbols_key" TO unconst; 125 | ALTER TABLE rename_test RENAME CONSTRAINT rename_test_col2_col1_col3_int4range_excl TO exconst; 126 | TABLE periods.unique_keys; 127 | key_name | table_name | column_names | period_name | unique_constraint | exclude_constraint 128 | ------------------------------+-------------+---------------------+-------------+-------------------+-------------------- 129 | rename_test_col2_col1_col3_p | rename_test | {col2,COLUMN1,col3} | p | unconst | exconst 130 | (1 row) 131 | 132 | /* foreign_keys */ 133 | CREATE TABLE rename_test_ref (LIKE rename_test); 134 | SELECT periods.add_period('rename_test_ref', 'q', 's < e', 'embedded " symbols'); 135 | add_period 136 | ------------ 137 | t 138 | (1 row) 139 | 140 | SELECT periods.add_foreign_key('rename_test_ref', ARRAY['col2', 'COLUMN1', 'col3'], 'q', 'rename_test_col2_col1_col3_p'); 141 | add_foreign_key 142 | ------------------------------------- 143 | rename_test_ref_col2_COLUMN1_col3_q 144 | (1 row) 145 | 146 | TABLE periods.foreign_keys; 147 | key_name | table_name | column_names | period_name | unique_key | match_type | delete_action | update_action | fk_insert_trigger | fk_update_trigger | uk_update_trigger | uk_delete_trigger 148 | -------------------------------------+-----------------+---------------------+-------------+------------------------------+------------+---------------+---------------+-----------------------------------------------+-----------------------------------------------+-----------------------------------------------+----------------------------------------------- 149 | rename_test_ref_col2_COLUMN1_col3_q | rename_test_ref | {col2,COLUMN1,col3} | q | rename_test_col2_col1_col3_p | SIMPLE | NO ACTION | NO ACTION | rename_test_ref_col2_COLUMN1_col3_q_fk_insert | rename_test_ref_col2_COLUMN1_col3_q_fk_update | rename_test_ref_col2_COLUMN1_col3_q_uk_update | rename_test_ref_col2_COLUMN1_col3_q_uk_delete 150 | (1 row) 151 | 152 | ALTER TABLE rename_test_ref RENAME COLUMN "COLUMN1" TO col1; -- fails 153 | ERROR: cannot drop or rename column "COLUMN1" on table "rename_test_ref" because it is used in period foreign key "rename_test_ref_col2_COLUMN1_col3_q" 154 | ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_fk_insert" ON rename_test_ref RENAME TO fk_insert; 155 | ERROR: cannot drop or rename trigger "rename_test_ref_col2_COLUMN1_col3_q_fk_insert" on table "rename_test_ref" because it is used in period foreign key "rename_test_ref_col2_COLUMN1_col3_q" 156 | ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_fk_update" ON rename_test_ref RENAME TO fk_update; 157 | ERROR: cannot drop or rename trigger "rename_test_ref_col2_COLUMN1_col3_q_fk_update" on table "rename_test_ref" because it is used in period foreign key "rename_test_ref_col2_COLUMN1_col3_q" 158 | ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_uk_update" ON rename_test RENAME TO uk_update; 159 | ERROR: cannot drop or rename trigger "rename_test_ref_col2_COLUMN1_col3_q_uk_update" on table "rename_test" because it is used in period foreign key "rename_test_ref_col2_COLUMN1_col3_q" 160 | ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_uk_delete" ON rename_test RENAME TO uk_delete; 161 | ERROR: cannot drop or rename trigger "rename_test_ref_col2_COLUMN1_col3_q_uk_delete" on table "rename_test" because it is used in period foreign key "rename_test_ref_col2_COLUMN1_col3_q" 162 | TABLE periods.foreign_keys; 163 | key_name | table_name | column_names | period_name | unique_key | match_type | delete_action | update_action | fk_insert_trigger | fk_update_trigger | uk_update_trigger | uk_delete_trigger 164 | -------------------------------------+-----------------+---------------------+-------------+------------------------------+------------+---------------+---------------+-----------------------------------------------+-----------------------------------------------+-----------------------------------------------+----------------------------------------------- 165 | rename_test_ref_col2_COLUMN1_col3_q | rename_test_ref | {col2,COLUMN1,col3} | q | rename_test_col2_col1_col3_p | SIMPLE | NO ACTION | NO ACTION | rename_test_ref_col2_COLUMN1_col3_q_fk_insert | rename_test_ref_col2_COLUMN1_col3_q_fk_update | rename_test_ref_col2_COLUMN1_col3_q_uk_update | rename_test_ref_col2_COLUMN1_col3_q_uk_delete 166 | (1 row) 167 | 168 | DROP TABLE rename_test_ref; 169 | /* system_versioning */ 170 | SELECT periods.add_system_versioning('rename_test'); 171 | NOTICE: history table "rename_test_history" created for "rename_test", be sure to index it properly 172 | add_system_versioning 173 | ----------------------- 174 | 175 | (1 row) 176 | 177 | ALTER FUNCTION rename_test__as_of(timestamp with time zone) RENAME TO bumble_bee; 178 | ERROR: cannot drop or rename function "public.rename_test__as_of(timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "public.rename_test" 179 | ALTER FUNCTION rename_test__between(timestamp with time zone, timestamp with time zone) RENAME TO bumble_bee; 180 | ERROR: cannot drop or rename function "public.rename_test__between(timestamp with time zone,timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "public.rename_test" 181 | ALTER FUNCTION rename_test__between_symmetric(timestamp with time zone, timestamp with time zone) RENAME TO bumble_bee; 182 | ERROR: cannot drop or rename function "public.rename_test__between_symmetric(timestamp with time zone,timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "public.rename_test" 183 | ALTER FUNCTION rename_test__from_to(timestamp with time zone, timestamp with time zone) RENAME TO bumble_bee; 184 | ERROR: cannot drop or rename function "public.rename_test__from_to(timestamp with time zone,timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "public.rename_test" 185 | SELECT periods.drop_system_versioning('rename_test', purge => true); 186 | drop_system_versioning 187 | ------------------------ 188 | t 189 | (1 row) 190 | 191 | DROP TABLE rename_test; 192 | -------------------------------------------------------------------------------- /expected/system_versioning.out: -------------------------------------------------------------------------------- 1 | /* 2 | * An alternative file for pre-v12 is necessary because LEAST() and GREATEST() 3 | * were not constant folded. It was actually while writing this extension that 4 | * the lack of optimization was noticed, and subsequently fixed. 5 | * 6 | * https://www.postgresql.org/message-id/flat/c6e8504c-4c43-35fa-6c8f-3c0b80a912cc%402ndquadrant.com 7 | */ 8 | SELECT setting::integer < 120000 AS pre_12 9 | FROM pg_settings WHERE name = 'server_version_num'; 10 | pre_12 11 | -------- 12 | f 13 | (1 row) 14 | 15 | /* Run tests as unprivileged user */ 16 | SET ROLE TO periods_unprivileged_user; 17 | /* Basic SYSTEM VERSIONING */ 18 | CREATE TABLE sysver (val text, flap boolean); 19 | SELECT periods.add_system_time_period('sysver', excluded_column_names => ARRAY['flap']); 20 | add_system_time_period 21 | ------------------------ 22 | t 23 | (1 row) 24 | 25 | TABLE periods.system_time_periods; 26 | table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names 27 | ------------+-------------+---------------------------------------+-------------------------------------+----------------------------------+------------------+----------------------- 28 | sysver | system_time | sysver_system_time_end_infinity_check | sysver_system_time_generated_always | sysver_system_time_write_history | sysver_truncate | {flap} 29 | (1 row) 30 | 31 | TABLE periods.system_versioning; 32 | table_name | period_name | history_table_name | view_name | func_as_of | func_between | func_between_symmetric | func_from_to 33 | ------------+-------------+--------------------+-----------+------------+--------------+------------------------+-------------- 34 | (0 rows) 35 | 36 | SELECT periods.add_system_versioning('sysver', 37 | history_table_name => 'custom_history_name', 38 | view_name => 'custom_view_name', 39 | function_as_of_name => 'custom_as_of', 40 | function_between_name => 'custom_between', 41 | function_between_symmetric_name => 'custom_between_symmetric', 42 | function_from_to_name => 'custom_from_to'); 43 | NOTICE: history table "custom_history_name" created for "sysver", be sure to index it properly 44 | add_system_versioning 45 | ----------------------- 46 | 47 | (1 row) 48 | 49 | TABLE periods.system_versioning; 50 | table_name | period_name | history_table_name | view_name | func_as_of | func_between | func_between_symmetric | func_from_to 51 | ------------+-------------+---------------------+------------------+-----------------------------------------------+--------------------------------------------------------------------------+------------------------------------------------------------------------------------+-------------------------------------------------------------------------- 52 | sysver | system_time | custom_history_name | custom_view_name | public.custom_as_of(timestamp with time zone) | public.custom_between(timestamp with time zone,timestamp with time zone) | public.custom_between_symmetric(timestamp with time zone,timestamp with time zone) | public.custom_from_to(timestamp with time zone,timestamp with time zone) 53 | (1 row) 54 | 55 | SELECT periods.drop_system_versioning('sysver', drop_behavior => 'CASCADE'); 56 | drop_system_versioning 57 | ------------------------ 58 | t 59 | (1 row) 60 | 61 | DROP TABLE custom_history_name; 62 | SELECT periods.add_system_versioning('sysver'); 63 | NOTICE: history table "sysver_history" created for "sysver", be sure to index it properly 64 | add_system_versioning 65 | ----------------------- 66 | 67 | (1 row) 68 | 69 | TABLE periods.system_versioning; 70 | table_name | period_name | history_table_name | view_name | func_as_of | func_between | func_between_symmetric | func_from_to 71 | ------------+-------------+--------------------+---------------------+------------------------------------------------+---------------------------------------------------------------------------+-------------------------------------------------------------------------------------+--------------------------------------------------------------------------- 72 | sysver | system_time | sysver_history | sysver_with_history | public.sysver__as_of(timestamp with time zone) | public.sysver__between(timestamp with time zone,timestamp with time zone) | public.sysver__between_symmetric(timestamp with time zone,timestamp with time zone) | public.sysver__from_to(timestamp with time zone,timestamp with time zone) 73 | (1 row) 74 | 75 | INSERT INTO sysver (val, flap) VALUES ('hello', false); 76 | SELECT val FROM sysver; 77 | val 78 | ------- 79 | hello 80 | (1 row) 81 | 82 | SELECT val FROM sysver_history ORDER BY system_time_start; 83 | val 84 | ----- 85 | (0 rows) 86 | 87 | SELECT transaction_timestamp() AS ts1 \gset 88 | UPDATE sysver SET val = 'world'; 89 | SELECT val FROM sysver; 90 | val 91 | ------- 92 | world 93 | (1 row) 94 | 95 | SELECT val FROM sysver_history ORDER BY system_time_start; 96 | val 97 | ------- 98 | hello 99 | (1 row) 100 | 101 | UPDATE sysver SET flap = not flap; 102 | UPDATE sysver SET flap = not flap; 103 | UPDATE sysver SET flap = not flap; 104 | UPDATE sysver SET flap = not flap; 105 | UPDATE sysver SET flap = not flap; 106 | SELECT val FROM sysver; 107 | val 108 | ------- 109 | world 110 | (1 row) 111 | 112 | SELECT val FROM sysver_history ORDER BY system_time_start; 113 | val 114 | ------- 115 | hello 116 | (1 row) 117 | 118 | SELECT transaction_timestamp() AS ts2 \gset 119 | DELETE FROM sysver; 120 | SELECT val FROM sysver; 121 | val 122 | ----- 123 | (0 rows) 124 | 125 | SELECT val FROM sysver_history ORDER BY system_time_start; 126 | val 127 | ------- 128 | hello 129 | world 130 | (2 rows) 131 | 132 | /* temporal queries */ 133 | SELECT val FROM sysver__as_of(:'ts1') ORDER BY system_time_start; 134 | val 135 | ------- 136 | hello 137 | (1 row) 138 | 139 | SELECT val FROM sysver__as_of(:'ts2') ORDER BY system_time_start; 140 | val 141 | ------- 142 | world 143 | (1 row) 144 | 145 | SELECT val FROM sysver__from_to(:'ts1', :'ts2') ORDER BY system_time_start; 146 | val 147 | ------- 148 | hello 149 | world 150 | (2 rows) 151 | 152 | SELECT val FROM sysver__from_to(:'ts2', :'ts1') ORDER BY system_time_start; 153 | val 154 | ----- 155 | (0 rows) 156 | 157 | SELECT val FROM sysver__between(:'ts1', :'ts2') ORDER BY system_time_start; 158 | val 159 | ------- 160 | hello 161 | world 162 | (2 rows) 163 | 164 | SELECT val FROM sysver__between(:'ts2', :'ts1') ORDER BY system_time_start; 165 | val 166 | ----- 167 | (0 rows) 168 | 169 | SELECT val FROM sysver__between_symmetric(:'ts1', :'ts2') ORDER BY system_time_start; 170 | val 171 | ------- 172 | hello 173 | world 174 | (2 rows) 175 | 176 | SELECT val FROM sysver__between_symmetric(:'ts2', :'ts1') ORDER BY system_time_start; 177 | val 178 | ------- 179 | hello 180 | world 181 | (2 rows) 182 | 183 | /* Ensure functions are inlined */ 184 | SET TimeZone = 'UTC'; 185 | SET DateStyle = 'ISO'; 186 | EXPLAIN (COSTS OFF) SELECT * FROM sysver__as_of('2000-01-01'); 187 | QUERY PLAN 188 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------ 189 | Append 190 | -> Seq Scan on sysver 191 | Filter: ((system_time_start <= '2000-01-01 00:00:00+00'::timestamp with time zone) AND (system_time_end > '2000-01-01 00:00:00+00'::timestamp with time zone)) 192 | -> Seq Scan on sysver_history 193 | Filter: ((system_time_start <= '2000-01-01 00:00:00+00'::timestamp with time zone) AND (system_time_end > '2000-01-01 00:00:00+00'::timestamp with time zone)) 194 | (5 rows) 195 | 196 | EXPLAIN (COSTS OFF) SELECT * FROM sysver__from_to('1000-01-01', '3000-01-01'); 197 | QUERY PLAN 198 | ----------------------------------------------------------------------------------------------------------------------------------------------------------------------- 199 | Append 200 | -> Seq Scan on sysver 201 | Filter: ((system_time_end > '1000-01-01 00:00:00+00'::timestamp with time zone) AND (system_time_start < '3000-01-01 00:00:00+00'::timestamp with time zone)) 202 | -> Seq Scan on sysver_history 203 | Filter: ((system_time_end > '1000-01-01 00:00:00+00'::timestamp with time zone) AND (system_time_start < '3000-01-01 00:00:00+00'::timestamp with time zone)) 204 | (5 rows) 205 | 206 | EXPLAIN (COSTS OFF) SELECT * FROM sysver__between('1000-01-01', '3000-01-01'); 207 | QUERY PLAN 208 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------ 209 | Append 210 | -> Seq Scan on sysver 211 | Filter: ((system_time_end > '1000-01-01 00:00:00+00'::timestamp with time zone) AND (system_time_start <= '3000-01-01 00:00:00+00'::timestamp with time zone)) 212 | -> Seq Scan on sysver_history 213 | Filter: ((system_time_end > '1000-01-01 00:00:00+00'::timestamp with time zone) AND (system_time_start <= '3000-01-01 00:00:00+00'::timestamp with time zone)) 214 | (5 rows) 215 | 216 | EXPLAIN (COSTS OFF) SELECT * FROM sysver__between_symmetric('3000-01-01', '1000-01-01'); 217 | QUERY PLAN 218 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------ 219 | Append 220 | -> Seq Scan on sysver 221 | Filter: ((system_time_end > '1000-01-01 00:00:00+00'::timestamp with time zone) AND (system_time_start <= '3000-01-01 00:00:00+00'::timestamp with time zone)) 222 | -> Seq Scan on sysver_history 223 | Filter: ((system_time_end > '1000-01-01 00:00:00+00'::timestamp with time zone) AND (system_time_start <= '3000-01-01 00:00:00+00'::timestamp with time zone)) 224 | (5 rows) 225 | 226 | /* TRUNCATE should delete the history, too */ 227 | SELECT val FROM sysver_with_history; 228 | val 229 | ------- 230 | hello 231 | world 232 | (2 rows) 233 | 234 | TRUNCATE sysver; 235 | SELECT val FROM sysver_with_history; --empty 236 | val 237 | ----- 238 | (0 rows) 239 | 240 | /* Try modifying several times in a transaction */ 241 | BEGIN; 242 | INSERT INTO sysver (val) VALUES ('hello'); 243 | INSERT INTO sysver (val) VALUES ('world'); 244 | ROLLBACK; 245 | SELECT val FROM sysver_with_history; --empty 246 | val 247 | ----- 248 | (0 rows) 249 | 250 | BEGIN; 251 | INSERT INTO sysver (val) VALUES ('hello'); 252 | UPDATE sysver SET val = 'world'; 253 | UPDATE sysver SET val = 'world2'; 254 | UPDATE sysver SET val = 'world3'; 255 | DELETE FROM sysver; 256 | COMMIT; 257 | SELECT val FROM sysver_with_history; --empty 258 | val 259 | ----- 260 | (0 rows) 261 | 262 | -- We can't drop the the table without first dropping SYSTEM VERSIONING because 263 | -- Postgres will complain about dependant objects (our view functions) before 264 | -- we get a chance to clean them up. 265 | DROP TABLE sysver; 266 | ERROR: cannot drop table sysver because other objects depend on it 267 | DETAIL: view sysver_with_history depends on table sysver 268 | function sysver__as_of(timestamp with time zone) depends on type sysver_with_history 269 | function sysver__between(timestamp with time zone,timestamp with time zone) depends on type sysver_with_history 270 | function sysver__between_symmetric(timestamp with time zone,timestamp with time zone) depends on type sysver_with_history 271 | function sysver__from_to(timestamp with time zone,timestamp with time zone) depends on type sysver_with_history 272 | HINT: Use DROP ... CASCADE to drop the dependent objects too. 273 | SELECT periods.drop_system_versioning('sysver', drop_behavior => 'CASCADE', purge => true); 274 | drop_system_versioning 275 | ------------------------ 276 | t 277 | (1 row) 278 | 279 | TABLE periods.system_versioning; 280 | table_name | period_name | history_table_name | view_name | func_as_of | func_between | func_between_symmetric | func_from_to 281 | ------------+-------------+--------------------+-----------+------------+--------------+------------------------+-------------- 282 | (0 rows) 283 | 284 | DROP TABLE sysver; 285 | TABLE periods.periods; 286 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 287 | ------------+-------------+-------------------+-----------------+------------+------------------------- 288 | (0 rows) 289 | 290 | TABLE periods.system_time_periods; 291 | table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names 292 | ------------+-------------+---------------------------+--------------------------+-----------------------+------------------+----------------------- 293 | (0 rows) 294 | 295 | -------------------------------------------------------------------------------- /expected/rename_following.out: -------------------------------------------------------------------------------- 1 | SELECT setting::integer < 90600 AS pre_96 2 | FROM pg_settings WHERE name = 'server_version_num'; 3 | pre_96 4 | -------- 5 | f 6 | (1 row) 7 | 8 | /* Run tests as unprivileged user */ 9 | SET ROLE TO periods_unprivileged_user; 10 | /* 11 | * If anything we store as "name" is renamed, we need to update our catalogs or 12 | * throw an error. 13 | */ 14 | /* periods */ 15 | CREATE TABLE rename_test(col1 text, col2 bigint, col3 time, s integer, e integer); 16 | SELECT periods.add_period('rename_test', 'p', 's', 'e'); 17 | add_period 18 | ------------ 19 | t 20 | (1 row) 21 | 22 | TABLE periods.periods; 23 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 24 | -------------+-------------+-------------------+-----------------+------------+------------------------- 25 | rename_test | p | s | e | int4range | rename_test_p_check 26 | (1 row) 27 | 28 | ALTER TABLE rename_test RENAME s TO start; 29 | ALTER TABLE rename_test RENAME e TO "end"; 30 | TABLE periods.periods; 31 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 32 | -------------+-------------+-------------------+-----------------+------------+------------------------- 33 | rename_test | p | start | end | int4range | rename_test_p_check 34 | (1 row) 35 | 36 | ALTER TABLE rename_test RENAME start TO "s < e"; 37 | TABLE periods.periods; 38 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 39 | -------------+-------------+-------------------+-----------------+------------+------------------------- 40 | rename_test | p | s < e | end | int4range | rename_test_p_check 41 | (1 row) 42 | 43 | ALTER TABLE rename_test RENAME "end" TO "embedded "" symbols"; 44 | TABLE periods.periods; 45 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 46 | -------------+-------------+-------------------+--------------------+------------+------------------------- 47 | rename_test | p | s < e | embedded " symbols | int4range | rename_test_p_check 48 | (1 row) 49 | 50 | ALTER TABLE rename_test RENAME CONSTRAINT rename_test_p_check TO start_before_end; 51 | TABLE periods.periods; 52 | table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint 53 | -------------+-------------+-------------------+--------------------+------------+------------------------- 54 | rename_test | p | s < e | embedded " symbols | int4range | start_before_end 55 | (1 row) 56 | 57 | /* system_time_periods */ 58 | SELECT periods.add_system_time_period('rename_test', excluded_column_names => ARRAY['col3']); 59 | add_system_time_period 60 | ------------------------ 61 | t 62 | (1 row) 63 | 64 | TABLE periods.system_time_periods; 65 | table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names 66 | -------------+-------------+--------------------------------------------+------------------------------------------+---------------------------------------+----------------------+----------------------- 67 | rename_test | system_time | rename_test_system_time_end_infinity_check | rename_test_system_time_generated_always | rename_test_system_time_write_history | rename_test_truncate | {col3} 68 | (1 row) 69 | 70 | ALTER TABLE rename_test RENAME col3 TO "COLUMN3"; 71 | ERROR: cannot drop or rename column "col3" on table "rename_test" because it is excluded from SYSTEM VERSIONING 72 | CONTEXT: PL/pgSQL function periods.rename_following() line 121 at RAISE 73 | ALTER TABLE rename_test RENAME CONSTRAINT rename_test_system_time_end_infinity_check TO inf_check; 74 | ALTER TRIGGER rename_test_system_time_generated_always ON rename_test RENAME TO generated_always; 75 | ALTER TRIGGER rename_test_system_time_write_history ON rename_test RENAME TO write_history; 76 | ALTER TRIGGER rename_test_truncate ON rename_test RENAME TO trunc; 77 | TABLE periods.system_time_periods; 78 | table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names 79 | -------------+-------------+---------------------------+--------------------------+-----------------------+------------------+----------------------- 80 | rename_test | system_time | inf_check | generated_always | write_history | trunc | {col3} 81 | (1 row) 82 | 83 | /* for_portion_views */ 84 | ALTER TABLE rename_test ADD COLUMN id integer PRIMARY KEY; 85 | SELECT periods.add_for_portion_view('rename_test', 'p'); 86 | add_for_portion_view 87 | ---------------------- 88 | t 89 | (1 row) 90 | 91 | TABLE periods.for_portion_views; 92 | table_name | period_name | view_name | trigger_name 93 | -------------+-------------+-------------------------------+------------------ 94 | rename_test | p | rename_test__for_portion_of_p | for_portion_of_p 95 | (1 row) 96 | 97 | ALTER TRIGGER for_portion_of_p ON rename_test__for_portion_of_p RENAME TO portion_trigger; 98 | TABLE periods.for_portion_views; 99 | table_name | period_name | view_name | trigger_name 100 | -------------+-------------+-------------------------------+----------------- 101 | rename_test | p | rename_test__for_portion_of_p | portion_trigger 102 | (1 row) 103 | 104 | SELECT periods.drop_for_portion_view('rename_test', 'p'); 105 | drop_for_portion_view 106 | ----------------------- 107 | t 108 | (1 row) 109 | 110 | ALTER TABLE rename_test DROP COLUMN id; 111 | /* unique_keys */ 112 | SELECT periods.add_unique_key('rename_test', ARRAY['col2', 'col1', 'col3'], 'p'); 113 | add_unique_key 114 | ------------------------------ 115 | rename_test_col2_col1_col3_p 116 | (1 row) 117 | 118 | TABLE periods.unique_keys; 119 | key_name | table_name | column_names | period_name | unique_constraint | exclude_constraint 120 | ------------------------------+-------------+------------------+-------------+---------------------------------------------------------+------------------------------------------- 121 | rename_test_col2_col1_col3_p | rename_test | {col2,col1,col3} | p | rename_test_col2_col1_col3_s < e_embedded " symbols_key | rename_test_col2_col1_col3_int4range_excl 122 | (1 row) 123 | 124 | ALTER TABLE rename_test RENAME COLUMN col1 TO "COLUMN1"; 125 | ALTER TABLE rename_test RENAME CONSTRAINT "rename_test_col2_col1_col3_s < e_embedded "" symbols_key" TO unconst; 126 | ALTER TABLE rename_test RENAME CONSTRAINT rename_test_col2_col1_col3_int4range_excl TO exconst; 127 | TABLE periods.unique_keys; 128 | key_name | table_name | column_names | period_name | unique_constraint | exclude_constraint 129 | ------------------------------+-------------+---------------------+-------------+-------------------+-------------------- 130 | rename_test_col2_col1_col3_p | rename_test | {col2,COLUMN1,col3} | p | unconst | exconst 131 | (1 row) 132 | 133 | /* foreign_keys */ 134 | CREATE TABLE rename_test_ref (LIKE rename_test); 135 | SELECT periods.add_period('rename_test_ref', 'q', 's < e', 'embedded " symbols'); 136 | add_period 137 | ------------ 138 | t 139 | (1 row) 140 | 141 | SELECT periods.add_foreign_key('rename_test_ref', ARRAY['col2', 'COLUMN1', 'col3'], 'q', 'rename_test_col2_col1_col3_p'); 142 | add_foreign_key 143 | ------------------------------------- 144 | rename_test_ref_col2_COLUMN1_col3_q 145 | (1 row) 146 | 147 | TABLE periods.foreign_keys; 148 | key_name | table_name | column_names | period_name | unique_key | match_type | delete_action | update_action | fk_insert_trigger | fk_update_trigger | uk_update_trigger | uk_delete_trigger 149 | -------------------------------------+-----------------+---------------------+-------------+------------------------------+------------+---------------+---------------+-----------------------------------------------+-----------------------------------------------+-----------------------------------------------+----------------------------------------------- 150 | rename_test_ref_col2_COLUMN1_col3_q | rename_test_ref | {col2,COLUMN1,col3} | q | rename_test_col2_col1_col3_p | SIMPLE | NO ACTION | NO ACTION | rename_test_ref_col2_COLUMN1_col3_q_fk_insert | rename_test_ref_col2_COLUMN1_col3_q_fk_update | rename_test_ref_col2_COLUMN1_col3_q_uk_update | rename_test_ref_col2_COLUMN1_col3_q_uk_delete 151 | (1 row) 152 | 153 | ALTER TABLE rename_test_ref RENAME COLUMN "COLUMN1" TO col1; -- fails 154 | ERROR: cannot drop or rename column "COLUMN1" on table "rename_test_ref" because it is used in period foreign key "rename_test_ref_col2_COLUMN1_col3_q" 155 | CONTEXT: PL/pgSQL function periods.rename_following() line 210 at RAISE 156 | ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_fk_insert" ON rename_test_ref RENAME TO fk_insert; 157 | ERROR: cannot drop or rename trigger "rename_test_ref_col2_COLUMN1_col3_q_fk_insert" on table "rename_test_ref" because it is used in period foreign key "rename_test_ref_col2_COLUMN1_col3_q" 158 | CONTEXT: PL/pgSQL function periods.rename_following() line 245 at RAISE 159 | ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_fk_update" ON rename_test_ref RENAME TO fk_update; 160 | ERROR: cannot drop or rename trigger "rename_test_ref_col2_COLUMN1_col3_q_fk_update" on table "rename_test_ref" because it is used in period foreign key "rename_test_ref_col2_COLUMN1_col3_q" 161 | CONTEXT: PL/pgSQL function periods.rename_following() line 245 at RAISE 162 | ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_uk_update" ON rename_test RENAME TO uk_update; 163 | ERROR: cannot drop or rename trigger "rename_test_ref_col2_COLUMN1_col3_q_uk_update" on table "rename_test" because it is used in period foreign key "rename_test_ref_col2_COLUMN1_col3_q" 164 | CONTEXT: PL/pgSQL function periods.rename_following() line 245 at RAISE 165 | ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_uk_delete" ON rename_test RENAME TO uk_delete; 166 | ERROR: cannot drop or rename trigger "rename_test_ref_col2_COLUMN1_col3_q_uk_delete" on table "rename_test" because it is used in period foreign key "rename_test_ref_col2_COLUMN1_col3_q" 167 | CONTEXT: PL/pgSQL function periods.rename_following() line 245 at RAISE 168 | TABLE periods.foreign_keys; 169 | key_name | table_name | column_names | period_name | unique_key | match_type | delete_action | update_action | fk_insert_trigger | fk_update_trigger | uk_update_trigger | uk_delete_trigger 170 | -------------------------------------+-----------------+---------------------+-------------+------------------------------+------------+---------------+---------------+-----------------------------------------------+-----------------------------------------------+-----------------------------------------------+----------------------------------------------- 171 | rename_test_ref_col2_COLUMN1_col3_q | rename_test_ref | {col2,COLUMN1,col3} | q | rename_test_col2_col1_col3_p | SIMPLE | NO ACTION | NO ACTION | rename_test_ref_col2_COLUMN1_col3_q_fk_insert | rename_test_ref_col2_COLUMN1_col3_q_fk_update | rename_test_ref_col2_COLUMN1_col3_q_uk_update | rename_test_ref_col2_COLUMN1_col3_q_uk_delete 172 | (1 row) 173 | 174 | DROP TABLE rename_test_ref; 175 | /* system_versioning */ 176 | SELECT periods.add_system_versioning('rename_test'); 177 | NOTICE: history table "rename_test_history" created for "rename_test", be sure to index it properly 178 | add_system_versioning 179 | ----------------------- 180 | 181 | (1 row) 182 | 183 | ALTER FUNCTION rename_test__as_of(timestamp with time zone) RENAME TO bumble_bee; 184 | ERROR: cannot drop or rename function "public.rename_test__as_of(timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "public.rename_test" 185 | CONTEXT: PL/pgSQL function periods.health_checks() line 42 at RAISE 186 | ALTER FUNCTION rename_test__between(timestamp with time zone, timestamp with time zone) RENAME TO bumble_bee; 187 | ERROR: cannot drop or rename function "public.rename_test__between(timestamp with time zone,timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "public.rename_test" 188 | CONTEXT: PL/pgSQL function periods.health_checks() line 42 at RAISE 189 | ALTER FUNCTION rename_test__between_symmetric(timestamp with time zone, timestamp with time zone) RENAME TO bumble_bee; 190 | ERROR: cannot drop or rename function "public.rename_test__between_symmetric(timestamp with time zone,timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "public.rename_test" 191 | CONTEXT: PL/pgSQL function periods.health_checks() line 42 at RAISE 192 | ALTER FUNCTION rename_test__from_to(timestamp with time zone, timestamp with time zone) RENAME TO bumble_bee; 193 | ERROR: cannot drop or rename function "public.rename_test__from_to(timestamp with time zone,timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "public.rename_test" 194 | CONTEXT: PL/pgSQL function periods.health_checks() line 42 at RAISE 195 | SELECT periods.drop_system_versioning('rename_test', purge => true); 196 | drop_system_versioning 197 | ------------------------ 198 | t 199 | (1 row) 200 | 201 | DROP TABLE rename_test; 202 | --------------------------------------------------------------------------------