├── .DS_Store ├── .circleci └── config.yml ├── LICENSE ├── Makefile ├── README.md ├── build ├── circleci_setup.sh ├── dependencies.sh ├── environment.sh ├── load_database.sh ├── pg_prove ├── pgtap.sql ├── pgtap_96.sql └── test_database.sh ├── circle.yml ├── docs ├── HettieD_CitusCon2023.pdf ├── bi_temporal_2Q_PG_Conf_2019.pptx ├── bi_temporal_PG_Open_2017.pptx ├── bitemporal.md ├── bitemporal__PG_Open_2016.pdf ├── bitemporal_datasets.png ├── bitemporal_datasets.svg ├── bitemporal_timeflow.svg ├── bitemporal_timeflow_paths.svg ├── interval.html ├── metadata.md ├── pg_bitemporal_reference.md ├── relationships.sql.md └── tempora-std-pg-bt.pptx ├── generate_bitemporal ├── _load_all_generate_bitemporal.sql ├── generate_bt_insert_trigger_template.sql ├── generate_bt_update_trigger_template.sql ├── generate_bt_update_trigger_template_corr_only.sql └── ll_generate_bitemp_for_schema.sql ├── relationships.sql.lit ├── sql ├── RI_BT_FKey_check_ins.sql ├── RI_BT_FKey_check_ins_device_id.sql ├── _load_all.sql ├── bitemporal_internal_schema.sql ├── extensions.sql ├── get_column_type.sql ├── ll_add_fk.sql ├── ll_bitemporal_correction.sql ├── ll_bitemporal_correction_hist.sql ├── ll_bitemporal_correction_select.sql ├── ll_bitemporal_delete.sql ├── ll_bitemporal_delete_select.sql ├── ll_bitemporal_inactivate.sql ├── ll_bitemporal_inactivate_select.sql ├── ll_bitemporal_insert.sql ├── ll_bitemporal_insert_select.sql ├── ll_bitemporal_list_of_fields.sql ├── ll_bitemporal_split_effective.sql ├── ll_bitemporal_update.sql ├── ll_bitemporal_update_select.sql ├── ll_check_bitemporal_update_conditions.sql ├── ll_create_bitemporal_partition.sql ├── ll_create_bitemporal_table.sql ├── ll_create_bitemporal_table_partitioned.sql ├── ll_generate_fk_trigger_function.sql ├── ll_generate_fk_validate.sql ├── ll_is_bitemporal_table.sql ├── ll_lookup_validation_function.sql ├── metadata.sql ├── relationships.sql └── t_RI_bt_insert.sql ├── tests ├── 00_pgtap_working.sql ├── 05_ll_functions.sql ├── 06_privs.sql ├── 10_relationships.sql ├── 15_metadata.sql ├── 16_metadata.sql └── 20_ll_update.sql └── tutorial ├── bitemp_tutorial.sql ├── bt_tutorial.pptx ├── ex_2.sql ├── first_example_select.sql ├── images ├── 12-1.png ├── 13-1.png ├── 20-1.png ├── 24-1.png ├── 26-1.png ├── 27-1.png ├── 30-1.png ├── 33-1.png ├── 35-1.png ├── 36-1.png ├── 4-1.png ├── 4-2.png ├── 5-1.png ├── 5-2.png ├── 6-1.png └── 6-2.png └── instructions.md /.DS_Store: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/.DS_Store -------------------------------------------------------------------------------- /.circleci/config.yml: -------------------------------------------------------------------------------- 1 | version: 2.1 2 | jobs: 3 | pgbuild: 4 | parameters: 5 | pg_version: 6 | type: string 7 | host_suffix: 8 | type: string 9 | pg_image_tag: 10 | type: string 11 | docker: 12 | - image: slaught/docker-buildbox:postgres-client 13 | environment: 14 | POSTGRES_PASSWORD: f0285cb79f623675a3df3fe88a014d80a7276e55 15 | POSTGRES_VERSION: << parameters.pg_version >> 16 | PGHOST: pg<< parameters.host_suffix >> 17 | - image: library/postgres:<> 18 | name: pg<> 19 | environment: 20 | PGDATA: /dev/shm/pgdata/data 21 | POSTGRES_PASSWORD: f0285cb79f623675a3df3fe88a014d80a7276e55 22 | steps: 23 | - checkout 24 | - run: 25 | name: dependencies 26 | command: ./build/dependencies.sh 27 | - run: 28 | name: load database 29 | command: ./build/load_database.sh 30 | - run: 31 | name: test database 32 | command: ./build/test_database.sh 33 | 34 | workflows: 35 | build: 36 | jobs: 37 | - pgbuild: 38 | name: "test-pg96" 39 | pg_version: "9.6" 40 | host_suffix: "96" 41 | pg_image_tag: 9.6-alpine 42 | - pgbuild: 43 | name: "test-pg10" 44 | pg_version: "10" 45 | host_suffix: "10" 46 | pg_image_tag: 10-alpine 47 | - pgbuild: 48 | name: "test-pg11" 49 | pg_version: "11" 50 | host_suffix: "11" 51 | pg_image_tag: 11-alpine 52 | - pgbuild: 53 | name: "test-pg12" 54 | pg_version: "12" 55 | host_suffix: "12" 56 | pg_image_tag: 12-alpine 57 | - pgbuild: 58 | name: "test-pg13" 59 | pg_version: "13" 60 | host_suffix: "13" 61 | pg_image_tag: 13-alpine 62 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright (c) 2015, Scale Genius, Inc 2 | All rights reserved. 3 | 4 | Redistribution and use in source and binary forms, with or without 5 | modification, are permitted provided that the following conditions are met: 6 | 7 | * Redistributions of source code must retain the above copyright notice, this 8 | list of conditions and the following disclaimer. 9 | 10 | * Redistributions in binary form must reproduce the above copyright notice, 11 | this list of conditions and the following disclaimer in the documentation 12 | and/or other materials provided with the distribution. 13 | 14 | * Neither the name of pg_bitemporal nor the names of its 15 | contributors may be used to endorse or promote products derived from 16 | this software without specific prior written permission. 17 | 18 | THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" 19 | AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE 20 | IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE 21 | DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE 22 | FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL 23 | DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR 24 | SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER 25 | CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, 26 | OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE 27 | OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 28 | 29 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | # 2 | # 3 | # 4 | PGDATABASE ?= bitemporal 5 | 6 | sql/%.sql : %.sql.lit 7 | lit -c --code-dir=sql $< 8 | 9 | docs/%.sql.md : %.sql.lit 10 | lit -m --docs-dir=docs $< 11 | 12 | all: docs/relationships.sql.md sql/relationships.sql 13 | @echo $(PGDATABASE) 14 | 15 | load: all 16 | @bash build/load_database.sh 17 | 18 | tests: load tests/*.sql 19 | @bash build/test_database.sh 20 | 21 | 22 | # vim: set filetype=make noexpandtab tabstop=6 shiftwidth=6: 23 | # syntax=make 24 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # pg\_bitemporal 2 | 3 | pg\_bitemporal project (temporal tables support in PostgreSQL) started in 2015, and was originally maintained in 4 | 5 | https://github.com/scalegenius/pg_bitemporal 6 | 7 | This repo was forked in 2020, and since them, is maintained by Hettie Dombrovskaya. 8 | 9 | This fork includes multiple bug fixes, additional functionality, and performance improvements. 10 | 11 | The documentation is available in the docs and tutorial directories. 12 | 13 | ## Project Tools 14 | 15 | * pg\_prove 16 | Perl package TAP::Parser::SourceHandler::pgTAP 17 | https://github.com/theory/tap-parser-sourcehandler-pgtap 18 | * pgtap 19 | http://pgtap.org/ 20 | * lit 21 | https://github.com/cdosborn/lit 22 | 23 | 24 | 25 | -------------------------------------------------------------------------------- /build/circleci_setup.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | # 3 | # Create Database 4 | # 5 | source `dirname $0`/environment.sh 6 | 7 | CREATE=$(cat <> ${PGPASS} 35 | echo "*:*:template1:postgres:$PGPASSWORD" >> ${PGPASS} 36 | chmod 600 ${PGPASS} 37 | if [ ! -f ${PGPASS} ]; then 38 | exit 3 39 | fi 40 | 41 | PGUSER=${PGUSER:-$USER} 42 | PGPASSWORD=${PGPASSWORD:-password} 43 | PGDATABASE=${PGDATABASE:-$PGUSER} 44 | 45 | echo "\\set PGUSER $PGUSER %\\set PGDATABASE $PGDATABASE%\\set PGPASSWORD $PGPASSWORD% $CREATE " |tr '%' '\n' | $PSQL 46 | exit $? 47 | fi 48 | 49 | 50 | -------------------------------------------------------------------------------- /build/dependencies.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | # 3 | # 4 | # 5 | 6 | echo "Apt-get Update" 7 | sudo apt-get update 8 | echo "Update ca certs" 9 | sudo update-ca-certificates 10 | echo "Install packages" 11 | sudo apt-get install -y --no-install-recommends parallel libgetopt-declare-perl 12 | yes | sudo cpan TAP::Parser::SourceHandler::pgTAP 13 | 14 | echo "Verify pgTAP is installed correctly." 15 | # If it is not tests get weird, hard to understand errors. 16 | perl -MTAP::Parser::SourceHandler::pgTAP -e 'print;' 17 | 18 | if (( $? )); then 19 | exit 1 20 | fi 21 | 22 | 23 | if [ "x$CIRCLECI" == "x" ]; then 24 | echo "Skipping CircleCI setup" 25 | else 26 | `dirname $0`/circleci_setup.sh 27 | fi 28 | -------------------------------------------------------------------------------- /build/environment.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | export BUILD=`dirname $0` 4 | export APP_ROOT=`dirname $BUILD` 5 | export PGOPTIONS="--client-min-messages=warning" 6 | 7 | export PSQL_CMD="psql -q -P pager=off " 8 | export PSQL="$PSQL_CMD -v VERBOSITY=terse -v ON_ERROR_STOP=on" 9 | 10 | export PGHOST=${PGHOST:-localhost} 11 | export PGPORT=${PGPORT:-5432} 12 | export PGUSER=${PGUSER:-ubuntu} 13 | export PGDATABASE=circle_test 14 | 15 | export PGPASSWORD=$POSTGRES_PASSWORD 16 | export PGVER=${POSTGRES_VERSION:-9.6} 17 | 18 | export DATABASE_URL=postgres://${PGUSER}:${PGPASSWORD}@${PGHOST}:${PGPORT}/${PGDATABASE} 19 | -------------------------------------------------------------------------------- /build/load_database.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | # 3 | source `dirname $0`/environment.sh 4 | 5 | D=${APP_ROOT}/sql 6 | 7 | # infra setup 8 | if [ "${CI:-nil}" != "nil" ] ; then 9 | echo "CI Infrastructure setup" 10 | fi 11 | echo "_load_all.sql" 12 | echo "\\set CI $CI %\\ir $D/_load_all.sql" |tr '%' '\n' | $PSQL 13 | LOAD_ALL=$? 14 | 15 | if (( $LOAD_ALL )); then 16 | exit 1 17 | fi 18 | 19 | # load pgtap framework 20 | LOAD_PGTAP=0 21 | if [ "${CI:-nil}" != "nil" ] ; then 22 | echo "Load pgtap" 23 | if [ "${POSTGRES_VERSION-nil}" = "9.6" ]; then 24 | echo "Using Postgresql 9.6" 25 | echo "\\ir ${BUILD}/pgtap_96.sql %" |tr '%' '\n' | $PSQL 26 | else 27 | echo "\\ir ${BUILD}/pgtap.sql %" |tr '%' '\n' | $PSQL 28 | fi 29 | LOAD_PGTAP=$? 30 | fi 31 | 32 | if (( $LOAD_PGTAP || $LOAD_ALL )); then 33 | exit 1 34 | else 35 | exit 0 36 | fi 37 | -------------------------------------------------------------------------------- /build/test_database.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | source `dirname $0`/environment.sh 4 | 5 | export CI=${CI:-true} 6 | 7 | D=${APP_ROOT}/sql 8 | 9 | 10 | ${BUILD}/pg_prove --ext .pg --ext .sql ${APP_ROOT}/tests/ 11 | PGTAP_TEST=$? 12 | 13 | echo "Test if load_all is reloadable." 14 | # TODO: make new 'create type" reloadable 15 | echo "There will be an ERROR for type bitemporal_pg_constraint" 16 | echo "\\set CI $CI %\\ir $D/_load_all.sql" |tr '%' '\n' | $PSQL 17 | RELOAD_TEST=$? 18 | 19 | # Print out the return code. Bash math sucks! 20 | echo " " 21 | echo "pgtap test returned:" $PGTAP_TEST 22 | echo "reload test returned:" $RELOAD_TEST 23 | 24 | echo "Skipping RELOAD_TEST Check" 25 | # if (( $PGTAP_TEST || $RELOAD_TEST )); then 26 | if (( $PGTAP_TEST )); then 27 | exit 1 28 | else 29 | exit 0 30 | fi 31 | -------------------------------------------------------------------------------- /circle.yml: -------------------------------------------------------------------------------- 1 | # 2 | # Sections 3 | #========= 4 | # machine: adjusting the VM to your preferences and requirements 5 | # checkout: checking out and cloning your git repo 6 | # dependencies: setting up your project's language-specific dependencies 7 | # database: preparing the databases for your tests 8 | # test: running your tests 9 | # deployment: deploying your code to your web servers 10 | # 11 | # Options in all Sections 12 | #------------------------ 13 | # pre: commands run before CircleCI's inferred commands 14 | # override: commands run instead of CircleCI's inferred commands 15 | # post: commands run after CircleCI's inferred commands 16 | # 17 | # Command Modifiers 18 | #------------------ 19 | # 20 | # timeout: if a command runs this many seconds without output, kill it 21 | # (default:180s) 22 | # pwd: run commands using this value as the current working directory 23 | # (default: the checkout directory named for your project, 24 | # except in the machine and checkout/pre sections, 25 | # where it defaults to $HOME.) 26 | # environment: a hash creating a list of environment variables set for this 27 | # command (see Machine configuration for this modifier's 28 | # properties when used in the machine section of the file) 29 | # parallel: (only used with commands in the test section) if you have manually 30 | # set up parallelism, set this to true to run a command across all VMs 31 | # files: The files identified by the file list (or globs) will be 32 | # appended to the command arguments. The files will be 33 | # distributed across all containers running the build. 34 | # Check manual parallelism setup document for more details. 35 | # background: when "true", runs a command in the background. It is 36 | # similar to ending a shell command with '&', but works 37 | # correctly over ssh. Useful for starting servers, 38 | # which your tests will connect to. 39 | 40 | ## Customize the machine 41 | machine: 42 | # Set the timezone 43 | timezone: 44 | America/Chicago 45 | 46 | post: 47 | - sudo apt-get update 48 | - sudo apt-get install parallel libgetopt-declare-perl 49 | - sudo chown -R postgres /usr/lib/postgresql/*/lib 50 | - sudo chown -R postgres /usr/share/postgresql/*/extension 51 | - yes | sudo cpan TAP::Parser::SourceHandler::pgTAP 52 | 53 | # Override /etc/hosts 54 | hosts: 55 | server.example.com: 127.0.0.1 56 | www.example.org: 127.0.0.1 57 | 58 | # Add machine level environment variables 59 | environment: 60 | CIRCLE_ENV: test 61 | DATABASE_URL: postgres://ubuntu:@127.0.0.1:5432/circle_test 62 | PGDATABASE: circle_test 63 | PGHOST: localhost 64 | PGPORT: 5432 65 | PGUSER: ubuntu 66 | 67 | ## Customize dependencies 68 | dependencies: 69 | pre: 70 | - bash ./build/dependencies.sh 71 | - perl -MTAP::Parser::SourceHandler::pgTAP -e 'print;' 72 | 73 | ## we automatically cache and restore many dependencies between 74 | ## builds. If you need to, you can add custom paths to cache: 75 | # cache_directories: 76 | # - "dummy_fdw" 77 | 78 | ## Customize database setup 79 | database: 80 | override: 81 | - bash build/load_database.sh: 82 | timeout: 600 83 | 84 | ## Customize test commands 85 | test: 86 | override: 87 | - bash build/test_database.sh 88 | -------------------------------------------------------------------------------- /docs/HettieD_CitusCon2023.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/docs/HettieD_CitusCon2023.pdf -------------------------------------------------------------------------------- /docs/bi_temporal_2Q_PG_Conf_2019.pptx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/docs/bi_temporal_2Q_PG_Conf_2019.pptx -------------------------------------------------------------------------------- /docs/bi_temporal_PG_Open_2017.pptx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/docs/bi_temporal_PG_Open_2017.pptx -------------------------------------------------------------------------------- /docs/bitemporal.md: -------------------------------------------------------------------------------- 1 | 2 | ## pg_bitemporal 3 | 4 | Bitemporal Table support in Postgresql 9.4 - 10.0 5 | 6 | 7 | 8 | ## Bitemporal Terms 9 | 10 | * Bitemporal Table is a relational database table with two time periods from 11 | two temporal dimensions per row. 12 | In the standard theory, these dimensions are called valid time and 13 | transaction time. In the Asserted Versioning theory, these dimensions are 14 | state time and assertion time. 15 | 16 | * Effective Time Period is the temporal dimension within which effective 17 | time periods are located. Each row in a bitemporal table has 18 | an effective time period. 19 | An effective time period is the temporal interval during which 20 | some row has, had or will have the properties and/or relationships 21 | related to the row. 22 | The standard theory calls this valid time. 23 | 24 | * Row Creation Time is a point in time to record when a given row is inserted 25 | into a table. 26 | 27 | * Assertion Time is the temporal dimension within which assertion-time periods 28 | are located. 29 | Each row in a bitemporal table has an assertion-time period. 30 | An assertion-time period is a time period during which a statement 31 | was, is or will be asserted to be true. 32 | 33 | * Time Interval is an unachored, directional duration, contiguous 34 | portion of the time line. An Interval is relative. 35 | For example: '3 months' '1 year 2 days' 36 | 37 | * Time Period is a period of time deliniated by a beginning time instance 38 | and an end time instance. A Time period is displayed using Closed-Open 39 | range syntax [begin, end ). Begin is inclusive in the range while End is 40 | exclusive to the range. If end is the inclusive than an single step value 41 | should be added to the inclusive end to find the period end 42 | Synonyms: Time Range 43 | 44 | * Clock Tick is the smallest point in time, at a given level of granularity, 45 | used for a given set of time periods. It is used to calculated the start 46 | of the next continious time period. 47 | 48 | 49 | * Allen relationships are a set of thirteen positional relationships between 50 | two time periods, as first defined in James F. Allen's 1983 article 51 | “Maintaining Knowledge about Temporal Intervals”. Every possible positional 52 | relationship between two time periods is represented by one and only one 53 | member of this set. 54 | 55 | 56 | * Temporal Primary Key is the primary key of a temporal table. It is 57 | usually a natural key plus the effective and asserted time periods. In our 58 | implementation we reference this natural key as a business key. In addition a 59 | surrogate key may be created. 60 | 61 | 62 | * Temporal Referential Integrity is a standard referential integrity 63 | constraint with a time dimensions. 64 | 65 | Temporal referential integrity is the constraint that the bitemporal 66 | extent of every row about a thing is [contained in] the bitemporal 67 | extent of a set of one or more rows has an existence dependency. 68 | 69 | 70 | 71 | 72 | ## What Bitemporal Combinations mean 73 | 74 | | | what we used to claim | what we currently claim | what we will claim| 75 | |---|-----------------------|-------------------------|------------------| 76 | |what things used to be like| what we used to claim things used to be like| what we currently claim things used to be like| what we will claim things used to be like| 77 | |what things are like | what we used to claim things are like now | what we currently claim things are like now | what we will claim things are like now| 78 | |what things will be like| what we used to claim things will be like| what we currently claim things will be like| what we will claim things will be like | 79 | 80 | -------------------------------------------------------------------------------- /docs/bitemporal__PG_Open_2016.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/docs/bitemporal__PG_Open_2016.pdf -------------------------------------------------------------------------------- /docs/bitemporal_datasets.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/docs/bitemporal_datasets.png -------------------------------------------------------------------------------- /docs/interval.html: -------------------------------------------------------------------------------- 1 | Interval Relationships 2 |

Interval Relationships

3 |

4 | There are 13 Allen Relationships. There are 6 basic relationships and 6 5 | inverses of those basic relationships and the equality relationship. The 6 | Allen relationship definitions assume the relationships are not communitive. 7 |

8 |

9 | These are graphical representations of the relationships. 10 |

11 |
12 |

Start

13 | 14 | 15 | A 16 | E 17 | 18 | 19 | 21 | 22 | 23 | 24 | 26 | 27 | 28 | 29 | 30 |

Start-1

31 | 32 | 33 | A 34 | E 35 | 36 | 37 | 39 | 40 | 41 | 42 | 44 | 45 | 46 | 47 |
48 | 49 |
50 |

Finish

51 | 52 | 53 | A 54 | E 55 | 56 | 57 | 59 | 60 | 61 | 62 | 64 | 65 | 66 | 67 |

Finish-1

68 | 69 | 70 | A 71 | E 72 | 73 | 74 | 76 | 77 | 78 | 79 | 81 | 82 | 83 | 84 |
85 |
86 |

Equal

87 | 88 | 89 | A 90 | E 91 | 92 | 93 | 95 | 96 | 97 | 98 | 100 | 101 | 102 | 103 |
104 |
105 |

During

106 | 107 | 108 | A 109 | E 110 | 111 | 112 | 114 | 115 | 116 | 117 | 119 | 120 | 121 | 122 |

During-1

123 | 124 | 125 | A 126 | E 127 | 128 | 129 | 131 | 132 | 133 | 134 | 136 | 137 | 138 | 139 |
140 |
141 |

Overlaps

142 | 143 | 144 | A 145 | E 146 | 147 | 148 | 150 | 151 | 152 | 153 | 155 | 156 | 157 | 158 | 159 |

Overlaps-1

160 | 161 | 162 | A 163 | E 164 | 165 | 166 | 168 | 169 | 170 | 171 | 173 | 174 | 175 | 176 |
177 |
178 |

Before

179 | 180 | 181 | A 182 | E 183 | 184 | 185 | 187 | 188 | 189 | 190 | 192 | 193 | 194 | 195 |

Before-1

196 | 197 | 198 | A 199 | E 200 | 201 | 202 | 204 | 205 | 206 | 207 | 209 | 210 | 211 | 212 |
213 |
214 |

Meets

215 | 216 | 217 | A 218 | E 219 | 220 | 221 | 222 | 224 | 225 | 226 | 227 | 229 | 230 | 231 | 232 |

Meets-1

233 | 234 | 235 | A 236 | E 237 | 238 | 239 | 241 | 242 | 243 | 244 | 246 | 247 | 248 | 249 |
250 | 251 | -------------------------------------------------------------------------------- /docs/metadata.md: -------------------------------------------------------------------------------- 1 | # Bitemporal Metadata 2 | 3 | Bitemporal tables need to store information about constraints 4 | that are specific to bitemporal tables. This implementation has 5 | chosen to leverage the existing catalogue to store this information. 6 | As there are no specific bitemporal support in postgres the 7 | information must be encoded into existing catalogue entry types. 8 | This encoded data must be read and parsed to return the actionable 9 | information. 10 | 11 | This meta data deals with three constraints: Foreign Key, Primary Key and 12 | Unique. 13 | 14 | The other constraints are not considered to be different in the cause of 15 | bitemporal tables vs normal tables. The not null constraint is the same 16 | on both tables. Triggers, Exclusion and Check constraints 17 | will need to be written as bitemporal aware. 18 | There is no support for them in these functions. 19 | 20 | 21 | ## Create Constraints 22 | 23 | There are three functions to create the necessary clauses for a create table 24 | or an alter table statement to add the particular bitemporal constraint. 25 | 26 | These constraints are not enforced by postgres itself. Therefore it is 27 | necessary to store information about the constraints in the pg catalog. These 28 | entries are encoded in the source column of specially named check constraints. 29 | The check constraint is suppose to always be true 30 | and contains a string with @ at the beginning and end to delimit the 31 | information about the bitemporal constraint. 32 | 33 | ### PK 34 | 35 | The Primary Key supports a single column which is encoded as the columns name 36 | delimited by @. 37 | 38 | This creates a clause for recording a single column as a primary key of a 39 | bitemporal table. 40 | 41 | ```sql 42 | select bitemporal_internal.pk_constraint('id') 43 | ``` 44 | 45 | ### FK 46 | 47 | The Foregn Key supports a single column to column FK. The tuple of column, 48 | foreign table and foreign column are encoded similar to this 49 | '@ local_column -> remote_table(remote_column) @' 50 | 51 | Thie creates a clause for recording a foreign key relationship between 52 | a single column in the local table and a single table in a foreign table. 53 | This takes three arguments. The first is the local column, the second is the 54 | foriegn table and the third is the foriegn table column. 55 | 56 | ```sql 57 | select bitemporal_internal.fk_constraint('user_id', 'users', 'user_id') 58 | ``` 59 | 60 | 61 | ### Unique 62 | 63 | The Unique constraint is enforced by postgres by reencoding a bitemporal 64 | unique constraint as an exclude constraint with the unique column and 65 | the bitemporal time ranges. 66 | 67 | This creates a constraint to maintain a unique column of values across the 68 | bitemporal dimensions. 69 | 70 | ```sql 71 | select string_agg(a, ',\n') from 72 | bitemporal_internal.unique_constraint('username') as s(a) 73 | ``` 74 | 75 | 76 | ### Alter helper 77 | 78 | This methods constructs the alter table statement given the output of one of 79 | the functions above. 80 | 81 | ```sql 82 | execute bitemporal_internal.add_constraint('users', bitemporal_internal.pk_constraint('username') ); 83 | ``` 84 | 85 | 86 | ## Search for Bitemporal Constraints 87 | 88 | There are two functions to find bitemporal Primary Key and bitemporal 89 | Foriegn Key constraints. These function decode the information embeded in the catalog. 90 | 91 | 92 | ### Primary Key. 93 | 94 | The functions finds the bitemporal primary key for the given table. The name 95 | of the column is returned as a text value. Only one column is supported. 96 | 97 | ```sql 98 | select bitemporal_internal.find_pk('schema.table_name') 99 | ``` 100 | 101 | ### Foreign Key 102 | 103 | The function finds all the bitemporal Foreign Key constraints for a given 104 | table. The fucntion returns the complete set of all Foreign Keys for the 105 | given table. 106 | 107 | There is a special composite type in the 108 | form of a table *bitemporal\_internal.fk\_constraint\_type*. 109 | 110 | ```sql 111 | create table if not exists bitemporal_internal.fk_constraint_type ( 112 | conname name 113 | , src_column name 114 | , fk_table text 115 | , fk_column name 116 | ); 117 | ``` 118 | 119 | The connname exists to help debug is not required to determine the FK 120 | relationship. The type also only supports foregn keys of one column. 121 | 122 | ```sql 123 | select * from bitemporal_internal.find_fk('schema.table_name') 124 | ``` 125 | 126 | 127 | 128 | 129 | # Examples 130 | 131 | The two main use cases are adding constraints at table creation time or after 132 | table exists. 133 | 134 | 135 | To add a unique_constraint to a an existing table *users* for the column 136 | *username* you would do the following. Using the ```unique_constraint``` 137 | function to create a valid constraint clause the ```add_constraint``` function 138 | place the clause in an alter statement that can be executed. 139 | 140 | ```sql 141 | DO $do$ 142 | DECLARE 143 | rc text; 144 | BEGIN 145 | select string_agg(a, ';') into rc from 146 | ( select bitemporal_internal.add_constraint('users', aa) from 147 | bitemporal_internal.unique_constraint('username') as s(aa) 148 | ) as t(a); 149 | execute rc; 150 | END; 151 | $do$; 152 | ``` 153 | 154 | The ```execute_add_constraint``` function will dynamicalyy execute the alter statement. 155 | ```sql 156 | select bitemporal_internal.execute_add_constraint('users', a) from 157 | bitemporal_internal.unique_constraint('username') as s(a) ; 158 | ``` 159 | 160 | 161 | 162 | If you which is create a primary key clause to add to a create table you can get the 163 | clause by the following. 164 | 165 | ```sql 166 | select bitemporal_internal.pk_constraint('id') 167 | ``` 168 | 169 | 170 | If you wish to create a table with a FK cluase at the same time you may do something like 171 | the following. 172 | 173 | 174 | ```sql 175 | DO $do$ BEGIN 176 | execute format($$create table groups ( group_id serial, 177 | group_name text, user_id int, 178 | % ); $$, 179 | bitemporal_internal.fk_constraint('user_id', 'users', 'user_id') ); 180 | END; $do$; 181 | ``` 182 | 183 | 184 | ## Example of how Catalog is Used 185 | 186 | 187 | ### calls to functions with clause output 188 | ### resulting create table 189 | ### select conname, contype, consrc from pg_constraints where table rel 190 | 191 | -------------------------------------------------------------------------------- /docs/relationships.sql.md: -------------------------------------------------------------------------------- 1 | 2 | # Time Period Relationships 3 | 4 | 5 | There are 13 Allen Relationships. There are 6 basic relationships and 6 6 | inverses of those basic relationships and the equality relationship. The 7 | Allen relationship definitions assume the relationships are not communitive. 8 | 9 | This library assumes that if the relationship and its inverse are communitive 10 | then there is one function defined and it is left to the user to swap the 11 | arguments if necessary. 12 | 13 | The 13 relationships are partitioned into 5 groups that encompasses 14 | two or more basic relationships. These partitions allow for a larger range 15 | of expression between two time periods. 16 | 17 | 18 | ## User Functions 19 | 20 | 21 | The user functions are defined below. They are group in a way that makes 22 | explaination easier. 23 | 24 | ```Sql 25 | << high level functions >>= 26 | << simple functions >> 27 | << during functions >> 28 | << overlaps functions >> 29 | << before functions >> 30 | << meets functions >> 31 | << partition functions >> 32 | ``` 33 | The function names are prefix with _is_ if the function implements a single 34 | relationship such as *is\_after* implementing the *[Before^-1]* relationship. 35 | The prefix _has_ is used to denote a function that implements both a 36 | relationship and its inverse, such as *has\_starts* implementing *[Starts]* and 37 | *[Starts^-1*. 38 | 39 | 40 | ### Starts, Finishes and Equals 41 | 42 | The has\_starts is [starts] and [starts^-1]. 43 | The has\_finishes is [finishes] [finishes^-1]. 44 | The equals is [equals]. As it is a single relationship that is its own inverse 45 | neither is or has prefix was used. 46 | 47 | The order of the arguments is unimportant to these relationship. 48 | 49 | 50 | ```Sql 51 | << simple functions >>= 52 | -- 53 | -- [starts] [starts^-1] 54 | -- 55 | -- [starts A E] 56 | -- A |---| 57 | -- E |-------| 58 | -- 59 | -- [starts^-1 A E] 60 | -- A |-------| 61 | -- E |---| 62 | -- 63 | create or replace 64 | function has_starts(a timeperiod , b timeperiod ) 65 | returns boolean language SQL IMMUTABLE 66 | as $$ 67 | select fst(a) = fst(b) and snd(a) <> snd(b); 68 | $$ 69 | SET search_path = 'temporal_relationships'; 70 | -- 71 | -- [finishes] [finishes^-1] 72 | -- 73 | -- [finishes A E] 74 | -- A |-------| 75 | -- E |---| 76 | -- 77 | -- [finishes^-1 A E] 78 | -- A |---| 79 | -- E |-------| 80 | -- 81 | create or replace 82 | function has_finishes(a timeperiod, b timeperiod) 83 | returns boolean language SQL IMMUTABLE 84 | as $$ 85 | select snd(a) = snd(b) and fst(a) <> fst(b); 86 | $$ 87 | SET search_path = 'temporal_relationships'; 88 | -- 89 | -- [equals] 90 | -- 91 | -- [equals A E] 92 | -- A |----| 93 | -- E |----| 94 | -- 95 | create or replace 96 | function equals(a timeperiod, b timeperiod) 97 | returns boolean language SQL IMMUTABLE 98 | as $$ 99 | -- doubtful = operator exists for timeperiod 100 | select fst(a) = fst(b) and snd(a) = snd(b) ; 101 | $$ 102 | SET search_path = 'temporal_relationships'; 103 | ``` 104 | ### During 105 | 106 | is\_during implements [during] and is\_contained\_in implements [during^-1]. 107 | The function names are meant to match how the relationship reads in english. 108 | 109 | The function has\_during implments the alternative of either argument is during 110 | the other. This is effective [during] or [during^-1]. 111 | It is unclear if this function would be needed. 112 | 113 | ```Sql 114 | << during functions >>= 115 | -- 116 | -- [during] 117 | -- 118 | -- [during A E] 119 | -- A |---| 120 | -- E |-------| 121 | -- 122 | create or replace 123 | function is_during(a timeperiod, b timeperiod) 124 | returns boolean language SQL IMMUTABLE 125 | as $$ 126 | select (fst(a) > fst(b)) and (snd(a) < snd(b)); 127 | $$ 128 | SET search_path = 'temporal_relationships'; 129 | -- 130 | -- [during^-1] contained 131 | -- 132 | -- [during^-1 A E] 133 | -- A |-------| 134 | -- E |---| 135 | -- 136 | create or replace 137 | function is_contained_in(a timeperiod, b timeperiod) 138 | returns boolean language SQL IMMUTABLE 139 | as $$ 140 | select is_during(b, a); 141 | $$ 142 | SET search_path = 'temporal_relationships'; 143 | 144 | -- 145 | -- [during] or [during^-1] 146 | -- 147 | create or replace 148 | function has_during(a timeperiod, b timeperiod) 149 | returns boolean language SQL IMMUTABLE 150 | as $$ 151 | select is_during(a, b) or is_during(b,a); 152 | $$ 153 | SET search_path = 'temporal_relationships'; 154 | ``` 155 | ### Overlaps 156 | 157 | Implementing [Overlaps] and [Overlaps^-1] is confusing. 158 | is\_overlaps implments the relationships based on the order of the arguments. 159 | But as an english description there is no real inverse as a can overlap b or b 160 | overlaps a. has\_overlaps implements both cases of overlap. 161 | 162 | 163 | ```Sql 164 | << overlaps functions >>= 165 | -- 166 | -- [overlaps] 167 | -- 168 | -- [overlaps A E] 169 | -- A |-----| 170 | -- E |-----| 171 | -- 172 | -- [overlaps^-1 A E] 173 | -- A |-----| 174 | -- E |-----| 175 | -- 176 | create or replace 177 | function is_overlaps(a timeperiod, b timeperiod) 178 | returns boolean language SQL IMMUTABLE 179 | 180 | as $$ 181 | select fst(a) < fst(b) and snd(a) > fst(b) and snd(a) < snd(b); 182 | $$ 183 | SET search_path = 'temporal_relationships'; 184 | 185 | -- 186 | -- either overlaps the other [overlaps] [overlaps^-1] 187 | -- 188 | create or replace 189 | function has_overlaps(a timeperiod, b timeperiod) 190 | returns boolean language SQL IMMUTABLE 191 | as $$ 192 | select is_overlaps(a , b ) or is_overlaps(b , a ) ; 193 | $$ 194 | SET search_path = 'temporal_relationships'; 195 | ``` 196 | ### Before 197 | 198 | There are three [before] and [before^-1] functions. is\_before implements 199 | [before] and is\_after implements [before^-1] and has\_before implements 200 | both cases. The word after reads better as the inverse of before. 201 | has\_before handles the case of determining if either argument is before the 202 | other without regard to which. 203 | 204 | ```Sql 205 | << before functions >>= 206 | -- 207 | -- [before] 208 | -- 209 | -- [before A E] 210 | -- A |-----| 211 | -- E |-----| 212 | -- 213 | create or replace 214 | function is_before(a timeperiod, b timeperiod) 215 | returns boolean language SQL IMMUTABLE 216 | as $$ 217 | select snd(a) < fst(b); 218 | $$ 219 | SET search_path = 'temporal_relationships'; 220 | -- 221 | -- [before^-1] 222 | -- 223 | -- [before^-1 A E] 224 | -- A |-----| 225 | -- E |-----| 226 | -- 227 | create or replace 228 | function is_after(a timeperiod, b timeperiod) 229 | returns boolean language SQL IMMUTABLE 230 | as $$ 231 | -- is_before(b, a) 232 | select snd(b) < fst(a); 233 | $$ 234 | SET search_path = 'temporal_relationships'; 235 | 236 | -- 237 | -- either [before] [before^-1] 238 | -- 239 | create or replace 240 | function has_before(a timeperiod, b timeperiod) 241 | returns boolean language SQL IMMUTABLE 242 | as $$ 243 | select snd(a) < fst(b) or snd(b) < fst(a); 244 | $$ 245 | SET search_path = 'temporal_relationships'; 246 | ``` 247 | ### Meets 248 | 249 | Meets is implemeted similarlly to overlaps. There is no english words to 250 | handle the inverse case. is\_meets can be used for [meets] or [meets^-1] 251 | depending on the order of arguments. has\_meets implements the order agnostic 252 | case of whether two time periods meet in either way. 253 | 254 | ```Sql 255 | << meets functions >>= 256 | -- 257 | -- [meets] [meets^-1] 258 | -- 259 | -- no shared time tick. 260 | -- 261 | -- [meets A E] 262 | -- A |-----| 263 | -- E |-----| 264 | -- 265 | -- [meets^-1 A E] 266 | -- A |-----| 267 | -- E |-----| 268 | -- 269 | create or replace 270 | function is_meets(a timeperiod, b timeperiod) 271 | returns boolean language SQL IMMUTABLE 272 | as $$ 273 | select snd(a) = fst(b) ; 274 | $$ 275 | SET search_path = 'temporal_relationships'; 276 | 277 | create or replace 278 | function has_meets(a timeperiod, b timeperiod) 279 | returns boolean language SQL IMMUTABLE 280 | as $$ 281 | select snd(a) = fst(b) or snd(b) = fst(a); 282 | $$ 283 | SET search_path = 'temporal_relationships'; 284 | ``` 285 | ### Partitioning of Relationships 286 | 287 | 288 | According to Johnston 2014 and Johnston, Weis 2010, the Allen Relationships 289 | can be binary partitioned into groups. Theses groupings allow for an extended 290 | set of terms to describe time period relationships. 291 | 292 | * Excludes 293 | * Includes 294 | * Contains 295 | * Encloses 296 | * AlignsWith 297 | 298 | Excludes is [Before], [Before^-1], [Meets], [Meets^-1]. 299 | Includes is [Overlaps], [Overlaps^-1] and the Contains group. 300 | Contains is [Equals] and Encloses group. 301 | Encloses is [During], [During^-1] and the AlignsWith group. 302 | AlignsWith is [Starts],[Starts^-1], [Finishes], and [Finishes^-1]. 303 | 304 | All the functions uses the _has_ prefix to denote they are agnostic to the 305 | order of arguements. 306 | 307 | 308 | ```Sql 309 | << partition functions >>= 310 | -- 311 | -- Partition of Allen Relationships 312 | -- 313 | 314 | -- 315 | -- [Includes] 316 | -- [Contains] or [Overlaps] 317 | create or replace 318 | function has_includes(a timeperiod, b timeperiod) 319 | returns boolean language SQL IMMUTABLE 320 | as $$ 321 | select fst(a) = fst(b) or snd(a) = snd(b) or 322 | (snd(a) <= snd(b) and (fst(a) >= fst(b) or fst(b) < snd(a))) or 323 | (snd(a) >= snd(b) and (fst(a) < snd(b) or fst(a) <= fst(b))); 324 | $$ 325 | SET search_path = 'temporal_relationships'; 326 | 327 | -- 328 | -- [Contains] 329 | -- [Encloses] or [Equals] 330 | 331 | create or replace 332 | function has_contains(a timeperiod, b timeperiod) 333 | returns boolean language SQL IMMUTABLE 334 | 335 | as $$ 336 | select fst(a) = fst(b) or snd(a) = snd(b) or 337 | (snd(a) < snd(b) and fst(a) > fst(b)) or 338 | (snd(b) < snd(a) and fst(b) > fst(a)); 339 | $$ 340 | SET search_path = 'temporal_relationships'; 341 | 342 | -- 343 | -- [Aligns With] 344 | -- [Starts] or [Finishes] 345 | -- 346 | create or replace 347 | function has_aligns_with(a timeperiod, b timeperiod) 348 | returns boolean language SQL IMMUTABLE 349 | as $$ 350 | select xor( fst(a) = fst(b) , snd(a) = snd(b) ); 351 | $$ 352 | SET search_path = 'temporal_relationships'; 353 | 354 | -- 355 | -- [Encloses] 356 | -- [Aligns With] or [During] 357 | -- 358 | 359 | create or replace 360 | function has_encloses(a timeperiod, b timeperiod) 361 | returns boolean language SQL IMMUTABLE 362 | as $$ 363 | select has_during(a,b) or has_aligns_with(a,b); 364 | $$ 365 | SET search_path = 'temporal_relationships'; 366 | 367 | 368 | -- 369 | -- [Excludes] 370 | -- [Before] or [Meets] 371 | -- 372 | create or replace 373 | function has_excludes(a timeperiod, b timeperiod) 374 | returns boolean language SQL IMMUTABLE 375 | as $$ 376 | select fst(a) >= snd(b) or fst(b) >= snd(a) ; 377 | $$ 378 | SET search_path = 'temporal_relationships'; 379 | ``` 380 | ### Schema 381 | 382 | ```Sql 383 | << schema >>= 384 | create schema if not exists temporal_relationships; 385 | grant usage on schema temporal_relationships to public; 386 | set local search_path to temporal_relationships, public; 387 | -- create a domain if not exists 388 | DO $d$ 389 | DECLARE 390 | domain_range_name text default 'timeperiod'; 391 | domain_range_type text default 'tstzrange'; 392 | domain_i_name text default 'time_endpoint'; 393 | domain_i_type text default 'timestamptz'; 394 | BEGIN 395 | -- Create timeperiod domain 396 | PERFORM n.nspname as "Schema", 397 | t.typname as "Name", 398 | pg_catalog.format_type(t.typbasetype, t.typtypmod) as "Type" 399 | FROM pg_catalog.pg_type t 400 | LEFT JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace 401 | WHERE t.typtype = 'd' 402 | AND n.nspname <> 'pg_catalog' 403 | AND n.nspname <> 'information_schema' 404 | AND pg_catalog.pg_type_is_visible(t.oid) 405 | AND t.typname = domain_range_name; 406 | if FOUND then 407 | raise NOTICE 'Domain % already exists', domain_range_name; 408 | else 409 | execute format('create domain %I as %I', domain_range_name, domain_range_type); 410 | end if; 411 | -- Create time_endpoint domain 412 | PERFORM n.nspname as "Schema", 413 | t.typname as "Name", 414 | pg_catalog.format_type(t.typbasetype, t.typtypmod) as "Type" 415 | FROM pg_catalog.pg_type t 416 | LEFT JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace 417 | WHERE t.typtype = 'd' 418 | AND n.nspname <> 'pg_catalog' 419 | AND n.nspname <> 'information_schema' 420 | AND pg_catalog.pg_type_is_visible(t.oid) 421 | AND t.typname = domain_i_name; 422 | if FOUND then 423 | raise NOTICE 'Domain % already exists', domain_i_name; 424 | else 425 | execute format('create domain %I as %I', domain_i_name, domain_i_type); 426 | end if; 427 | END; 428 | $d$; 429 | ``` 430 | ### Types 431 | 432 | 433 | ```Sql 434 | << domain type functions >>= 435 | create or replace 436 | function timeperiod( p_range_start time_endpoint, p_range_end time_endpoint) 437 | RETURNS timeperiod 438 | language sql IMMUTABLE 439 | as 440 | $func$ 441 | select tstzrange(p_range_start, p_range_end,'[)')::timeperiod; 442 | $func$ 443 | SET search_path = 'temporal_relationships'; 444 | -- backwards compatible 445 | create or replace 446 | function timeperiod_range( _s time_endpoint, _e time_endpoint, _ignored text) 447 | returns timeperiod 448 | language sql 449 | as 450 | $func$ 451 | select timeperiod(_s,_e); 452 | $func$ 453 | SET search_path = 'temporal_relationships'; 454 | ``` 455 | ### Support Functions 456 | 457 | The accessor functions in Postgresql for ranges uses lower/upper but 458 | I found that naming to be a bit arch. fst & snd are named after the haskell 459 | methods for accessing elements of a two-tuple. 460 | 461 | The xor function was to make the logic of the partition functions more 462 | readable and tie into the function definitions. The expressions were 463 | simplified and the xor arose during simplification. 464 | 465 | ```Sql 466 | << internal functions >>= 467 | create or replace 468 | function xor(a boolean, b boolean) returns boolean 469 | language sql IMMUTABLE 470 | as 471 | $$ select ( (not a) <> (not b)); $$; 472 | 473 | create or replace 474 | function fst( x anyrange ) returns anyelement 475 | language SQL IMMUTABLE 476 | as 477 | $$ select lower(x); $$; 478 | 479 | create or replace 480 | function snd( x anyrange ) returns anyelement 481 | language SQL IMMUTABLE 482 | as 483 | $$ select upper(x); $$; 484 | ``` 485 | ## References 486 | 487 | 1. James F. Allen. 1983. "Maintaining knowledge about temporal intervals." 488 | Commun. ACM 26, 11 (November 1983), 832-843. [DOI](http://dx.doi.org/10.1145/182.358434) 489 | 2. Tom Johnston. 2014. "Bitemporal Data: Theory and Practice (1st ed.)." 490 | Morgan Kaufmann Publishers Inc., San Francisco, CA, USA. 491 | 3. Tom Johnston & Randall Weis. 2010. "Managing Time in Relational Databases: 492 | How to Design, Update and Query Temporal Data." Morgan Kaufmann Publishers Inc., San Francisco, CA, USA. 493 | 494 | 495 | 496 | ## Appendix: Main File structure 497 | 498 | The file structure is as follows 499 | 500 | ```Sql 501 | << * >>= 502 | begin; 503 | << schema >> 504 | << domain type functions >> 505 | << internal functions >> 506 | << high level functions >> 507 | commit; 508 | 509 | -- vim: set filetype=pgsql expandtab tabstop=2 shiftwidth=2: 510 | ``` 511 | -------------------------------------------------------------------------------- /docs/tempora-std-pg-bt.pptx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/docs/tempora-std-pg-bt.pptx -------------------------------------------------------------------------------- /generate_bitemporal/_load_all_generate_bitemporal.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | set search_path to bitemporal_internal, public; 3 | 4 | \ir ll_generate_bitem_for_schema.sql 5 | --the triggers generation is not 100% automated, thr funcitons below produce the draft of the code 6 | --which should be finalized manually 7 | \ir generate_bt_insert_trigger_template.sql 8 | \ir generate bt_update_trigger_template.sql 9 | \ir generate bt_update_trigger_template_corr_only.sql 10 | 11 | commit; 12 | -------------------------------------------------------------------------------- /generate_bitemporal/generate_bt_insert_trigger_template.sql: -------------------------------------------------------------------------------- 1 | create or replace function generate_bt_insert_trigger_template (p_table_name text) returns text 2 | as 3 | $function_body$ 4 | DECLARE 5 | v_trigger_text text; 6 | v_list_of_fields_ext text; 7 | v_list_of_values_ext text:=' '; 8 | v_list_of_fields_arr text[]; 9 | v_schema_name text; 10 | v_table_name text; 11 | v_bt_table_name text; 12 | v_current_field text; 13 | BEGIN 14 | select split_part(p_table_name,'.',1) into v_schema_name; 15 | select split_part(p_table_name,'.',2) into v_table_name; 16 | v_bt_table_name:=v_schema_name||'_bitemporal.'||v_table_name; 17 | select bitemporal_internal.ll_bitemporal_list_of_fields(v_bt_table_name) into v_list_of_fields_arr; 18 | v_list_of_fields_ext:=array_to_string(v_list_of_fields_arr, ','); 19 | FOREACH v_current_field in array v_list_of_fields_arr LOOP 20 | /*if v_list_of_values_ext>' ' then 21 | v_list_of_values_ext:=v_list_of_values_ext||','; 22 | end if; 23 | */ 24 | v_list_of_values_ext:=v_list_of_values_ext||$nxt$||$$,$$||case when NEW.$nxt$||v_current_field|| $nxt$ is NULL then 'NULL' else $$'$$||NEW.$nxt$||v_current_field|| $nxt$ ||$$'$$ end 25 | $nxt$; 26 | END LOOP; 27 | v_trigger_text:=format($tt$ 28 | CREATE OR REPLACE FUNCTION %s_insert_bitemp() 29 | RETURNS trigger AS 30 | $BODY$ 31 | DECLARE v_list_of_fields text :=%L; 32 | v_list_of_values text; 33 | v_effective tstzrange; 34 | v_asserted tstzrange; 35 | BEGIN 36 | SELECT tstzrange(now(), 'infinity', '[)') into v_asserted; 37 | SELECT tstzrange(now(), 'infinity', '[)') into v_effective; /*review*/ 38 | v_list_of_values :=%s; /*review*/ 39 | perform bitemporal_internal.ll_bitemporal_insert(%L , 40 | v_list_of_fields,v_list_of_values, 41 | v_effective, 42 | v_asserted); 43 | return new; 44 | END; 45 | 46 | $BODY$ 47 | LANGUAGE plpgsql VOLATILE; 48 | $tt$, 49 | p_table_name, 50 | v_list_of_fields_ext, 51 | v_list_of_values_ext, 52 | v_bt_table_name 53 | ); 54 | 55 | return v_trigger_text; 56 | end; 57 | $function_body$ 58 | language plpgsql; 59 | -------------------------------------------------------------------------------- /generate_bitemporal/generate_bt_update_trigger_template.sql: -------------------------------------------------------------------------------- 1 | create or replace function generate_bt_update_trigger_template (p_table_name text) returns text 2 | as 3 | $function_body$ 4 | DECLARE 5 | v_trigger_text text; 6 | v_list_of_fields_ext text; 7 | v_list_of_values_ext text:=' '; 8 | v_list_of_fields_arr text[]; 9 | v_schema_name text; 10 | v_table_name text; 11 | v_bt_table_name text; 12 | v_current_field text; 13 | BEGIN 14 | select split_part(p_table_name,'.',1) into v_schema_name; 15 | select split_part(p_table_name,'.',2) into v_table_name; 16 | v_bt_table_name:=v_schema_name||'_bitemporal.'||v_table_name; 17 | select bitemporal_internal.ll_bitemporal_list_of_fields(v_bt_table_name) into v_list_of_fields_arr; 18 | v_list_of_fields_ext:=array_to_string(v_list_of_fields_arr, ','); 19 | FOREACH v_current_field in array v_list_of_fields_arr LOOP 20 | /*if v_list_of_values_ext>' ' then 21 | v_list_of_values_ext:=v_list_of_values_ext||','; 22 | end if; 23 | */ 24 | v_list_of_values_ext:=v_list_of_values_ext||$nxt$||$$,$$||case when NEW.$nxt$||v_current_field|| $nxt$ is NULL then 'NULL' else $$'$$||NEW.$nxt$||v_current_field|| $nxt$ ||$$'$$ end 25 | $nxt$; 26 | END LOOP; 27 | v_trigger_text:=format($tt$ 28 | CREATE OR REPLACE FUNCTION %s_update_bitemp() 29 | RETURNS trigger AS 30 | $BODY$ 31 | DECLARE v_list_of_fields text :=%L; /*exclude table_id */ 32 | v_list_of_values text; 33 | v_effective tstzrange; 34 | v_asserted tstzrange; 35 | BEGIN 36 | SELECT tstzrange(now(), 'infinity', '[)') into v_asserted; 37 | SELECT tstzrange(new.time, 'infinity', '[)') into v_effective; /*review*/ 38 | v_list_of_values :=%s; /*exclude table_id*/ 39 | if new.time!=old.time then /*review*/ 40 | perform bitemporal_internal.ll_bitemporal_update(%L , 41 | v_list_of_fields,v_list_of_values, 42 | '%s_id', 43 | NEW.%s_id::text, 44 | v_effective, 45 | v_asserted); 46 | else 47 | perform bitemporal_internal.ll_bitemporal_correction(%L , 48 | v_list_of_fields,v_list_of_values, 49 | '%s_id', 50 | NEW.%s_id::text, 51 | v_effective); 52 | end if; 53 | return new; 54 | END; 55 | $BODY$ 56 | LANGUAGE plpgsql VOLATILE; 57 | $tt$, 58 | p_table_name, 59 | v_list_of_fields_ext, 60 | v_list_of_values_ext, 61 | v_bt_table_name, 62 | v_table_name, 63 | v_table_name, 64 | v_bt_table_name, 65 | v_table_name, 66 | v_table_name 67 | ); 68 | 69 | return v_trigger_text; 70 | end; 71 | $function_body$ 72 | language plpgsql; 73 | -------------------------------------------------------------------------------- /generate_bitemporal/generate_bt_update_trigger_template_corr_only.sql: -------------------------------------------------------------------------------- 1 | create or replace function generate_bt_update_trigger_template_corr_only (p_table_name text) 2 | returns text 3 | as 4 | $function_body$ 5 | DECLARE 6 | v_trigger_text text; 7 | v_list_of_fields_ext text; 8 | v_list_of_values_ext text:=' '; 9 | v_list_of_fields_arr text[]; 10 | v_schema_name text; 11 | v_table_name text; 12 | v_bt_table_name text; 13 | v_current_field text; 14 | BEGIN 15 | select split_part(p_table_name,'.',1) into v_schema_name; 16 | select split_part(p_table_name,'.',2) into v_table_name; 17 | v_bt_table_name:=v_schema_name||'_bitemporal.'||v_table_name; 18 | select bitemporal_internal.ll_bitemporal_list_of_fields(v_bt_table_name) into v_list_of_fields_arr; 19 | v_list_of_fields_ext:=array_to_string(v_list_of_fields_arr, ','); 20 | FOREACH v_current_field in array v_list_of_fields_arr LOOP 21 | /*if v_list_of_values_ext>' ' then 22 | v_list_of_values_ext:=v_list_of_values_ext||','; 23 | end if; 24 | */ 25 | v_list_of_values_ext:=v_list_of_values_ext||$nxt$||$$,$$||case when NEW.$nxt$||v_current_field|| $nxt$ is NULL then 'NULL' else $$'$$||NEW.$nxt$||v_current_field|| $nxt$ ||$$'$$ end 26 | $nxt$; 27 | END LOOP; 28 | v_trigger_text:=format($tt$ 29 | CREATE OR REPLACE FUNCTION %s_update_bitemp() 30 | RETURNS trigger AS 31 | $BODY$ 32 | DECLARE v_list_of_fields text :=%L; 33 | v_list_of_values text; 34 | v_effective tstzrange; 35 | 36 | BEGIN 37 | --SELECT tstzrange(now(), 'infinity', '[)') into v_effective; 38 | SELECT distinct(effective) into v_effective 39 | from %s where %s_id=new.%s_id; /* review */ 40 | v_list_of_values :=%s; /*remove id*/ 41 | perform bitemporal_internal.ll_bitemporal_correction(%L , 42 | v_list_of_fields,v_list_of_values, 43 | 'table_id', /* review */ 44 | NEW.table_id::text,/* review */ 45 | v_effective 46 | ); 47 | return new; 48 | END; 49 | 50 | $BODY$ 51 | LANGUAGE plpgsql VOLATILE; 52 | $tt$, 53 | p_table_name, 54 | v_list_of_fields_ext, 55 | v_bt_table_name, 56 | v_table_name, 57 | v_table_name, 58 | v_list_of_values_ext, 59 | v_bt_table_name 60 | ); 61 | 62 | return v_trigger_text; 63 | end; 64 | $function_body$ 65 | language plpgsql; 66 | -------------------------------------------------------------------------------- /generate_bitemporal/ll_generate_bitemp_for_schema.sql: -------------------------------------------------------------------------------- 1 | --select bitemporal_internal.ll_generate_bitemp_for_schema('capture_messages_core_reporting') 2 | 3 | create or replace function bitemporal_internal.ll_generate_bitemp_for_schema(p_schema_name text) 4 | returns text as 5 | $BODY$ 6 | declare 7 | v_rec record; 8 | v_rec2 record; 9 | v_table_definition text; 10 | v_business_key text; 11 | v_business_key_def int2[]; 12 | v_all_tables text:=' '; 13 | begin 14 | for v_rec in (select c.relname, lower(c.relname) as stg_name, 15 | c.oid from pg_class c 16 | JOIN pg_namespace n ON n.oid = c.relnamespace and relkind='r' 17 | and n.nspname=p_schema_name 18 | order by 1) 19 | loop 20 | v_table_definition:= format( 21 | $text$select * from 22 | bitemporal_internal.ll_create_bitemporal_table ('%s_bt', 23 | %L, 24 | '$text$, 25 | p_schema_name, 26 | v_rec.stg_name); 27 | select conkey into v_business_key_def from pg_constraint where conrelid=v_rec.oid 28 | and contype='p'; 29 | --raise notice '%', v_business_key_def; 30 | v_business_key:=NULL; 31 | for v_rec2 in (select ordinal_position, 32 | column_name::text as column_name, 33 | data_type::text|| 34 | case when character_maximum_length is not null 35 | then '('||character_maximum_length::text||')' 36 | else '' 37 | end || 38 | case data_type when 'numeric' 39 | then '('||numeric_precision::text||','||numeric_scale::text|| ')' 40 | else '' 41 | end 42 | as data_type, 43 | case is_nullable 44 | when 'NO' then 'NOT NULL' 45 | else '' 46 | end as nullable 47 | from information_schema.columns 48 | where table_schema=p_schema_name 49 | and table_name=v_rec.stg_name 50 | order by ordinal_position) 51 | loop 52 | if v_rec2.ordinal_position>1 then 53 | v_table_definition:= 54 | v_table_definition||','; 55 | end if; 56 | v_table_definition:= 57 | v_table_definition||format($text$%s %s 58 | $text$, 59 | v_rec2.column_name, 60 | v_rec2.data_type); 61 | if v_rec2.ordinal_position = any (v_business_key_def) 62 | then if v_business_key is null 63 | then v_business_key:=v_rec2.column_name ;else 64 | v_business_key:=v_business_key||','||v_rec2.column_name; 65 | end if; 66 | end if; 67 | 68 | end loop; 69 | v_table_definition:= v_table_definition|| format( 70 | $text$', 71 | %L 72 | ); 73 | 74 | $text$, 75 | v_business_key); 76 | 77 | v_all_tables:=v_all_tables|| v_table_definition; 78 | end loop; 79 | return v_all_tables; 80 | end; 81 | $BODY$ 82 | LANGUAGE plpgsql; -------------------------------------------------------------------------------- /sql/RI_BT_FKey_check_ins.sql: -------------------------------------------------------------------------------- 1 | 2 | CREATE or replace FUNCTION bitemporal_internal.ri_bt_fkey_check_ins() 3 | RETURNS trigger 4 | LANGUAGE 'plpgsql' 5 | COST 100.0 6 | AS $BODY$ 7 | 8 | /* TG_ARGV[0] is a schema name 9 | TG_ARGV[1] is a table name 10 | TG_ARGV[2] is a column name 11 | */ 12 | DECLARE v_value integer; 13 | v_result boolean; 14 | BEGIN 15 | v_value:=NEW.device_id; 16 | execute format($ef$ select * from %s.validate_bitemporal_%s_%s(%s, 17 | $1, $2)$ef$ , 18 | TG_ARGV[0], 19 | TG_ARGV[1], 20 | TG_ARGV[2], 21 | v_value 22 | ) into v_result 23 | using NEW.effective, NEW.asserted; 24 | 25 | if v_result is false then 26 | RAISE EXCEPTION '% % foreign key constraint violated', TG_ARGV[2], NEW.device_id; 27 | end if; 28 | return new; 29 | END; 30 | 31 | $BODY$; 32 | -------------------------------------------------------------------------------- /sql/RI_BT_FKey_check_ins_device_id.sql: -------------------------------------------------------------------------------- 1 | 2 | CREATE or replace FUNCTION bitemporal_internal.ri_bt_fkey_check_ins_device_id() 3 | RETURNS trigger 4 | LANGUAGE 'plpgsql' 5 | COST 100.0 6 | AS $BODY$ 7 | 8 | /* TG_ARGV[0] is a schema name 9 | TG_ARGV[1] is a table name 10 | TG_ARGV[2] is a column name 11 | */ 12 | DECLARE v_value integer; 13 | v_result boolean; 14 | BEGIN 15 | v_value:=NEW.device_id; 16 | execute format($ef$ select * from %s.validate_bitemporal_%s_%s(%s, 17 | $1, $2)$ef$ , 18 | TG_ARGV[0], 19 | TG_ARGV[1], 20 | TG_ARGV[2], 21 | v_value 22 | ) into v_result 23 | using NEW.effective, NEW.asserted; 24 | 25 | if v_result is false then 26 | RAISE EXCEPTION '% % foreign key constraint violated', TG_ARGV[2], NEW.device_id; 27 | end if; 28 | return new; 29 | END; 30 | 31 | $BODY$; 32 | -------------------------------------------------------------------------------- /sql/_load_all.sql: -------------------------------------------------------------------------------- 1 | \echo Start load all bitemporal code 2 | \set ON_ERROR_STOP on 3 | \pset pager off 4 | -- toggle timing to get a better idea of what is going on 5 | --\timing on 6 | set client_min_messages to warning; 7 | 8 | \ir extensions.sql 9 | \ir relationships.sql 10 | 11 | begin; 12 | set search_path to bitemporal_internal, public; 13 | 14 | 15 | \ir bitemporal_internal_schema.sql 16 | 17 | \ir metadata.sql 18 | 19 | \ir ll_create_bitemporal_table.sql 20 | \ir ll_bitemporal_list_of_fields.sql 21 | \ir ll_is_bitemporal_table.sql 22 | \ir ll_check_bitemporal_update_conditions.sql 23 | \ir ll_bitemporal_split_effective.sql 24 | \ir ll_bitemporal_correction.sql 25 | \ir ll_bitemporal_correction_hist.sql 26 | \ir ll_bitemporal_delete.sql 27 | \ir ll_bitemporal_inactivate.sql 28 | \ir ll_bitemporal_insert.sql 29 | \ir ll_bitemporal_insert_select.sql 30 | \ir ll_bitemporal_update.sql 31 | \ir ll_bitemporal_update_select.sql 32 | \ir ll_bitemporal_delete_select.sql 33 | \ir ll_create_bitemporal_table_partitioned.sql 34 | \ir ll_create_bitemporal_partition.sql 35 | 36 | commit; 37 | 38 | -------------------------------------------------------------------------------- /sql/bitemporal_internal_schema.sql: -------------------------------------------------------------------------------- 1 | CREATE SCHEMA IF NOT EXISTS bitemporal_internal; 2 | grant usage on schema bitemporal_internal to public; 3 | 4 | -------------------------------------------------------------------------------- /sql/extensions.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | set local search_path to public; 3 | 4 | create extension if not exists btree_gist; 5 | 6 | 7 | commit; 8 | -------------------------------------------------------------------------------- /sql/get_column_type.sql: -------------------------------------------------------------------------------- 1 | create or replace function temporal_relationships.get_column_type( 2 | p_schema_name text, 3 | p_table_name text, 4 | p_column_name text) 5 | RETURNS text 6 | LANGUAGE 'sql' 7 | COST 100.0 8 | AS $function$ 9 | select t.typname :: text 10 | from pg_class c 11 | JOIN pg_attribute a ON c.oid = a.attrelid and 12 | c.relname=p_table_name and attname=p_column_name 13 | JOIN pg_namespace n ON n.oid = c.relnamespace and n.nspname=p_schema_name 14 | join pg_type t on atttypid =t.oid; 15 | $function$; 16 | -------------------------------------------------------------------------------- /sql/ll_add_fk.sql: -------------------------------------------------------------------------------- 1 | create or replace function bitemporal_internal.ll_add_fk( 2 | p_schema_name text, 3 | p_table_name text, 4 | p_column_name text, 5 | p_source_schema_name text, 6 | p_source_table_name text, 7 | p_source_column_name text) 8 | returns text 9 | as 10 | $BODY$ 11 | declare 12 | v_fk_constraint_name text; 13 | v_function_name text; 14 | v_trigger_function_name text; 15 | v_return_type text; 16 | begin 17 | if bitemporal_internal.validate_bitemporal_pk_uq( 18 | p_source_schema_name, 19 | p_source_table_name, 20 | p_source_column_name) IS NULL 21 | then 22 | return 'no primary key or unique constraint'; 23 | exit; 24 | end if; 25 | v_return_type:=temporal_relationships.get_column_type( 26 | p_source_schema_name , 27 | p_source_table_name , 28 | p_source_column_name ); 29 | v_fk_constraint_name:= bitemporal_internal.fk_constraint( 30 | p_column_name, 31 | p_source_table_name, 32 | p_source_column_name); 33 | execute format ($a$ALTER TABLE %s.%s ADD %s $a$ 34 | ,p_schema_name 35 | ,p_table_name 36 | ,v_fk_constraint_name) ; 37 | 38 | if not bitemporal_internal.ll_lookup_validation_function( 39 | p_source_schema_name, 40 | p_source_table_name, 41 | p_source_column_name ) then 42 | select * into v_function_name from bitemporal_internal.ll_generate_fk_validate( 43 | p_source_schema_name, 44 | p_source_table_name , 45 | p_source_column_name); 46 | end if; 47 | /*do not need to check whether this constraint already exists, 48 | it will error, if exists */ 49 | select * into v_trigger_function_name 50 | from bitemporal_internal.ll_generate_fk_trigger_function( 51 | p_schema_name , 52 | p_table_name , 53 | p_column_name ) ; 54 | execute format ($create_tg$ 55 | create trigger t_RI_bt_insert_%s_%s 56 | BEFORE INSERT OR UPDATE ON %s.%s 57 | FOR EACH ROW 58 | EXECUTE PROCEDURE %s(%s, %s, %s) 59 | $create_tg$, 60 | p_table_name, 61 | p_column_name, 62 | p_schema_name, 63 | p_table_name, 64 | v_trigger_function_name, 65 | p_schema_name, 66 | p_table_name, 67 | p_column_name 68 | ) ; 69 | return v_fk_constraint_name; 70 | 71 | END; 72 | $BODY$ 73 | LANGUAGE plpgsql; 74 | 75 | 76 | -------------------------------------------------------------------------------- /sql/ll_bitemporal_correction.sql: -------------------------------------------------------------------------------- 1 | 2 | CREATE OR REPLACE FUNCTION bitemporal_internal.ll_bitemporal_correction(p_schema_name text, 3 | p_table_name text, 4 | p_list_of_fields text, 5 | p_list_of_values text, 6 | p_search_fields text, 7 | p_search_values text, 8 | p_effective temporal_relationships.timeperiod, 9 | p_now temporal_relationships.time_endpoint ) 10 | RETURNS integer AS 11 | $BODY$ 12 | DECLARE 13 | v_sql text; 14 | v_rowcount INTEGER:=0; 15 | v_list_of_fields_to_insert text; 16 | v_table_attr text[]; 17 | v_now temporal_relationships.time_endpoint:=p_now ;-- for compatiability with the previous version 18 | v_serial_key text:=p_table_name||'_key'; 19 | v_table text:=p_schema_name||'.'||p_table_name; 20 | v_effective_start temporal_relationships.time_endpoint:=lower(p_effective) ; 21 | v_keys int[]; 22 | v_keys_old int[]; 23 | BEGIN 24 | v_table_attr := bitemporal_internal.ll_bitemporal_list_of_fields(v_table); 25 | IF array_length(v_table_attr,1)=0 26 | THEN RAISE EXCEPTION 'Empty list of fields for a table: %', v_table; 27 | RETURN v_rowcount; 28 | END IF; 29 | 30 | v_list_of_fields_to_insert:= array_to_string(v_table_attr, ',',''); 31 | EXECUTE 32 | format($u$ WITH updt AS (UPDATE %s SET asserted = temporal_relationships.timeperiod_range(lower(asserted), %L, '[)') 33 | WHERE ( %s )=( %s ) AND %L=lower(effective) 34 | AND upper(asserted)='infinity' 35 | AnD lower(asserted)<%L returning %s ) 36 | SELECT array_agg(%s) FROM updt 37 | $u$ --end assertion period for the old record(s), if any 38 | , v_table 39 | , v_now 40 | , p_search_fields 41 | , p_search_values 42 | , v_effective_start 43 | , v_now 44 | , v_serial_key 45 | , v_serial_key) into v_keys_old; 46 | -- raise notice 'sql%', v_sql; 47 | 48 | EXECUTE 49 | -- v_sql:= 50 | format($i$WITH inst AS (INSERT INTO %s ( %s, effective, asserted ) 51 | SELECT %s ,effective, temporal_relationships.timeperiod_range(upper(asserted), 'infinity', '[)') 52 | FROM %s WHERE ( %s )IN ( %s ) 53 | returning %s ) 54 | SELECT array_agg(%s) FROM inst $i$ --insert new assertion rage with old values where applicable 55 | , v_table 56 | , v_list_of_fields_to_insert 57 | , v_list_of_fields_to_insert 58 | , v_table 59 | , v_serial_key 60 | , coalesce(array_to_string(v_keys_old,','),'NULL') 61 | , v_serial_key 62 | , v_serial_key 63 | )into v_keys; 64 | --raise notice 'sql%', v_sql; 65 | 66 | --raise notice 'sql%', v_sql; 67 | if coalesce(array_to_string(v_keys_old,',')) IS NULL 68 | then 69 | EXECUTE format($uu$UPDATE %s SET ( %s ) = (SELECT %s ) WHERE ( %s ) = ( %s ) 70 | AND effective = %L 71 | AND upper(asserted)='infinity' 72 | $uu$ --update new assertion rage with new values 73 | , v_table 74 | , p_list_of_fields 75 | , p_list_of_values 76 | , p_search_fields 77 | , p_search_values 78 | , p_effective 79 | ) 80 | ; 81 | 82 | ELSE 83 | EXECUTE 84 | -- v_sql:= 85 | format($uu$UPDATE %s SET ( %s ) = ( SELECT %s ) WHERE ( %s ) IN ( %s ) 86 | $uu$ --update new assertion rage with new values 87 | , v_table 88 | , p_list_of_fields 89 | , p_list_of_values 90 | , v_serial_key 91 | ,coalesce(array_to_string(v_keys,','), 'NULL')); 92 | 93 | -- raise notice 'sql%', v_sql; 94 | END IF; 95 | GET DIAGNOSTICS v_rowcount:=ROW_COUNT; 96 | 97 | RETURN v_rowcount; 98 | END; 99 | $BODY$ 100 | LANGUAGE plpgsql VOLATILE; 101 | 102 | 103 | CREATE OR REPLACE FUNCTION bitemporal_internal.ll_bitemporal_correction(p_schema_name text, 104 | p_table_name text, 105 | p_list_of_fields text, 106 | p_list_of_values text, 107 | p_search_fields text, 108 | p_search_values text, 109 | p_effective temporal_relationships.timeperiod) 110 | RETURNS integer AS 111 | $BODY$ 112 | declare v_rowcount int; 113 | begin 114 | select * into v_rowcount from bitemporal_internal.ll_bitemporal_correction(p_schema_name , 115 | p_table_name , 116 | p_list_of_fields , 117 | p_list_of_values , 118 | p_search_fields , 119 | p_search_values, 120 | p_effective , 121 | clock_timestamp() ); 122 | return v_rowcount; 123 | END; 124 | $BODY$ 125 | LANGUAGE plpgsql VOLATILE; 126 | -------------------------------------------------------------------------------- /sql/ll_bitemporal_correction_hist.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION bitemporal_internal.ll_bitemporal_correction_hist(p_schema_name text, 2 | p_table_name text, 3 | p_list_of_fields text, 4 | p_list_of_values text, 5 | p_search_fields text, 6 | p_search_values text, 7 | p_effective temporal_relationships.timeperiod, 8 | p_now temporal_relationships.time_endpoint ) 9 | RETURNS integer AS 10 | $BODY$ 11 | DECLARE 12 | v_sql text; 13 | v_rowcount INTEGER:=0; 14 | v_cnt int:=0; 15 | v_list_of_fields_to_insert text; 16 | v_table_attr text[]; 17 | v_now temporal_relationships.time_endpoint:=p_now ;-- for compatiability with the previous version 18 | v_effective_start temporal_relationships.time_endpoint; 19 | v_serial_key text:=p_table_name||'_key'; 20 | v_table text:=p_schema_name||'.'||p_table_name; 21 | v_keys int[]; 22 | v_keys_old int[]; 23 | v_effective temporal_relationships.timeperiod; 24 | v_asserted temporal_relationships.timeperiod; 25 | u_effective temporal_relationships.timeperiod; 26 | u_asserted temporal_relationships.timeperiod; 27 | BEGIN 28 | v_table_attr := bitemporal_internal.ll_bitemporal_list_of_fields(v_table); 29 | IF array_length(v_table_attr,1)=0 30 | THEN RAISE EXCEPTION 'Empty list of fields for a table: %', v_table; 31 | RETURN v_rowcount; 32 | END IF; 33 | 34 | v_list_of_fields_to_insert:= array_to_string(v_table_attr, ',',''); 35 | 36 | execute format($$select distinct effective, asserted from %s 37 | WHERE ( %s )=( %s ) AND %L::timestamptz<@effective 38 | AND upper(asserted)='infinity' 39 | AND lower(asserted)<%L $$ 40 | , v_table 41 | , p_search_fields 42 | , p_search_values 43 | , lower(p_effective) 44 | , v_now 45 | ) 46 | into v_effective, v_asserted ; 47 | -- raise notice 'effective:%',v_effective; 48 | IF lower(v_effective)lower(u_effective) 84 | THEN ---create new interval 85 | perform bitemporal_internal.ll_bitemporal_split_effective( 86 | p_schema_name, 87 | p_table_name, 88 | p_search_fields, 89 | p_search_values, 90 | upper(p_effective), 91 | u_asserted); 92 | END IF; 93 | ---done with splitting intervals 94 | 95 | /* 96 | select bitemporal_internal.ll_bitemporal_correction( 97 | p_schema_name, 98 | p_table_name, 99 | p_list_of_fields, 100 | p_list_of_values , 101 | p_search_fields, 102 | p_search_values, 103 | temporal_relationships.timeperiod(lower(p_effective), v_effective_start), 104 | v_now) into v_cnt; 105 | 106 | --v_effective_start:=upper(v_effective); 107 | v_cnt:=1; 108 | ELSE 109 | v_effective_start:=lower(p_effective); 110 | END IF; 111 | */ 112 | EXECUTE 113 | --v_sql:= 114 | format($u$ WITH updt AS (UPDATE %s SET asserted = temporal_relationships.timeperiod(lower(asserted), %L) 115 | WHERE ( %s )=( %s ) AND effective<@ %L 116 | AND upper(asserted)='infinity' 117 | AND lower(asserted)<%L returning %s ) 118 | SELECT array_agg(%s) FROM updt 119 | $u$ --end assertion period for the old record(s), if any 120 | , v_table 121 | , v_now 122 | , p_search_fields 123 | , p_search_values 124 | , p_effective 125 | , v_now 126 | , v_serial_key 127 | , v_serial_key 128 | ) into v_keys_old; 129 | -- raise notice 'sql%', v_sql; 130 | 131 | EXECUTE 132 | -- v_sql:= 133 | format($i$WITH inst AS (INSERT INTO %s ( %s, effective, asserted ) 134 | SELECT %s ,effective, temporal_relationships.timeperiod_range(upper(asserted), 'infinity', '[)') 135 | FROM %s WHERE ( %s )IN ( %s ) 136 | returning %s ) 137 | SELECT array_agg(%s) FROM inst $i$ --insert new assertion rage with old values where applicable 138 | , v_table 139 | , v_list_of_fields_to_insert 140 | , v_list_of_fields_to_insert 141 | , v_table 142 | , v_serial_key 143 | , coalesce(array_to_string(v_keys_old,','),'NULL') 144 | , v_serial_key 145 | , v_serial_key 146 | )into v_keys; 147 | --raise notice 'sql%', v_sql; 148 | 149 | --raise notice 'sql%', v_sql; 150 | if coalesce(array_to_string(v_keys_old,',')) IS NULL 151 | then 152 | EXECUTE format($uu$UPDATE %s SET ( %s ) = (SELECT %s ) WHERE ( %s ) = ( %s ) 153 | AND lower(effective)>= lower(%L::temporal_relationships.timeperiod) 154 | and upper(effective) <=upper(%L::temporal_relationships.timeperiod) ---is_included (effective ) 155 | 156 | AND upper(asserted)='infinity' 157 | $uu$ --update new assertion rage with new values 158 | , v_table 159 | , p_list_of_fields 160 | , p_list_of_values 161 | , p_search_fields 162 | , p_search_values 163 | , p_effective 164 | ,p_effective 165 | ) 166 | ; 167 | 168 | ELSE 169 | EXECUTE 170 | -- v_sql:= 171 | format($uu$UPDATE %s SET ( %s ) = ( SELECT %s ) WHERE ( %s ) IN ( %s ) 172 | $uu$ --update new assertion rage with new values 173 | , v_table 174 | , p_list_of_fields 175 | , p_list_of_values 176 | , v_serial_key 177 | ,coalesce(array_to_string(v_keys,','), 'NULL')); 178 | 179 | -- raise notice 'sql%', v_sql; 180 | END IF; 181 | GET DIAGNOSTICS v_rowcount:=ROW_COUNT; 182 | if coalesce(array_to_string(v_keys,',')) IS NULL 183 | then v_rowcount:=0; 184 | end if; 185 | RETURN v_rowcount+v_cnt; 186 | END; 187 | $BODY$ 188 | LANGUAGE plpgsql VOLATILE; 189 | 190 | 191 | 192 | CREATE OR REPLACE FUNCTION bitemporal_internal.ll_bitemporal_correction_hist(p_schema_name text, 193 | p_table_name text, 194 | p_list_of_fields text, 195 | p_list_of_values text, 196 | p_search_fields text, 197 | p_search_values text, 198 | p_effective temporal_relationships.timeperiod) 199 | RETURNS integer AS 200 | $BODY$ 201 | declare v_rowcount int; 202 | begin 203 | select * into v_rowcount from bitemporal_internal.ll_bitemporal_correction_hist(p_schema_name , 204 | p_table_name , 205 | p_list_of_fields , 206 | p_list_of_values , 207 | p_search_fields , 208 | p_search_values, 209 | p_effective , 210 | clock_timestamp() ); 211 | return v_rowcount; 212 | END; 213 | $BODY$ 214 | LANGUAGE plpgsql VOLATILE; 215 | -------------------------------------------------------------------------------- /sql/ll_bitemporal_correction_select.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION bitemporal_internal.ll_bitemporal_correction_select( 2 | p_table text, 3 | p_list_of_fields text, 4 | p_values_selected_update text, 5 | p_where text, 6 | -- p_values_selected_search text, 7 | p_effective_at time_endpoint , 8 | p_now time_endpoint) 9 | RETURNS integer AS 10 | $BODY$ 11 | DECLARE 12 | v_sql text; 13 | v_rowcount INTEGER:=0; 14 | v_list_of_fields_to_insert text; 15 | v_table_attr text[]; 16 | v_now temporal_relationships.time_endpoint:=p_now ;-- for compatiability with the previous version 17 | v_effective_at temporal_relationships.time_endpoint:=p_effective_at ; 18 | BEGIN 19 | v_table_attr := bitemporal_internal.ll_bitemporal_list_of_fields(p_table); 20 | IF array_length(v_table_attr,1)=0 21 | THEN RAISE EXCEPTION 'Empty list of fields for a table: %', p_table; 22 | RETURN v_rowcount; 23 | END IF; 24 | 25 | v_list_of_fields_to_insert:= array_to_string(v_table_attr, ',',''); 26 | 27 | EXECUTE 28 | --v_sql:= 29 | format($u$ UPDATE %s t SET asserted = temporal_relationships.timeperiod_range(lower(asserted), %L, '[)') 30 | WHERE %s AND %L::timestamptz <@ t.effective 31 | AND upper(t.asserted)='infinity' 32 | AnD lower(t.asserted)<%L$u$ --end assertion period for the old record(s), if any 33 | , p_table 34 | , v_now 35 | , p_where 36 | ,v_effective_at 37 | , v_now); 38 | -- raise notice 'sql %', v_sql; 39 | 40 | EXECUTE 41 | -- v_sql:= 42 | format($i$INSERT INTO %s ( %s, effective, asserted ) 43 | SELECT %s ,effective, temporal_relationships.timeperiod_range(now(), 44 | 'infinity', '[)') 45 | FROM %s WHERE %s AND %L::timestamptz <@ effective 46 | AND upper(asserted)= %L 47 | $i$ --insert new assertion rage with old values where applicable 48 | , p_table 49 | , v_list_of_fields_to_insert 50 | , v_list_of_fields_to_insert 51 | , p_table 52 | , p_where 53 | , v_effective_at 54 | , v_now 55 | ); 56 | --raise notice 'sql%', v_sql; 57 | 58 | EXECUTE 59 | -- v_sql:= 60 | format($uu$UPDATE %s t SET ( %s ) = ( %s ) WHERE %s 61 | AND %L::timestamptz <@ t.effective 62 | AND upper(asserted)='infinity' 63 | RETURNING * $uu$ --update new assertion rage with new values 64 | , p_table 65 | , p_list_of_fields 66 | , p_values_selected_update 67 | , p_where 68 | , v_effective_at 69 | ) ; 70 | -- raise notice 'sql%', v_sql; 71 | GET DIAGNOSTICS v_rowcount:=ROW_COUNT; 72 | RETURN v_rowcount; 73 | END; 74 | $BODY$ 75 | LANGUAGE plpgsql ; -------------------------------------------------------------------------------- /sql/ll_bitemporal_delete.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION bitemporal_internal.ll_bitemporal_delete(p_table text 2 | , p_search_fields TEXT -- search fields 3 | , p_search_values TEXT -- search values 4 | , p_asserted temporal_relationships.timeperiod -- will be asserted 5 | ) 6 | RETURNS INTEGER 7 | AS 8 | $BODY$ 9 | DECLARE 10 | v_rowcount INTEGER:=0; 11 | BEGIN 12 | --end assertion period for the current records record(s) 13 | 14 | EXECUTE format($u$ UPDATE %s SET asserted = 15 | temporal_relationships.timeperiod(lower(asserted), lower(%L::temporal_relationships.timeperiod)) 16 | WHERE ( %s )=( %s )AND lower(%L::temporal_relationships.timeperiod)<@ asserted $u$ 17 | , p_table 18 | , p_asserted 19 | , p_search_fields 20 | , p_search_values 21 | , p_asserted 22 | ); 23 | 24 | 25 | GET DIAGNOSTICS v_rowcount:=ROW_COUNT; 26 | RETURN v_rowcount; 27 | END; 28 | $BODY$ LANGUAGE plpgsql; 29 | 30 | -------------------------------------------------------------------------------- /sql/ll_bitemporal_delete_select.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION bitemporal_internal.ll_bitemporal_delete_select( 2 | p_table text, 3 | p_search_fields text, 4 | p_values_selected_search text, 5 | p_asserted temporal_relationships.timeperiod) 6 | RETURNS integer 7 | LANGUAGE 'plpgsql' 8 | COST 100 9 | VOLATILE 10 | AS $BODY$ 11 | 12 | DECLARE 13 | v_rowcount INTEGER:=0; 14 | v_table_attr text[]; 15 | v_now timestamptz:=now();-- so that we can reference this time 16 | BEGIN 17 | EXECUTE format($u$ UPDATE %s t SET asserted = 18 | temporal_relationships.timeperiod(lower(asserted), lower(%L::temporal_relationships.timeperiod)) 19 | WHERE ( %s )in( %s ) AND lower(%L::temporal_relationships.timeperiod)<@asserted $u$ 20 | , p_table 21 | , p_asserted 22 | , p_search_fields 23 | , p_values_selected_search 24 | , p_asserted); 25 | 26 | GET DIAGNOSTICS v_rowcount:=ROW_COUNT; 27 | RETURN v_rowcount; 28 | END; 29 | 30 | $BODY$; 31 | 32 | CREATE OR REPLACE FUNCTION bitemporal_internal.ll_bitemporal_delete_select( 33 | p_table text, 34 | p_selected_search text, 35 | p_asserted temporal_relationships.timeperiod) 36 | RETURNS integer 37 | LANGUAGE 'plpgsql' 38 | COST 100 39 | VOLATILE 40 | AS $BODY$ 41 | 42 | DECLARE 43 | v_rowcount INTEGER:=0; 44 | v_table_attr text[]; 45 | v_now timestamptz:=now();-- so that we can reference this time 46 | BEGIN 47 | EXECUTE format($u$ UPDATE %s t SET asserted = 48 | temporal_relationships.timeperiod(lower(asserted), lower(%L::temporal_relationships.timeperiod)) 49 | WHERE ( %s ) AND lower(%L::temporal_relationships.timeperiod)<@asserted $u$ 50 | , p_table 51 | , p_asserted 52 | , p_selected_search 53 | , p_asserted); 54 | 55 | GET DIAGNOSTICS v_rowcount:=ROW_COUNT; 56 | RETURN v_rowcount; 57 | END; 58 | 59 | $BODY$; 60 | 61 | -------------------------------------------------------------------------------- /sql/ll_bitemporal_inactivate.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION bitemporal_internal.ll_bitemporal_inactivate(p_schema_name text, 2 | p_table_name text 3 | , p_search_fields TEXT -- search fields 4 | , p_search_values TEXT -- search values 5 | , p_effective temporal_relationships.timeperiod -- inactive starting 6 | , p_asserted temporal_relationships.timeperiod -- will be asserted 7 | ) 8 | RETURNS INTEGER 9 | AS 10 | $BODY$ 11 | DECLARE 12 | v_sql text ; 13 | v_rowcount INTEGER:=0; 14 | v_list_of_fields_to_insert text:=' '; 15 | v_list_of_fields_to_insert_excl_effective text; 16 | v_table_attr text[]; 17 | v_now timestamptz:=now();-- so that we can reference this time 18 | v_keys int[]; 19 | v_keys_old int[]; 20 | v_serial_key text:=p_table_name||'_key'; 21 | v_table text:=p_schema_name||'.'||p_table_name; 22 | 23 | BEGIN 24 | IF lower(p_asserted)0) pa 16 | LEFT OUTER JOIN pg_attrdef pad ON adrelid=p_table::regclass 17 | AND adrelid=attrelid 18 | AND pa.attnum=pad.adnum 19 | WHERE (adsrc NOT LIKE 'nextval%' OR adsrc IS NULL) 20 | AND attname !='asserted' 21 | AND attname !='effective' 22 | AND attname !='row_created_at' 23 | and attname not like '%dropped%' 24 | ORDER BY pa.attnum)); 25 | END; 26 | $BODY$ LANGUAGE plpgsql 27 | $txt$ ; 28 | else v_sql:= 29 | $txt$ 30 | CREATE OR REPLACE FUNCTION bitemporal_internal.ll_bitemporal_list_of_fields(p_table text) RETURNS text[] 31 | AS 32 | $BODY$ 33 | BEGIN 34 | RETURN ( array(SELECT attname 35 | FROM (SELECT * FROM pg_attribute 36 | WHERE attrelid=p_table::regclass AND attnum >1) pa 37 | LEFT OUTER JOIN pg_attrdef pad ON adrelid=p_table::regclass 38 | AND adrelid=attrelid 39 | AND pa.attnum=pad.adnum 40 | WHERE attname !='asserted' 41 | AND attname !='effective' 42 | AND attname !='row_created_at' 43 | AND attname not like '%dropped%' 44 | ORDER BY pa.attnum)); 45 | END; 46 | $BODY$ LANGUAGE plpgsql 47 | $txt$; 48 | 49 | end if; 50 | 51 | execute (v_sql); 52 | return null; 53 | 54 | end; 55 | $GBODY$ LANGUAGE plpgsql; 56 | 57 | select * from bitemporal_internal.generate_ll_bitemporal_list_of_fields(); 58 | drop function bitemporal_internal.generate_ll_bitemporal_list_of_fields(); 59 | -------------------------------------------------------------------------------- /sql/ll_bitemporal_split_effective.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION bitemporal_internal.ll_bitemporal_split_effective(p_schema_name text 2 | ,p_table_name TEXT 3 | ,p_search_fields TEXT -- search fields 4 | ,p_search_values TEXT -- search values 5 | ,p_effective_split temporal_relationships.time_endpoint 6 | ,p_asserted temporal_relationships.timeperiod -- assertion for the update 7 | ) 8 | RETURNS INTEGER 9 | AS 10 | $BODY$ 11 | DECLARE 12 | v_rowcount INTEGER:=0; 13 | v_list_of_fields_to_insert text:=' '; 14 | v_list_of_fields_to_insert_excl_effective text; 15 | v_table_attr text[]; 16 | v_serial_key text:=p_table_name||'_key'; 17 | v_table text:=p_schema_name||'.'||p_table_name; 18 | v_keys_old int[]; 19 | v_keys int[]; 20 | v_now timestamptz:=now();-- so that we can reference this time 21 | BEGIN 22 | /*IF lower(p_asserted)1 and attnum in ( 22 | select unnest(conkey) as attnum 23 | from pg_constraint 24 | where conrelid::regclass= (p_schema||'.'||p_table)::regclass 25 | and contype='p') 26 | ); 27 | v_business_key_name :=substr(p_partition_name||'_'||translate( 28 | translate(v_business_key, ' 29 | ',''), ', ','_'),1,47)||'_assert_eff_excl'; 30 | v_business_key_gist :=replace(v_business_key, ',',' WITH =,')||' WITH =, asserted WITH &&, effective WITH &&'; 31 | --raise notice 'gist %',v_business_key_gist; 32 | --EXECUTE 33 | v_sql :=format($create$ 34 | CREATE TABLE %s.%s PARTITION OF 35 | %s.%s FOR VALUES %s; 36 | ALTER TABLE %s.%s ADD CONSTRAINT 37 | %s EXCLUDE 38 | USING gist (%s) 39 | $create$ 40 | ,p_schema 41 | ,p_partition_name 42 | ,p_schema 43 | ,p_table 44 | ,p_range 45 | ,p_schema 46 | , p_partition_name 47 | ,v_business_key_name 48 | ,v_business_key_gist 49 | ) ; 50 | raise notice '%', v_sql; 51 | execute v_sql; 52 | RETURN ('true'); 53 | EXCEPTION WHEN OTHERS THEN 54 | GET STACKED DIAGNOSTICS v_error = MESSAGE_TEXT; 55 | raise notice '%', v_error; 56 | RETURN ('false'); 57 | END; 58 | $BODY$; 59 | -------------------------------------------------------------------------------- /sql/ll_create_bitemporal_table.sql: -------------------------------------------------------------------------------- 1 | 2 | CREATE OR REPLACE FUNCTION bitemporal_internal.ll_create_bitemporal_table( 3 | p_schema text, 4 | p_table text, 5 | p_table_definition text, 6 | p_business_key text) 7 | RETURNS boolean AS 8 | $BODY$ 9 | DECLARE 10 | v_business_key_name text; 11 | v_business_key_gist text; 12 | v_serial_key_name text; 13 | v_serial_key text; 14 | v_pk_constraint_name text; 15 | v_table_definition text; 16 | v_error text; 17 | v_business_key_array text[]; 18 | i int; 19 | BEGIN 20 | v_serial_key :=p_table||'_key'; 21 | v_serial_key_name :=v_serial_key ||' serial'; 22 | v_pk_constraint_name:= p_table||'_pk'; 23 | v_business_key_name :=p_table||'_'||translate(p_business_key, ', ','_')||'_assert_eff_excl'; 24 | v_business_key_gist :=replace(p_business_key, ',',' WITH =,')||' WITH =, asserted WITH &&, effective WITH &&'; 25 | --raise notice 'gist %',v_business_key_gist; 26 | v_table_definition :=replace (p_table_definition, ' serial', ' integer'); 27 | v_business_key_array :=string_to_array(p_business_key, ','); 28 | 29 | EXECUTE format($create$ 30 | CREATE TABLE %s.%s ( 31 | %s 32 | ,%s 33 | ,effective temporal_relationships.timeperiod NOT NULL 34 | ,asserted temporal_relationships.timeperiod NOT NULL 35 | ,row_created_at timestamptz NOT NULL DEFAULT now() 36 | ,CONSTRAINT %s PRIMARY KEY (%s) 37 | ,CONSTRAINT %s EXCLUDE 38 | USING gist (%s) 39 | ) 40 | $create$ 41 | ,p_schema 42 | ,p_table 43 | ,v_serial_key_name 44 | ,v_table_definition 45 | ,v_pk_constraint_name 46 | ,v_serial_key 47 | ,v_business_key_name 48 | ,v_business_key_gist 49 | ) ; 50 | i:=1; 51 | while v_business_key_array[i] is not null loop 52 | execute format($alter$ 53 | ALTER TABLE %s.%s ALTER %s SET NOT NULL 54 | $alter$ 55 | ,p_schema 56 | ,p_table 57 | ,v_business_key_array[i] 58 | ) ; 59 | i:=i+1; 60 | end loop; 61 | RETURN ('true'); 62 | EXCEPTION WHEN OTHERS THEN 63 | GET STACKED DIAGNOSTICS v_error = MESSAGE_TEXT; 64 | raise notice '%', v_error; 65 | RETURN ('false'); 66 | END; 67 | $BODY$ 68 | LANGUAGE plpgsql; -------------------------------------------------------------------------------- /sql/ll_create_bitemporal_table_partitioned.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION bitemporal_internal.ll_create_bitemporal_table_partitioned( 2 | p_schema text, 3 | p_table text, 4 | p_table_definition text, 5 | p_business_key text, 6 | p_partitioned_by text default null) 7 | RETURNS boolean 8 | LANGUAGE 'plpgsql' 9 | AS $BODY$ 10 | DECLARE 11 | v_business_key_name text; 12 | v_business_key_gist text; 13 | v_serial_key_name text; 14 | v_serial_key text; 15 | v_pk_constraint_name text; 16 | v_table_definition text; 17 | v_error text; 18 | v_business_key_array text[]; 19 | i int; 20 | v_partition_clause text; 21 | v_sql text; 22 | BEGIN 23 | v_serial_key :=p_table||'_key'; 24 | v_serial_key_name :=v_serial_key ||' serial'; 25 | v_pk_constraint_name:= p_table||'_pk'; 26 | v_table_definition :=replace (p_table_definition, ' serial', ' integer'); 27 | v_business_key_array :=string_to_array(p_business_key, ','); 28 | v_partition_clause := ' partition by range('||coalesce(p_partitioned_by,p_business_key)||')'; 29 | --EXECUTE 30 | v_sql :=format($create$ 31 | CREATE TABLE %s.%s ( 32 | %s 33 | ,%s 34 | ,effective temporal_relationships.timeperiod NOT NULL 35 | ,asserted temporal_relationships.timeperiod NOT NULL 36 | ,row_created_at timestamptz NOT NULL DEFAULT now() 37 | ,CONSTRAINT %s PRIMARY KEY (%s,%s) 38 | ) %s 39 | $create$ 40 | ,p_schema 41 | ,p_table 42 | ,v_serial_key_name 43 | ,v_table_definition 44 | ,v_pk_constraint_name 45 | ,v_serial_key 46 | ,p_business_key 47 | , v_partition_clause 48 | ) ; 49 | raise notice '%', v_sql; 50 | execute V_sql; 51 | i:=1; 52 | while v_business_key_array[i] is not null loop 53 | execute format($alter$ 54 | ALTER TABLE %s.%s ALTER %s SET NOT NULL 55 | $alter$ 56 | ,p_schema 57 | ,p_table 58 | ,v_business_key_array[i] 59 | ) ; 60 | i:=i+1; 61 | end loop; 62 | RETURN ('true'); 63 | EXCEPTION WHEN OTHERS THEN 64 | GET STACKED DIAGNOSTICS v_error = MESSAGE_TEXT; 65 | raise notice '%', v_error; 66 | RETURN ('false'); 67 | END; 68 | $BODY$; 69 | -------------------------------------------------------------------------------- /sql/ll_generate_fk_trigger_function.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION bitemporal_internal.ll_generate_fk_trigger_function( 2 | p_schema_name text, 3 | p_table_name text, 4 | p_column_name text) returns text 5 | as $BODY_AUTO$ 6 | declare t text; 7 | v_trigger_function_name text; 8 | v_trigger_name text; 9 | v_return_type text; 10 | BEGIN 11 | v_trigger_function_name:=p_schema_name||'.RI_BT_FKey_check_ins_'||p_column_name; 12 | t:=format($execute$create or replace function %s () returns trigger as 13 | $TR_BODY$ 14 | /* TG_ARGV[0] is a schema name 15 | TG_ARGV[1] is a table name 16 | TG_ARGV[2] is a column name 17 | */ 18 | DECLARE v_value anyelement; 19 | v_result boolean; 20 | 21 | BEGIN 22 | v_value:=NEW.%s; 23 | execute format($ef$ select * from %%s.validate_bitemporal_%%s_%%s(%%s, 24 | $1, $2)$ef$ , 25 | TG_ARGV[0], 26 | TG_ARGV[1], 27 | TG_ARGV[2], 28 | v_value 29 | ) into v_result 30 | using NEW.effective, NEW.asserted; 31 | if v_result is false then 32 | RAISE EXCEPTION '%% %% foreign key constraint violated', TG_ARGV[2], NEW.%s; 33 | end if; 34 | return new; 35 | END; 36 | $TR_BODY$ 37 | LANGUAGE plpgsql; 38 | $execute$ 39 | , v_trigger_function_name 40 | , p_column_name 41 | , p_column_name 42 | ); 43 | --raise notice 'code:%',t; 44 | return v_trigger_function_name; 45 | END; 46 | $BODY_AUTO$ 47 | LANGUAGE plpgsql VOLATILE 48 | ; 49 | 50 | -------------------------------------------------------------------------------- /sql/ll_generate_fk_validate.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION bitemporal_internal.ll_generate_fk_validate( 2 | p_schema_name text, 3 | p_table_name text, 4 | p_column_name text) returns text 5 | as $BODY_AUTO$ 6 | declare t text; 7 | v_function_name text; 8 | --v_return_type text; 9 | BEGIN 10 | v_function_name:='validate_bt_'||p_table_name||'_'||p_column_name; 11 | /*v_return_type :=temporal_relationships.get_column_type( 12 | p_schema_name , 13 | p_table_name , 14 | p_column_name );*/ 15 | 16 | --EXECUTE 17 | t:=format($execute$ 18 | create or replace function %s.%s( 19 | p_value anyelement, 20 | p_effective temporal_relationships.timeperiod, 21 | p_asserted temporal_relationships.timeperiod) 22 | RETURNS boolean AS 23 | $BODY$ 24 | declare 25 | v_record record; 26 | i integer:=0; 27 | v_min_low_effective temporal_relationships.time_endpoint; 28 | v_max_upper_effective temporal_relationships.time_endpoint; 29 | v_min_low_asserted temporal_relationships.time_endpoint; 30 | v_max_upper_asserted temporal_relationships.time_endpoint; 31 | begin 32 | for v_record in select effective from 33 | %s.%s where %s=p_value 34 | and temporal_relationships.has_includes(effective, p_effective) 35 | and temporal_relationships.has_includes(asserted ,p_asserted ) 36 | order by lower(effective), upper(effective) 37 | loop 38 | if i=0 then 39 | if lower(p_effective) v_max_upper_effective 49 | then 50 | raise notice 'false- gap in effective!'; 51 | return false; 52 | else 53 | if upper(v_record.effective) > v_max_upper_effective ---sanity check 54 | then v_max_upper_effective:= upper(v_record.effective) ; 55 | end if; 56 | end if; 57 | end loop; 58 | if i=0 then 59 | return false; 60 | end if; 61 | if v_max_upper_effective< upper(p_effective) then 62 | return false; 63 | end if; 64 | i:=0; 65 | for v_record in select asserted from 66 | %s.%s where %s=p_value 67 | and temporal_relationships.has_includes(effective,p_effective) 68 | and temporal_relationships.has_includes(asserted,p_asserted ) 69 | order by lower(asserted), upper(asserted) 70 | loop 71 | if i=0 then 72 | if lower(p_asserted) v_max_upper_asserted 82 | then 83 | return false; 84 | else 85 | if upper(v_record.asserted) > v_max_upper_asserted ---sanity check 86 | then v_max_upper_asserted:= upper(v_record.asserted) ; 87 | end if; 88 | end if; 89 | end loop; 90 | if i=0 then 91 | return false; 92 | end if; 93 | if v_max_upper_asserted< upper(p_asserted) then 94 | return false; 95 | end if; 96 | return true; 97 | end; 98 | $BODY$ 99 | LANGUAGE plpgsql 100 | $execute$ 101 | , p_schema_name 102 | , v_function_name 103 | , v_return_type 104 | , p_schema_name 105 | , p_table_name 106 | , p_column_name 107 | , p_schema_name 108 | , p_table_name 109 | , p_column_name); 110 | raise notice 'code:%',t; 111 | return v_function_name; 112 | END; 113 | $BODY_AUTO$ 114 | LANGUAGE plpgsql VOLATILE 115 | ; 116 | -------------------------------------------------------------------------------- /sql/ll_is_bitemporal_table.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION bitemporal_internal.ll_is_bitemporal_table(p_table text) RETURNS boolean immutable 2 | AS 3 | $$ 4 | DECLARE 5 | v_schemaname text; 6 | v_tablename text; 7 | BEGIN 8 | SELECT split_part(p_table, '.', 1) INTO v_schemaname; 9 | SELECT split_part(p_table, '.', 2) INTO v_tablename; 10 | RETURN 11 | ( SELECT 12 | coalesce(max(CASE WHEN a.attname='asserted' THEN 1 ELSE 0 END),0) + 13 | coalesce(max(CASE WHEN a.attname='effective' THEN 1 ELSE 0 END),0)=2 14 | AND exists (select 1 from pg_attribute ac 15 | JOIN pg_class cc 16 | ON ac.attrelid=cc.oid 17 | and ac.attname='row_created_at' 18 | JOIN pg_namespace n ON n.oid = cc.relnamespace 19 | and n.nspname=v_schemaname AND cc.relname=v_tablename) 20 | FROM pg_class c 21 | JOIN pg_namespace n ON n.oid = c.relnamespace and relkind='i' 22 | join pg_am am ON am.oid=c.relam 23 | join pg_index x ON c.oid=x.indexrelid 24 | and amname='gist' 25 | and indisexclusion='true' 26 | JOIN pg_class cc ON cc.oid = x.indrelid 27 | join pg_attribute a ON a.attrelid=c.oid 28 | join pg_type t ON a.atttypid=t.oid 29 | -- join pg_attribute ac ON ac.attrelid=cc.oid 30 | WHERE n.nspname=v_schemaname AND cc.relname=v_tablename); 31 | END; 32 | $$ LANGUAGE plpgsql; 33 | -------------------------------------------------------------------------------- /sql/ll_lookup_validation_function.sql: -------------------------------------------------------------------------------- 1 | create or replace function bitemporal_internal.ll_lookup_validation_function( 2 | p_schema_name text, 3 | p_table_name text, 4 | p_column_name text) 5 | returns boolean immutable as 6 | $$select count(*)=1 from 7 | pg_proc p 8 | join pg_namespace n ON n.oid = p.pronamespace 9 | and proname ='validate_bt_'||p_table_name||'_'||p_column_name 10 | and n.nspname=p_schema_name 11 | ;$$ 12 | language sql; -------------------------------------------------------------------------------- /sql/metadata.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- 3 | -- triggers, not null, exclusions and check 4 | -- all work exactly the same given the bitemporal constraints 5 | -- 6 | -- 3 constraints do not. primary key, foreign key and unique constraints. 7 | -- 8 | 9 | -- create the three types of constraints. 10 | -- need strings to include in a create table 11 | -- need commands to modify existing table 12 | 13 | -- find the a particular set of constraints given a table 14 | -- 15 | 16 | create or replace 17 | function bitemporal_internal.conname_prefix() returns text 18 | language sql IMMUTABLE as $f$ 19 | select 'bitemporal'::text; 20 | $f$; 21 | 22 | create or replace 23 | function bitemporal_internal.mk_conname(con_type text, src_column text, fk_table text, fk_column text ) 24 | returns text 25 | language sql IMMUTABLE 26 | as $f$ 27 | select substring(format('%s %s %s%s%s', conname_prefix() 28 | , con_type 29 | , src_column 30 | , fk_table, fk_column) 31 | from 0 for 64 ); 32 | $f$ 33 | SET search_path = 'bitemporal_internal'; 34 | 35 | 36 | create or replace 37 | function bitemporal_internal.mk_constraint(con_type text, con_name text, con_src text) 38 | returns text 39 | language sql IMMUTABLE 40 | as $ff$ 41 | select format($$CONSTRAINT %I check(true or '%s' <> '@%s@') $$ 42 | , con_name 43 | , con_type 44 | , con_src)::text; 45 | $ff$; 46 | 47 | create or replace 48 | function bitemporal_internal.pk_constraint(src_column text) 49 | returns text 50 | language sql IMMUTABLE as $f$ 51 | select mk_constraint('pk', mk_conname('pk', src_column, '', '') , src_column); 52 | $f$ 53 | SET search_path = 'bitemporal_internal'; 54 | 55 | create or replace 56 | function bitemporal_internal.fk_constraint(src_column text, fk_table text, fk_column text, connname text) 57 | returns text 58 | language sql IMMUTABLE 59 | as $ff$ 60 | select mk_constraint('fk' 61 | , connname 62 | , format('%s -> %s(%s)', src_column, fk_table, fk_column) ); 63 | $ff$ 64 | SET search_path = 'bitemporal_internal'; 65 | 66 | create or replace 67 | function bitemporal_internal.fk_constraint(src_column text, fk_table text, fk_column text) 68 | returns text 69 | language sql IMMUTABLE 70 | as $ff$ 71 | select fk_constraint(src_column , fk_table , fk_column, 72 | mk_conname('fk', src_column, fk_table, fk_column)); 73 | $ff$ 74 | SET search_path = 'bitemporal_internal'; 75 | 76 | create or replace 77 | function bitemporal_internal.unique_constraint(src_column text) 78 | returns setof text 79 | language sql IMMUTABLE 80 | as $f$ 81 | values ( mk_constraint('u' 82 | , mk_conname('u', src_column, '','') 83 | , format('%s', src_column) )), 84 | (format('CONSTRAINT %I EXCLUDE USING gist (%I WITH =, asserted WITH &&, effective WITH &&)' 85 | , mk_conname('unique', src_column, '', '') 86 | , src_column)::text) 87 | 88 | ; 89 | -- CONSTRAINT devices_device_id_asserted_effective_excl EXCLUDE 90 | -- USING gist (device_id WITH =, asserted WITH &&, effective WITH &&) 91 | $f$ 92 | SET search_path = 'bitemporal_internal'; 93 | 94 | create or replace 95 | function bitemporal_internal.add_constraint(table_name text, _con text) 96 | returns text 97 | language sql IMMUTABLE 98 | as $f$ 99 | select format('alter table %s add %s', table_name, _con)::text; 100 | $f$; 101 | 102 | create or replace 103 | function bitemporal_internal.select_constraint_value(src text) 104 | returns text 105 | language plpgsql IMMUTABLE 106 | as $f$ 107 | DECLARE 108 | at int; 109 | s text; 110 | BEGIN 111 | -- select inside @ @ 112 | at := strpos(src, '@'); 113 | s := substr(src, at + 1 ); 114 | at := strpos(s, '@'); 115 | return substring(s from 0::int for at ); 116 | END; 117 | $f$; 118 | drop type if exists bitemporal_internal.bitemporal_pg_constraint cascade; 119 | create 120 | type bitemporal_internal.bitemporal_pg_constraint 121 | as 122 | ( 123 | oid oid 124 | ,conname name 125 | ,connamespace oid 126 | ,contype "char" 127 | ,condeferrable bool 128 | ,condeferred bool 129 | ,convalidated bool 130 | ,conrelid oid 131 | ,contypid oid 132 | ,conindid oid 133 | -- ,conparentid oid 134 | ,confrelid oid 135 | ,confupdtype "char" 136 | ,confdeltype "char" 137 | ,confmatchtype "char" 138 | ,conislocal bool 139 | ,coninhcount int4 140 | ,connoinherit bool 141 | ,conkey int2[] 142 | ,confkey int2[] 143 | ,conpfeqop oid[] 144 | ,conppeqop oid[] 145 | ,conffeqop oid[] 146 | ,conexclop oid[] 147 | ,conbin pg_node_tree 148 | , consrc text 149 | ); 150 | 151 | create or replace 152 | function bitemporal_internal.find_constraints(table_name text, _criteria text ) 153 | returns setof bitemporal_internal.bitemporal_pg_constraint 154 | language sql IMMUTABLE 155 | as $f$ 156 | select oid, conname, connamespace, contype, 157 | condeferrable, condeferred,convalidated, 158 | conrelid, contypid, conindid, /* conparentid,*/ confrelid, 159 | confupdtype, confdeltype, confmatchtype, conislocal, 160 | coninhcount , connoinherit, conkey, confkey, 161 | conpfeqop , conppeqop , conffeqop , conexclop , conbin 162 | , pg_get_expr(conbin, conrelid) as consrc -- .pg_get_constraintdef() 163 | from pg_constraint 164 | where conrelid = cast(table_name as regclass) 165 | and conname like format('%s %s %%', bitemporal_internal.conname_prefix(), _criteria ) 166 | ; 167 | $f$; 168 | 169 | create or replace 170 | function bitemporal_internal.find_pk(table_name text) 171 | returns text 172 | language plpgsql IMMUTABLE 173 | as $f$ 174 | DECLARE 175 | r record; 176 | BEGIN 177 | select * into r from bitemporal_internal.find_constraints(table_name, 'pk'); 178 | RETURN bitemporal_internal.select_constraint_value(r.consrc); 179 | END; 180 | $f$; 181 | 182 | create table if not exists bitemporal_internal.fk_constraint_type ( 183 | conname name 184 | , src_column name 185 | , fk_table text 186 | , fk_column name 187 | ); 188 | 189 | create or replace 190 | function bitemporal_internal.split_out_fk(consrc text) 191 | returns bitemporal_internal.fk_constraint_type 192 | language plpgsql IMMUTABLE 193 | as $f$ 194 | DECLARE 195 | src text; 196 | ref text; 197 | rc fk_constraint_type%ROWTYPE; 198 | rp int; 199 | lp int; 200 | BEGIN 201 | -- format('%s -> %s(%s)', src_column, fk_table, fk_column) 202 | src := select_constraint_value(consrc) ; 203 | rc.src_column := split_part(src, ' ', 1); 204 | ref := split_part(src, ' ', 3); 205 | rp := strpos(ref, '('); 206 | lp := strpos(ref, ')'); 207 | if (lp < 1 or rp < 1 ) then 208 | raise notice 'split_out_bitemporal_fk: invaild format "%"', consrc ; 209 | return NULL; 210 | end if; 211 | rc.fk_table := substring(ref from 0 for rp ); 212 | rc.fk_column := substring(ref from rp +1 for (lp - rp -1) ); 213 | RETURN rc; 214 | END; 215 | $f$ 216 | SET search_path = 'bitemporal_internal'; 217 | 218 | create or replace 219 | function bitemporal_internal.find_fk(table_name text) 220 | returns setof bitemporal_internal.fk_constraint_type 221 | language plpgsql 222 | as $f$ 223 | DECLARE 224 | rc bitemporal_internal.fk_constraint_type%ROWTYPE; 225 | r record; 226 | BEGIN 227 | 228 | for r in select * from bitemporal_internal.find_constraints(table_name, 'fk') 229 | loop 230 | rc := bitemporal_internal.split_out_fk(r.consrc); 231 | rc.conname := r.conname; 232 | return next rc; 233 | end loop; 234 | RETURN ; 235 | END; 236 | $f$; 237 | 238 | 239 | 240 | /* 241 | conname | contype | conrelid | 242 | consrc 243 | ---------------------+---------+----------+----------------------------------------------------------------------------------------- 244 | bitemporal fk 1 | c | 1625561 | (true OR ('fk'::text <> '@node_id -> sg.networks network_id@'::text)) 245 | bitemporal fk 2 | c | 1625561 | (true OR ('fk'::text = ANY (ARRAY['node_id'::text, 'cnu.networks'::text, 'id'::text]))) 246 | bitemporal unique 3 | c | 1625561 | (true OR ('col'::text = 'name'::text)) 247 | 248 | */ 249 | 250 | -- vim: set filetype=pgsql expandtab tabstop=2 shiftwidth=2: 251 | -------------------------------------------------------------------------------- /sql/relationships.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | create schema if not exists temporal_relationships; 3 | grant usage on schema temporal_relationships to public; 4 | set local search_path to temporal_relationships, public; 5 | -- create a domain if not exists 6 | DO $d$ 7 | DECLARE 8 | domain_range_name text default 'timeperiod'; 9 | domain_range_type text default 'tstzrange'; 10 | domain_i_name text default 'time_endpoint'; 11 | domain_i_type text default 'timestamptz'; 12 | BEGIN 13 | -- Create timeperiod domain 14 | PERFORM n.nspname as "Schema", 15 | t.typname as "Name", 16 | pg_catalog.format_type(t.typbasetype, t.typtypmod) as "Type" 17 | FROM pg_catalog.pg_type t 18 | LEFT JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace 19 | WHERE t.typtype = 'd' 20 | AND n.nspname <> 'pg_catalog' 21 | AND n.nspname <> 'information_schema' 22 | AND pg_catalog.pg_type_is_visible(t.oid) 23 | AND t.typname = domain_range_name; 24 | if FOUND then 25 | raise NOTICE 'Domain % already exists', domain_range_name; 26 | else 27 | execute format('create domain %I as %I', domain_range_name, domain_range_type); 28 | end if; 29 | -- Create time_endpoint domain 30 | PERFORM n.nspname as "Schema", 31 | t.typname as "Name", 32 | pg_catalog.format_type(t.typbasetype, t.typtypmod) as "Type" 33 | FROM pg_catalog.pg_type t 34 | LEFT JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace 35 | WHERE t.typtype = 'd' 36 | AND n.nspname <> 'pg_catalog' 37 | AND n.nspname <> 'information_schema' 38 | AND pg_catalog.pg_type_is_visible(t.oid) 39 | AND t.typname = domain_i_name; 40 | if FOUND then 41 | raise NOTICE 'Domain % already exists', domain_i_name; 42 | else 43 | execute format('create domain %I as %I', domain_i_name, domain_i_type); 44 | end if; 45 | END; 46 | $d$; 47 | create or replace 48 | function timeperiod( p_range_start time_endpoint, p_range_end time_endpoint) 49 | RETURNS timeperiod 50 | language sql IMMUTABLE 51 | as 52 | $func$ 53 | select tstzrange(p_range_start, p_range_end,'[)')::timeperiod; 54 | $func$ 55 | SET search_path = 'temporal_relationships'; 56 | -- backwards compatible 57 | create or replace 58 | function timeperiod_range( _s time_endpoint, _e time_endpoint, _ignored text) 59 | returns timeperiod 60 | language sql 61 | as 62 | $func$ 63 | select timeperiod(_s,_e); 64 | $func$ 65 | SET search_path = 'temporal_relationships'; 66 | create or replace 67 | function xor(a boolean, b boolean) returns boolean 68 | language sql IMMUTABLE 69 | as 70 | $$ select ( (not a) <> (not b)); $$; 71 | 72 | create or replace 73 | function fst( x anyrange ) returns anyelement 74 | language SQL IMMUTABLE 75 | as 76 | $$ select lower(x); $$; 77 | 78 | create or replace 79 | function snd( x anyrange ) returns anyelement 80 | language SQL IMMUTABLE 81 | as 82 | $$ select upper(x); $$; 83 | -- 84 | -- [starts] [starts^-1] 85 | -- 86 | -- [starts A E] 87 | -- A |---| 88 | -- E |-------| 89 | -- 90 | -- [starts^-1 A E] 91 | -- A |-------| 92 | -- E |---| 93 | -- 94 | create or replace 95 | function has_starts(a timeperiod , b timeperiod ) 96 | returns boolean language SQL IMMUTABLE 97 | as $$ 98 | select fst(a) = fst(b) and snd(a) <> snd(b); 99 | $$ 100 | SET search_path = 'temporal_relationships'; 101 | -- 102 | -- [finishes] [finishes^-1] 103 | -- 104 | -- [finishes A E] 105 | -- A |-------| 106 | -- E |---| 107 | -- 108 | -- [finishes^-1 A E] 109 | -- A |---| 110 | -- E |-------| 111 | -- 112 | create or replace 113 | function has_finishes(a timeperiod, b timeperiod) 114 | returns boolean language SQL IMMUTABLE 115 | as $$ 116 | select snd(a) = snd(b) and fst(a) <> fst(b); 117 | $$ 118 | SET search_path = 'temporal_relationships'; 119 | -- 120 | -- [equals] 121 | -- 122 | -- [equals A E] 123 | -- A |----| 124 | -- E |----| 125 | -- 126 | create or replace 127 | function equals(a timeperiod, b timeperiod) 128 | returns boolean language SQL IMMUTABLE 129 | as $$ 130 | -- doubtful = operator exists for timeperiod 131 | select fst(a) = fst(b) and snd(a) = snd(b) ; 132 | $$ 133 | SET search_path = 'temporal_relationships'; 134 | -- 135 | -- [during] 136 | -- 137 | -- [during A E] 138 | -- A |---| 139 | -- E |-------| 140 | -- 141 | create or replace 142 | function is_during(a timeperiod, b timeperiod) 143 | returns boolean language SQL IMMUTABLE 144 | as $$ 145 | select (fst(a) > fst(b)) and (snd(a) < snd(b)); 146 | $$ 147 | SET search_path = 'temporal_relationships'; 148 | -- 149 | -- [during^-1] contained 150 | -- 151 | -- [during^-1 A E] 152 | -- A |-------| 153 | -- E |---| 154 | -- 155 | create or replace 156 | function is_contained_in(a timeperiod, b timeperiod) 157 | returns boolean language SQL IMMUTABLE 158 | as $$ 159 | select is_during(b, a); 160 | $$ 161 | SET search_path = 'temporal_relationships'; 162 | 163 | -- 164 | -- [during] or [during^-1] 165 | -- 166 | create or replace 167 | function has_during(a timeperiod, b timeperiod) 168 | returns boolean language SQL IMMUTABLE 169 | as $$ 170 | select is_during(a, b) or is_during(b,a); 171 | $$ 172 | SET search_path = 'temporal_relationships'; 173 | -- 174 | -- [overlaps] 175 | -- 176 | -- [overlaps A E] 177 | -- A |-----| 178 | -- E |-----| 179 | -- 180 | -- [overlaps^-1 A E] 181 | -- A |-----| 182 | -- E |-----| 183 | -- 184 | create or replace 185 | function is_overlaps(a timeperiod, b timeperiod) 186 | returns boolean language SQL IMMUTABLE 187 | 188 | as $$ 189 | select fst(a) < fst(b) and snd(a) > fst(b) and snd(a) < snd(b); 190 | $$ 191 | SET search_path = 'temporal_relationships'; 192 | 193 | -- 194 | -- either overlaps the other [overlaps] [overlaps^-1] 195 | -- 196 | create or replace 197 | function has_overlaps(a timeperiod, b timeperiod) 198 | returns boolean language SQL IMMUTABLE 199 | as $$ 200 | select is_overlaps(a , b ) or is_overlaps(b , a ) ; 201 | $$ 202 | SET search_path = 'temporal_relationships'; 203 | -- 204 | -- [before] 205 | -- 206 | -- [before A E] 207 | -- A |-----| 208 | -- E |-----| 209 | -- 210 | create or replace 211 | function is_before(a timeperiod, b timeperiod) 212 | returns boolean language SQL IMMUTABLE 213 | as $$ 214 | select snd(a) < fst(b); 215 | $$ 216 | SET search_path = 'temporal_relationships'; 217 | -- 218 | -- [before^-1] 219 | -- 220 | -- [before^-1 A E] 221 | -- A |-----| 222 | -- E |-----| 223 | -- 224 | create or replace 225 | function is_after(a timeperiod, b timeperiod) 226 | returns boolean language SQL IMMUTABLE 227 | as $$ 228 | -- is_before(b, a) 229 | select snd(b) < fst(a); 230 | $$ 231 | SET search_path = 'temporal_relationships'; 232 | 233 | -- 234 | -- either [before] [before^-1] 235 | -- 236 | create or replace 237 | function has_before(a timeperiod, b timeperiod) 238 | returns boolean language SQL IMMUTABLE 239 | as $$ 240 | select snd(a) < fst(b) or snd(b) < fst(a); 241 | $$ 242 | SET search_path = 'temporal_relationships'; 243 | -- 244 | -- [meets] [meets^-1] 245 | -- 246 | -- no shared time tick. 247 | -- 248 | -- [meets A E] 249 | -- A |-----| 250 | -- E |-----| 251 | -- 252 | -- [meets^-1 A E] 253 | -- A |-----| 254 | -- E |-----| 255 | -- 256 | create or replace 257 | function is_meets(a timeperiod, b timeperiod) 258 | returns boolean language SQL IMMUTABLE 259 | as $$ 260 | select snd(a) = fst(b) ; 261 | $$ 262 | SET search_path = 'temporal_relationships'; 263 | 264 | create or replace 265 | function has_meets(a timeperiod, b timeperiod) 266 | returns boolean language SQL IMMUTABLE 267 | as $$ 268 | select snd(a) = fst(b) or snd(b) = fst(a); 269 | $$ 270 | SET search_path = 'temporal_relationships'; 271 | -- 272 | -- Partition of Allen Relationships 273 | -- 274 | 275 | -- 276 | -- [Includes] 277 | -- [Contains] or [Overlaps] 278 | create or replace 279 | function has_includes(a timeperiod, b timeperiod) 280 | returns boolean language SQL IMMUTABLE 281 | as $$ 282 | select fst(a) = fst(b) or snd(a) = snd(b) or 283 | (snd(a) <= snd(b) and (fst(a) >= fst(b) or fst(b) < snd(a))) or 284 | (snd(a) >= snd(b) and (fst(a) < snd(b) or fst(a) <= fst(b))); 285 | $$ 286 | SET search_path = 'temporal_relationships'; 287 | 288 | -- 289 | -- [Contains] 290 | -- [Encloses] or [Equals] 291 | 292 | create or replace 293 | function has_contains(a timeperiod, b timeperiod) 294 | returns boolean language SQL IMMUTABLE 295 | 296 | as $$ 297 | select fst(a) = fst(b) or snd(a) = snd(b) or 298 | (snd(a) < snd(b) and fst(a) > fst(b)) or 299 | (snd(b) < snd(a) and fst(b) > fst(a)); 300 | $$ 301 | SET search_path = 'temporal_relationships'; 302 | 303 | -- 304 | -- [Aligns With] 305 | -- [Starts] or [Finishes] 306 | -- 307 | create or replace 308 | function has_aligns_with(a timeperiod, b timeperiod) 309 | returns boolean language SQL IMMUTABLE 310 | as $$ 311 | select xor( fst(a) = fst(b) , snd(a) = snd(b) ); 312 | $$ 313 | SET search_path = 'temporal_relationships'; 314 | 315 | -- 316 | -- [Encloses] 317 | -- [Aligns With] or [During] 318 | -- 319 | 320 | create or replace 321 | function has_encloses(a timeperiod, b timeperiod) 322 | returns boolean language SQL IMMUTABLE 323 | as $$ 324 | select has_during(a,b) or has_aligns_with(a,b); 325 | $$ 326 | SET search_path = 'temporal_relationships'; 327 | 328 | 329 | -- 330 | -- [Excludes] 331 | -- [Before] or [Meets] 332 | -- 333 | create or replace 334 | function has_excludes(a timeperiod, b timeperiod) 335 | returns boolean language SQL IMMUTABLE 336 | as $$ 337 | select fst(a) >= snd(b) or fst(b) >= snd(a) ; 338 | $$ 339 | SET search_path = 'temporal_relationships'; 340 | commit; 341 | 342 | -- vim: set filetype=pgsql expandtab tabstop=2 shiftwidth=2: 343 | -------------------------------------------------------------------------------- /sql/t_RI_bt_insert.sql: -------------------------------------------------------------------------------- 1 | create trigger t_RI_bt_insert 2 | BEFORE INSERT OR UPDATE ON bi_temp_tables.app_devices_test 3 | FOR EACH ROW 4 | EXECUTE PROCEDURE bitemporal_internal.RI_BT_FKey_check_ins('bi_temp_tables', 5 | 'app_devices_test', 'device_id'); 6 | -------------------------------------------------------------------------------- /tests/00_pgtap_working.sql: -------------------------------------------------------------------------------- 1 | -- Start a transaction. 2 | BEGIN; 3 | SELECT plan( 2 ); 4 | 5 | -- two simple tests to check pgtap is working 6 | SELECT ok( 7 | now() = now(), 8 | 'now() = now() should return true' 9 | ); 10 | 11 | SELECT is( 12 | ARRAY( 13 | VALUES (1),(2),(3) 14 | ), 15 | ARRAY[ 1,2, 3 ], 16 | 'An array of 3 values' 17 | ); 18 | 19 | SELECT * FROM finish(); 20 | ROLLBACK; 21 | 22 | 23 | -------------------------------------------------------------------------------- /tests/05_ll_functions.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | set client_min_messages to warning; 3 | set search_path = bitemporal_internal, public; 4 | 5 | SELECT plan(3); 6 | 7 | select unialike( current_setting('search_path'), '%temporal_relationships%' 8 | ,'temporal_relationships should NOT be on search_path for these tests' ); 9 | 10 | CREATE SCHEMA bi_temp_tables; 11 | 12 | --create test table 13 | -------------------------- 14 | drop table if exists bi_temp_tables.devices; 15 | select * from bitemporal_internal.ll_create_bitemporal_table('bi_temp_tables','devices', 16 | 'device_id integer, device_descr text', 'device_id') ; 17 | 18 | drop table if exists bi_temp_tables.devices_manual; 19 | create table bi_temp_tables.devices_manual ( 20 | device_id_key serial NOT NULL 21 | , device_id integer 22 | , effective tstzrange 23 | , asserted tstzrange 24 | , device_descr text 25 | , row_created_at timestamptz NOT NULL DEFAULT now() 26 | , CONSTRAINT devices_device_id_asserted_effective_excl EXCLUDE 27 | USING gist (device_id WITH =, asserted WITH &&, effective WITH &&) 28 | ); 29 | 30 | 31 | insert into bi_temp_tables.devices( 32 | device_id , 33 | effective, 34 | asserted, 35 | device_descr ) values (1, '[01-01-2015, infinity)', '[01-01-2015, infinity)','descr_1') 36 | ; 37 | 38 | ---non-temp for test 39 | drop table if exists bi_temp_tables.devices_non_temp; 40 | 41 | create table bi_temp_tables.devices_non_temp( 42 | device_id_key serial, 43 | device_id int4 44 | ); 45 | 46 | drop table if exists bi_temp_tables.devices_temp; 47 | create table bi_temp_tables.devices_temp( 48 | device_id_key serial, 49 | device_id int4, 50 | effective tsrange, 51 | EXCLUDE USING gist (device_id WITH =, effective WITH &&) 52 | ); 53 | 54 | 55 | -- 56 | -- Test each relationship function against the sample data 57 | -- 58 | 59 | select results_eq( 60 | $q$ select ll_is_bitemporal_table('bi_temp_tables.devices') 61 | $q$::text, 62 | $v$VALUES (true) $v$, 'bitemp_table' 63 | ); 64 | 65 | select results_eq( 66 | $q$ select ll_is_bitemporal_table('bi_temp_tables.devices_manual') 67 | $q$::text, 68 | $v$VALUES (true) $v$, 'bitemp_table' 69 | ); 70 | 71 | 72 | SELECT * FROM finish(); 73 | ROLLBACK; 74 | -------------------------------------------------------------------------------- /tests/06_privs.sql: -------------------------------------------------------------------------------- 1 | -- Start a transaction. 2 | BEGIN; 3 | SELECT plan( 2 ); 4 | 5 | SELECT schema_privs_are ( 6 | 'temporal_relationships' 7 | , 'public' 8 | , ARRAY['USAGE'] 9 | -- , ':description 10 | ); 11 | 12 | 13 | SELECT schema_privs_are ( 14 | 'bitemporal_internal' 15 | , 'public' 16 | , ARRAY['USAGE'] 17 | -- , ':description 18 | ); 19 | 20 | SELECT * FROM finish(); 21 | ROLLBACK; 22 | 23 | 24 | -------------------------------------------------------------------------------- /tests/10_relationships.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | set client_min_messages to warning; 3 | 4 | SELECT plan( 27 ); 5 | 6 | -- support functions: xor, fst, snd 7 | select is( temporal_relationships.xor(true, true), false) ; 8 | select is( temporal_relationships.xor(true, false), true) ; 9 | select is( temporal_relationships.xor(false, true), true) ; 10 | select is( temporal_relationships.xor(false, false), false) ; 11 | 12 | select is( temporal_relationships.fst( daterange('1999-01-01'::date, '2010-12-31'::date)), '1999-01-01'::date ); 13 | select is( temporal_relationships.snd( daterange('1999-01-01'::date, '2010-12-31'::date)), '2010-12-31'::date ); 14 | 15 | 16 | -------------------------- 17 | -- setup sample data 18 | select lives_ok($$ 19 | create view raw_testing_data (description,s1,f1,s2,f2, force_order) as 20 | values 21 | ('-- starts' 22 | ,'1999-01-01'::date 23 | ,'1999-01-10'::date 24 | ,'1999-01-01'::date 25 | ,'1999-01-22'::date 26 | ,1),( 27 | '-- starts^-1' 28 | ,'1999-02-01'::date 29 | ,'1999-02-10'::date 30 | ,'1999-02-01'::date 31 | ,'1999-02-22'::date 32 | ,2),( 33 | '--finish' 34 | ,'1999-01-22'::date 35 | ,'1999-02-28'::date 36 | ,'1999-01-10'::date 37 | ,'1999-02-28'::date 38 | ,3),( 39 | 40 | '--finish^-1' 41 | ,'1999-04-22'::date 42 | ,'1999-05-28'::date 43 | ,'1999-04-10'::date 44 | ,'1999-05-28'::date 45 | ,4),( 46 | 47 | '-- equals' 48 | ,'2000-01-01'::date 49 | ,'2000-01-02'::date 50 | ,'2000-01-01'::date 51 | ,'2000-01-02'::date 52 | ,5),( 53 | 54 | '--during' 55 | ,'2020-01-02'::date 56 | ,'2020-01-03'::date 57 | ,'2020-01-01'::date 58 | ,'2020-01-31'::date 59 | ,6),( 60 | 61 | '-- during^-1' 62 | ,'2020-03-01'::date 63 | ,'2020-03-31'::date 64 | ,'2020-03-02'::date 65 | ,'2020-03-12'::date 66 | ,7),( 67 | 68 | '-- overlaps' 69 | ,'1999-01-01'::date 70 | ,'2010-12-31'::date 71 | ,'2000-01-01'::date 72 | ,'2020-12-31'::date 73 | ,8),( 74 | 75 | '--overlaps^-1' 76 | ,'2000-01-01'::date 77 | ,'2002-12-31'::date 78 | ,'1999-01-01'::date 79 | ,'2001-12-31'::date 80 | ,9),( 81 | 82 | '--before' 83 | ,'1999-01-01'::date 84 | ,'1999-01-10'::date 85 | ,'2001-12-01'::date 86 | ,'2001-12-31'::date 87 | ,10),( 88 | 89 | '--before^-1' 90 | ,'2012-12-01'::date 91 | ,'2012-12-31'::date 92 | ,'1999-05-11'::date 93 | ,'1999-07-11'::date 94 | ,11),( 95 | 96 | '--meets' 97 | ,'2002-10-01'::date 98 | ,'2002-11-01'::date 99 | ,'2002-11-01'::date 100 | ,'2002-11-30'::date 101 | ,12),( 102 | 103 | '--meets^-1' 104 | ,'2020-01-01'::date 105 | ,'2020-01-31'::date 106 | ,'2019-12-01'::date 107 | ,'2020-01-01'::date 108 | ,13) 109 | ; 110 | create view testing_relationships (description, s1,f1,s2,f2, a, b) as 111 | select description,s1,f1,s2,f2, tstzrange(s1,f1, '[)'),tstzrange(s2,f2,'[)') 112 | , force_order 113 | from raw_testing_data order by force_order 114 | ; 115 | $$); 116 | 117 | select bag_eq( $q$ select count(*) from testing_relationships $q$::text, 118 | $$ values ( 13) $$ ); 119 | 120 | -- 121 | -- Test each relationship function against the sample data 122 | -- 123 | 124 | select results_eq( 125 | $q$ 126 | select 127 | temporal_relationships.has_starts(a , b) 128 | from testing_relationships 129 | $q$::text, 130 | $$ values 131 | (true), (true) 132 | , (false), (false), (false) 133 | , (false), (false), (false), (false) 134 | , (false), (false), (false), (false) 135 | $$,'has_starts' 136 | ); 137 | 138 | select results_eq( 139 | $q$ 140 | select 141 | temporal_relationships.has_finishes(a , b ) 142 | from testing_relationships 143 | $q$::text, 144 | $$ values 145 | (false), (false) 146 | , (true), (true) 147 | , (false) 148 | , (false), (false), (false), (false) 149 | , (false), (false), (false), (false) 150 | $$, 'has_finishes' 151 | ); 152 | select results_eq( 153 | $q$ 154 | select 155 | temporal_relationships.equals(a , b ) 156 | from testing_relationships 157 | $q$::text, 158 | $$ values 159 | (false), (false) 160 | , (false), (false) 161 | , (true) 162 | , (false), (false), (false), (false) 163 | , (false), (false), (false), (false) 164 | $$, 'equals' 165 | ); 166 | /* test 12 */ 167 | select results_eq( 168 | $q$ 169 | select 170 | temporal_relationships.is_during(a , b ) 171 | from testing_relationships 172 | $q$::text, 173 | $$ values 174 | (false), (false) 175 | , (false), (false), (false) 176 | , (true), (false) 177 | , (false), (false) 178 | , (false), (false), (false), (false) 179 | $$, 'is_during' 180 | ); 181 | select results_eq( 182 | $q$ 183 | select 184 | temporal_relationships.is_contained_in(a , b ) 185 | from testing_relationships 186 | $q$::text, 187 | $$ values 188 | (false), (false) 189 | , (false), (false), (false) 190 | , (false), (true), (false), (false) 191 | , (false), (false), (false), (false) 192 | $$, 'is_contained_in' 193 | ); 194 | select results_eq( 195 | $q$ 196 | select 197 | temporal_relationships.has_during(a , b ) 198 | from testing_relationships 199 | $q$::text, 200 | $$ values 201 | (false), (false) 202 | , (false), (false), (false) 203 | , (true), (true), (false), (false) 204 | , (false), (false), (false), (false) 205 | $$, 'has_during' 206 | ); 207 | 208 | select results_eq( 209 | $q$ 210 | select 211 | temporal_relationships.is_overlaps(a , b ) 212 | from testing_relationships 213 | $q$::text, 214 | $$ values 215 | (false), (false) 216 | , (false), (false), (false) 217 | , (false), (false), (true), (false) 218 | , (false), (false), (false), (false) 219 | $$, 'is_overlaps' 220 | ); 221 | select results_eq( 222 | $q$ 223 | select 224 | temporal_relationships.is_overlaps(b,a ) 225 | from testing_relationships 226 | $q$::text, 227 | $$ values 228 | (false), (false) 229 | , (false), (false), (false) 230 | , (false), (false), (false), (true) 231 | , (false), (false), (false), (false) 232 | $$, 'is_overlaps' 233 | ); 234 | select results_eq( 235 | $q$ 236 | select 237 | temporal_relationships.has_overlaps(a , b ) 238 | from testing_relationships 239 | $q$::text, 240 | $$ values 241 | (false), (false) 242 | , (false), (false), (false) 243 | , (false), (false), (true), (true) 244 | , (false), (false), (false), (false) 245 | $$, 'has_overlaps' 246 | ); 247 | select results_eq( 248 | $q$ 249 | select 250 | temporal_relationships.is_before(a , b ) 251 | from testing_relationships 252 | $q$::text, 253 | $$ values 254 | (false), (false) 255 | , (false), (false), (false) 256 | , (false), (false), (false), (false) 257 | , (true), (false), (false), (false) 258 | $$, 'is_before' 259 | ); 260 | select results_eq( 261 | $q$ 262 | select 263 | temporal_relationships.is_after(a , b ) 264 | from testing_relationships 265 | $q$::text, 266 | $$ values 267 | (false), (false) 268 | , (false), (false), (false) 269 | , (false), (false), (false), (false) 270 | , (false), (true), (false), (false) 271 | $$, 'is_after' 272 | ); 273 | select results_eq( 274 | $q$ 275 | select 276 | temporal_relationships.has_before(a , b ) 277 | from testing_relationships 278 | $q$::text, 279 | $$ values 280 | (false), (false) 281 | , (false), (false), (false) 282 | , (false), (false), (false), (false) 283 | , (true), (true), (false), (false) 284 | $$, 'has_before' 285 | ); 286 | select results_eq( 287 | $q$ 288 | select 289 | temporal_relationships.is_meets(a , b ) 290 | from testing_relationships 291 | $q$::text, 292 | $$ values 293 | (false), (false) 294 | , (false), (false), (false) 295 | , (false), (false), (false), (false) 296 | , (false), (false), (true), (false) 297 | $$, 'is_meets' 298 | ); 299 | select results_eq( 300 | $q$ 301 | select 302 | temporal_relationships.has_meets(a , b ) 303 | from testing_relationships 304 | $q$::text, 305 | $$ values 306 | (false), (false) 307 | , (false), (false), (false) 308 | , (false), (false), (false), (false) 309 | , (false), (false), (true), (true) 310 | $$, 'has_meets' 311 | ); 312 | 313 | -- partition functions 314 | 315 | select results_eq( 316 | $q$ 317 | select 318 | temporal_relationships.has_includes(a , b ) 319 | from testing_relationships 320 | $q$::text, 321 | $$ values 322 | (true), (true) 323 | , (true), (true), (true) 324 | , (true), (true), (true), (true) 325 | , (false), (false), (false), (false) 326 | $$, 'has_includes' 327 | ); 328 | select results_eq( 329 | $q$ 330 | select 331 | temporal_relationships.has_contains(a , b ) 332 | from testing_relationships 333 | $q$::text, 334 | $$ values 335 | (true), (true) 336 | , (true), (true), (true) 337 | , (true), (true), (false), (false) 338 | , (false), (false), (false), (false) 339 | $$, 'has_contains' 340 | ); 341 | select results_eq( 342 | $q$ 343 | select 344 | temporal_relationships.has_aligns_with(a , b ) 345 | from testing_relationships 346 | $q$::text, 347 | $$ values 348 | (true), (true) 349 | , (true), (true), (false) 350 | , (false), (false), (false), (false) 351 | , (false), (false), (false), (false) 352 | $$, 'has_aligns_with' 353 | ); 354 | select results_eq( 355 | $q$ 356 | select 357 | temporal_relationships.has_encloses(a , b ) 358 | from testing_relationships 359 | $q$::text, 360 | $$ values 361 | (true), (true) 362 | , (true), (true), (false) 363 | , (true), (true), (false), (false) 364 | , (false), (false), (false), (false) 365 | $$, 'has_encloses' 366 | ); 367 | select results_eq( 368 | $q$ 369 | select 370 | temporal_relationships.has_excludes(a , b ) 371 | from testing_relationships 372 | $q$::text, 373 | $$ values 374 | (false), (false) 375 | , (false), (false), (false) 376 | , (false), (false), (false), (false) 377 | , (true), (true), (true), (true) 378 | $$, 'has_excludes' 379 | ); 380 | 381 | SELECT * FROM finish(); 382 | ROLLBACK; 383 | -- vim: set filetype=pgsql expandtab tabstop=2 shiftwidth=2: 384 | -------------------------------------------------------------------------------- /tests/15_metadata.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | SELECT plan( 14 ); 3 | 4 | select unialike( current_setting('search_path'), '%bitemporal_internal%' 5 | ,'bitemporal_internal should NOT be on search_path for these tests' ); 6 | 7 | select lives_ok($$ 8 | create table t9 ( 9 | id serial primary key 10 | , name text 11 | , mark int 12 | , node_id int 13 | , unique (name) 14 | , unique ( mark ) 15 | , constraint "bitemporal fk 1" check ( true or 'fk' <> '@node_id -> sg.networks(network_id)@') 16 | , constraint "bitemporal fk 2" check ( true or 'fk' <>'@node_id -> networks(id)@' ) 17 | , constraint "bitemporal unique 3" check ( true or 'u' <> 'name' ) 18 | , constraint "bitemporal pk 1" check ( true or 'pk' <> '@id@') 19 | ) 20 | $$); 21 | 22 | -- consrc 23 | -- ---------------------+---------+----------+----------------------------------------------------------------------------------------- 24 | -- bitemporal fk 1 | c | 1625561 | (true OR ('fk'::text <> '@node_id -> sg.networks network_id@'::text)) 25 | -- bitemporal fk 2 | c | 1625561 | (true OR ('fk'::text = ANY (ARRAY['node_id'::text, 'cnu.networks'::text, 'id'::text]))) 26 | -- bitemporal unique 3 | c | 1625561 | (true OR ('col'::text = 'name'::text)) 27 | -- 28 | 29 | select lives_ok($$ 30 | select bitemporal_internal.conname_prefix() ; 31 | $$, 'bitemporal_conname_prefix' ); 32 | 33 | select is(bitemporal_internal.mk_conname('a','b','c','d') 34 | , format('%s a bcd', bitemporal_internal.conname_prefix() ) 35 | , 'mk_conname'); 36 | 37 | 38 | select is(bitemporal_internal.mk_constraint('type', 'name', 'source') 39 | , $$CONSTRAINT name check(true or 'type' <> '@source@') $$ 40 | , 'mk_constraint'); 41 | 42 | select is( bitemporal_internal.pk_constraint('src_column') 43 | , $$CONSTRAINT "bitemporal pk src_column" check(true or 'pk' <> '@src_column@') $$ 44 | , 'pk_constraint'); 45 | 46 | 47 | -- format('% -> %(%)', src_column, fk_table, fk_column) 48 | select is( bitemporal_internal.fk_constraint('a', 'b', 'c') 49 | , $$CONSTRAINT "bitemporal fk abc" check(true or 'fk' <> '@a -> b(c)@') $$ 50 | , 'fk_constraint'); 51 | 52 | select results_eq( 53 | $q$ 54 | select string_agg(a, ', ') from bitemporal_internal.unique_constraint('a') as s(a) 55 | $q$::text, 56 | $$ values 57 | ('CONSTRAINT "bitemporal u a" check(true or ''u'' <> ''@a@'')' || ' , ' || 58 | 'CONSTRAINT "bitemporal unique a" EXCLUDE USING gist '|| 59 | '(a WITH =, asserted WITH &&, effective WITH &&)') 60 | $$ 61 | , 'unique_constraint' ); 62 | 63 | select is( bitemporal_internal.select_constraint_value($$asdfasdfasdf '@XXX@' $$) 64 | , 'XXX' 65 | , 'select_constraint_value' ); 66 | 67 | select is(bitemporal_internal.add_constraint('t9', 'XXX') 68 | , $$alter table t9 add XXX$$ 69 | , 'add_constraint'); 70 | 71 | select is( bitemporal_internal.find_pk('t9') , $$id$$ , 'find_bitemporal_pk'); 72 | 73 | 74 | select bag_eq( $$ 75 | select * from bitemporal_internal.find_fk('t9') 76 | $$, 77 | $$ 78 | values 79 | ('bitemporal fk 1', 'node_id','sg.networks','network_id') 80 | , ('bitemporal fk 2','node_id','networks','id' ) 81 | $$ 82 | , 'find_bitemporal_fk'); 83 | 84 | select results_eq($$ 85 | select count(*)::int from bitemporal_internal.find_constraints('t9', '%' ) 86 | $$ 87 | , $$ 88 | values ( 4::int ) 89 | $$, 'find_constraints'); 90 | 91 | select has_relation('bitemporal_internal', 'fk_constraint_type', 'table bitemporal_internal.fk_constraint_type exists'); 92 | 93 | SELECT * FROM finish(); 94 | ROLLBACK; 95 | 96 | -- vim: set filetype=pgsql expandtab tabstop=2 shiftwidth=2: 97 | -------------------------------------------------------------------------------- /tests/16_metadata.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | SELECT plan( 2 ); 3 | 4 | 5 | CREATE TABLE postgres_auth_methods ( 6 | auth_method text NOT NULL unique 7 | ); 8 | 9 | COPY postgres_auth_methods (auth_method) FROM stdin; 10 | md5 11 | ldap 12 | krb 13 | ident 14 | ident pgadmin 15 | ident sameuser 16 | \. 17 | 18 | select lives_ok($$ 19 | 20 | select bitemporal_internal.pk_constraint('release_version_id') ; 21 | select bitemporal_internal.unique_constraint('release_version') ; 22 | 23 | CREATE TABLE database_versions ( 24 | release_version_id integer -- | not null default nextval('database_versions_id_seq'::regclass) 25 | , release_version numeric(3,1) -- temporal unique 26 | , effective temporal_relationships.timeperiod 27 | , asserted temporal_relationships.timeperiod 28 | , row_created_at timestamptz NOT NULL DEFAULT now() 29 | , CONSTRAINT "bitemporal ok release_version_id unique idx" EXCLUDE 30 | USING gist (release_version_id WITH =, asserted WITH &&, effective WITH &&) 31 | , CONSTRAINT "bitemporal pk release_version_id" 32 | check(true or 'pk' <> '@release_version_id@') 33 | , CONSTRAINT "bitemporal unique release_version" EXCLUDE USING gist 34 | (release_version WITH =, asserted WITH &&, effective WITH &&) 35 | ); 36 | 37 | select bitemporal_internal.pk_constraint('postgres_cluster_id'); 38 | select bitemporal_internal.unique_constraint('port'); 39 | select bitemporal_internal.fk_constraint( 40 | 'postgres_version', 'database_versions', 'release_version'); 41 | 42 | CREATE TABLE postgres_clusters ( 43 | postgres_cluster_id integer NOT NULL -- bitemporal PK 44 | , port int -- bitemporal unique 45 | , name varchar(16) 46 | , postgres_version int -- bitemporal fk 47 | , archive boolean DEFAULT false NOT NULL 48 | , preferred_auth_method text references postgres_auth_methods ( auth_method ) 49 | , effective temporal_relationships.timeperiod 50 | , asserted temporal_relationships.timeperiod 51 | , row_created_at temporal_relationships.time_endpoint NOT NULL DEFAULT now() 52 | , CONSTRAINT "bitemporal pk postgres_cluster_id unique idx" EXCLUDE 53 | USING gist (postgres_cluster_id WITH =, asserted WITH &&, effective WITH &&) 54 | , CONSTRAINT "bitemporal pk postgres_cluster_id" check(true or 'pk' <> '@postgres_cluster_id@') 55 | , CONSTRAINT "bitemporal unique port" EXCLUDE USING gist 56 | (port WITH =, asserted WITH &&, effective WITH &&) 57 | , CONSTRAINT "bitemporal fk postgres_versiondatabase_versionsrelease_version" 58 | check (true or 'fk' <> '@postgres_version -> database_versions(release_version)@') 59 | ); 60 | $$); 61 | 62 | select results_eq($q$ 63 | /* relname,conname,contype,consrc */ 64 | select relname::name, conname::name, contype::char,pg_get_constraintdef(pg_constraint.oid) 65 | from pg_constraint join pg_class on pg_class.oid = conrelid 66 | where 67 | conname like 'bitemporal%' 68 | and relname in ( 'postgres_clusters' , 'database_versions' ) 69 | order by 1,2 70 | $q$,$v$ 71 | VALUES 72 | ('database_versions'::name,'bitemporal ok release_version_id unique idx'::name 73 | ,'x'::char,'EXCLUDE USING gist (release_version_id WITH =, asserted WITH &&, effective WITH &&)') 74 | ,('database_versions'::name,'bitemporal pk release_version_id'::name 75 | ,'c'::char 76 | ,$src$CHECK ((true OR ('pk'::text <> '@release_version_id@'::text)))$src$) 77 | ,('database_versions'::name,'bitemporal unique release_version'::name 78 | ,'x'::char,'EXCLUDE USING gist (release_version WITH =, asserted WITH &&, effective WITH &&)') 79 | ,('postgres_clusters'::name 80 | ,'bitemporal fk postgres_versiondatabase_versionsrelease_version'::name 81 | ,'c'::char 82 | ,$$CHECK ((true OR ('fk'::text <> '@postgres_version -> database_versions(release_version)@'::text)))$$) 83 | ,('postgres_clusters'::name 84 | ,'bitemporal pk postgres_cluster_id'::name,'c'::char 85 | ,$$CHECK ((true OR ('pk'::text <> '@postgres_cluster_id@'::text)))$$) 86 | ,('postgres_clusters'::name 87 | ,'bitemporal pk postgres_cluster_id unique idx'::name 88 | ,'x'::char,$$EXCLUDE USING gist (postgres_cluster_id WITH =, asserted WITH &&, effective WITH &&)$$) 89 | ,('postgres_clusters'::name,'bitemporal unique port'::name 90 | ,'x'::char,$$EXCLUDE USING gist (port WITH =, asserted WITH &&, effective WITH &&)$$) 91 | $v$); 92 | 93 | /* 94 | relname | conname | contype | consrc 95 | -------------------+----------------------------------------------------------------+---------+-------------------------------------------------------------------------------------------- 96 | database_versions | bitemporal ok release_version_id unique idx | x | 97 | database_versions | bitemporal pk release_version_id | c | (true OR ('pk'::text <> '@release_version_id@'::text)) 98 | database_versions | bitemporal unique release_version | x | 99 | postgres_clusters | bitemporal fk postgres_versiondatabase_versionsrelease_version | c | (true OR ('fk'::text <> '@postgres_version -> database_versions(release_version)@'::text)) 100 | postgres_clusters | bitemporal pk postgres_cluster_id | c | (true OR ('pk'::text <> '@postgres_cluster_id@'::text)) 101 | postgres_clusters | bitemporal pk postgres_cluster_id unique idx | x | 102 | postgres_clusters | bitemporal unique port | x | 103 | (7 rows) 104 | */ 105 | 106 | 107 | 108 | 109 | SELECT * FROM finish(); 110 | ROLLBACK; 111 | 112 | -- vim: set filetype=pgsql expandtab tabstop=2 shiftwidth=2: 113 | -------------------------------------------------------------------------------- /tests/20_ll_update.sql: -------------------------------------------------------------------------------- 1 | 2 | BEGIN; 3 | set client_min_messages to warning; 4 | set local search_path = 'bi_temp_tables','bitemporal_internal','public'; 5 | set local TimeZone = 'UTC'; 6 | 7 | SELECT plan(27); 8 | 9 | select unialike( current_setting('search_path'), '%temporal_relationships%' 10 | ,'temporal_relationships should NOT be on search_path for these tests' ); 11 | 12 | 13 | 14 | select lives_ok($$ 15 | create schema bi_temp_tables 16 | $$, 'create schema'); 17 | 18 | select lives_ok($$ 19 | create table bi_temp_tables.devices_manual ( 20 | device_id_key serial NOT NULL 21 | , device_id integer NOT NULL 22 | , effective tstzrange 23 | , asserted tstzrange 24 | , device_descr text 25 | , row_created_at timestamptz NOT NULL DEFAULT now() 26 | , CONSTRAINT devices_device_id_asserted_effective_excl EXCLUDE 27 | USING gist (device_id WITH =, asserted WITH &&, effective WITH &&) 28 | ) 29 | $$, 'create devices manual'); 30 | 31 | select lives_ok($$select * from bitemporal_internal.ll_create_bitemporal_table('bi_temp_tables','devices', 32 | 'device_id integer, device_descr text', 'device_id') 33 | $$, 'create devices'); 34 | 35 | select lives_ok($$ 36 | insert into bi_temp_tables.devices( device_id , effective, asserted, device_descr ) 37 | values 38 | (1, '[01-01-2015, infinity)', '[01-01-2015, infinity)','descr2') 39 | ,(5, '[2015-12-01 00:00:00-06,2015-12-31 00:00:00+00)', '[2015-12-01 00:00:00-06,2015-12-31 00:00:00+00)', 'test_5') 40 | $$, 'insert data into devices'); 41 | 42 | ---non-temp for test 43 | 44 | select lives_ok($$ 45 | create table bi_temp_tables.devices_non_temp( 46 | device_id_key serial, 47 | device_id int4 48 | ); 49 | create table bi_temp_tables.devices_temp( 50 | device_id_key serial, 51 | device_id int4, 52 | effective tsrange, 53 | EXCLUDE USING gist (device_id WITH =, effective WITH &&) 54 | ) 55 | $$, 'double create'); 56 | 57 | select is( ll_is_bitemporal_table('bi_temp_tables.devices_temp'), false 58 | , 'is bitemporal table? devices_temp'); 59 | 60 | select is( ll_is_bitemporal_table('bi_temp_tables.devices') 61 | , true , 'is bitemporal table? devices'); 62 | 63 | select is( ll_is_bitemporal_table('bi_temp_tables.devices_manual') 64 | , true , 'is bitemporal table? devices_manual'); 65 | 66 | select is( ll_is_bitemporal_table('bi_temp_tables.devices_non_temp') 67 | , false , 'is bitemporal table? devices_non_temp'); 68 | 69 | select is( ll_is_bitemporal_table('bi_temp_tables.dev') 70 | , false , 'is bitemporal table? dev'); 71 | 72 | ----test insert: 73 | select results_eq ($q$ 74 | select bitemporal_internal.ll_bitemporal_insert('bi_temp_tables.devices', 75 | 'device_id , device_descr', $$'11', 'new_descr'$$, '[01-01-2016, infinity)', '[01-02-2016, infinity)' ) 76 | $q$, 77 | $v$ values(1) $v$ 78 | ,'bitemporal insert' 79 | ); 80 | 81 | -- select * from bi_temp_tables.devices ; 82 | 83 | select results_eq($q$ select device_id, device_descr, effective, asserted 84 | from bi_temp_tables.devices where device_id =11 $q$ 85 | , $v$ 86 | values 87 | ( 11 88 | ,'new_descr'::text 89 | ,'["2016-01-01 00:00:00+00",infinity)'::temporal_relationships.timeperiod 90 | ,'["2016-01-02 00:00:00+00",infinity)'::temporal_relationships.timeperiod 91 | ) 92 | $v$ 93 | ,'bitemporal insert, returns select ' 94 | ); 95 | 96 | ---test correction 97 | 98 | 99 | select results_eq($q$select * from bitemporal_internal.ll_bitemporal_correction('bi_temp_tables','devices', 100 | 'device_descr', 101 | $$'updated_descr_11'$$, 102 | 'device_id' , 103 | '11', 104 | '[01-01-2016, infinity)' ::temporal_relationships.timeperiod)$q$, 105 | $v$ values(1) $v$ 106 | ,'bitemporal correction' 107 | ); 108 | 109 | select results_eq($q$ 110 | select device_descr 111 | from bi_temp_tables.devices where device_id = 11 and upper(asserted)='infinity' and effective='[01-01-2016, infinity)' 112 | $q$ 113 | , $v$ 114 | values 115 | ('updated_descr_11'::text) 116 | $v$ 117 | ,'select after bitemporal correction - old' 118 | ); 119 | 120 | select results_eq($q$ 121 | select device_descr 122 | from bi_temp_tables.devices where device_id = 11 and lower(asserted)='2016-01-02' 123 | and effective='[01-01-2016, infinity)' 124 | $q$ 125 | , $v$ 126 | values 127 | ('new_descr'::text) 128 | $v$ 129 | ,'select after bitemporal correction - new' 130 | ); 131 | 132 | 133 | 134 | select results_eq($q$ 135 | select * from 136 | bitemporal_internal.ll_bitemporal_list_of_fields('bi_temp_tables.devices') 137 | $q$ 138 | , $v$ 139 | values 140 | ( 141 | ARRAY['device_id','device_descr'] 142 | ) 143 | $v$ 144 | ,'list of fields' 145 | ); 146 | 147 | 148 | 149 | ---correct test: 150 | 151 | select results_eq($q$ 152 | select * from bitemporal_internal.ll_bitemporal_update('bi_temp_tables','devices' 153 | ,'device_descr' 154 | ,$$'descr starting from jan 1'$$ 155 | ,'device_id' 156 | ,$$1$$ 157 | ,'[2018-01-01, infinity)' 158 | , '[3016-01-01, infinity)') $q$, 159 | $v$ values(1) $v$ 160 | ,'bitemporal update - correct' 161 | ); 162 | 163 | 164 | 165 | select results_eq ($q$ 166 | select bitemporal_internal.ll_bitemporal_insert('bi_temp_tables.devices', 167 | 'device_id , device_descr', $$'10', 'descr_crean_insert'$$, '[01-01-2017, infinity)', '[3017-07-09 21:59:58.993815-05, infinity)' ) 168 | $q$, 169 | $v$ values(1) $v$ 170 | ,'bitemporal insert for correction' 171 | ); 172 | 173 | select results_eq($q$select * from bitemporal_internal.ll_bitemporal_correction('bi_temp_tables','devices', 174 | 'device_descr', 175 | $$'descr_10_corr_on_place'$$, 176 | 'device_id' , 177 | '10', 178 | '[01-01-2017, infinity)'::temporal_relationships.timeperiod , '3017-07-09 21:59:58.993815-05' 179 | )$q$, 180 | $v$ values(1) $v$ 181 | ,'bitemporal correction on place' 182 | ); 183 | 184 | select results_eq($q$ 185 | select device_descr 186 | from bi_temp_tables.devices where device_id = 10 187 | and effective='[01-01-2017, infinity)' 188 | $q$ 189 | , $v$ 190 | values 191 | ('descr_10_corr_on_place'::text) 192 | $v$ 193 | ,'select after bitemporal correction on place' 194 | ); 195 | 196 | 197 | select results_eq($q$select * from bitemporal_internal.ll_bitemporal_correction('bi_temp_tables','devices', 198 | 'device_descr', 199 | $$'descr_10_corr_with_new-record'$$, 200 | 'device_id' , 201 | '10', 202 | '[01-01-2017, infinity)' ::temporal_relationships.timeperiod, '3017-07-09 22:10:58.993815-05' 203 | )$q$, 204 | $v$ values(1) $v$ 205 | ,'bitemporal correction new record' 206 | ); 207 | 208 | select results_eq($q$ 209 | select device_descr 210 | from bi_temp_tables.devices where device_id = 10 211 | and effective='[01-01-2017, infinity)' and upper(asserted)='infinity' 212 | $q$ 213 | , $v$ 214 | values 215 | ('descr_10_corr_with_new-record'::text) 216 | $v$ 217 | ,'select after bitemporal correction new record' 218 | ); 219 | ---test update with error: 220 | /* 221 | 222 | select * from bitemporal_internal.ll_bitemporal_update('bi_temp_tables.devices' 223 | ,'device_descr' 224 | ,$$'descr starting from jan 1'$$ 225 | ,'device_id' 226 | ,$$8$$ 227 | ,'[2016-01-01, infinity)' 228 | , '[2016-01-02, infinity)') 229 | ; 230 | 231 | ---output: 232 | 233 | ERROR: Asserted interval starts in the past or has a finite end: ["2016-01-02 00:00:00-06",infinity) 234 | 235 | Exactly the same test should be performed for inactivate 236 | */ 237 | 238 | /* should probably include the test of bitemporal_internal.ll_check_bitemporal_update_conditions - if it returns zero, 239 | then 240 | 241 | ERROR: Nothing to update, use INSERT or check effective: ["2015-01-02 00:00:00-06","2015-02-02") 242 | 243 | Exactly the same test should be performed for inactivate 244 | 245 | 246 | */ 247 | 248 | 249 | select results_eq($q$select * from bitemporal_internal.ll_bitemporal_inactivate('bi_temp_tables','devices' 250 | ,'device_id' 251 | ,$$11$$ 252 | ,'[3016-02-02, infinity)' 253 | , '[3016-03-01, infinity)') $q$, 254 | $v$ values(1) $v$ 255 | ,'bitemporal inactivate - correct' 256 | ); 257 | 258 | 259 | select results_eq($q$select count(*)::integer from bi_temp_tables.devices 260 | where device_id=11 261 | and '[3016-03-16, 3016-03-16]'<@ asserted 262 | and '[3016-02-04, 3016-02-04]' <@ effective $q$, 263 | $v$ values(0::integer) $v$,'bitemporal inactivate no active rows'); 264 | 265 | 266 | ---delete: 267 | 268 | select results_eq($q$select * from bitemporal_internal.ll_bitemporal_delete('bi_temp_tables.devices' 269 | ,'device_id' 270 | ,$$1$$ 271 | , '[3016-04-04 21:30, infinity)') $q$, 272 | $v$ values(2) $v$ 273 | ,'bitemporal delete'); 274 | 275 | select results_eq($q$select count(*)::integer from bi_temp_tables.devices 276 | where device_id=1 277 | and '[3016-04-05, 3016-04-05]' <@ asserted $q$, 278 | $v$ values(0::integer) $v$ 279 | ,'bitemporal delete no active rows'); 280 | 281 | SELECT * FROM finish(); 282 | ROLLBACK; 283 | -- vim: set filetype=pgsql expandtab tabstop=2 shiftwidth=2: 284 | -------------------------------------------------------------------------------- /tutorial/bitemp_tutorial.sql: -------------------------------------------------------------------------------- 1 | SELECT * FROM bitemporal_internal.ll_create_bitemporal_table( 2 | 'bt_tutorial', 3 | 'staff_bt', 4 | $$staff_id int, 5 | staff_name text not null, 6 | staff_location text not null 7 | $$, 8 | 'staff_id'); 9 | 10 | SELECT * FROM bitemporal_internal.ll_create_bitemporal_table( 11 | 'bt_tutorial', 12 | 'cust_bt', 13 | $$cust_id int not null, 14 | cust_name text not null, 15 | phone text 16 | $$, 17 | 'cust_id'); 18 | 19 | SELECT * FROM bitemporal_internal.ll_create_bitemporal_table( 20 | 'bt_tutorial', 21 | 'product_bt', 22 | $$product_id int, 23 | product_name text not null, 24 | weight integer not null default(0), 25 | price integer not null default(0) 26 | $$, 27 | 'product_id'); 28 | 29 | SELECT * FROM bitemporal_internal.ll_create_bitemporal_table( 30 | 'bt_tutorial', 31 | 'order_bt', 32 | $$order_id int not null, 33 | staff_id int not null, 34 | cust_id int not null, 35 | order_created_at timestamptz 36 | $$, 37 | 'order_id'); 38 | 39 | SELECT * FROM bitemporal_internal.ll_create_bitemporal_table( 40 | 'bt_tutorial', 41 | 'order_line_bt', 42 | $$order_line_id int not null, 43 | order_id int not null, 44 | product_id int not null, 45 | qty int not null, 46 | order_line_created_at timestamptz 47 | $$, 48 | 'order_id,order_line_id'); 49 | 50 | 51 | 52 | DROP SEQUENCE if exists bt_tutorial.staff_id_seq; 53 | CREATE SEQUENCE bt_tutorial.staff_id_seq; 54 | DROP SEQUENCE if exists bt_tutorial.cust_id_seq; 55 | CREATE SEQUENCE bt_tutorial.cust_id_seq; 56 | DROP SEQUENCE if exists bt_tutorial.product_id_seq; 57 | CREATE SEQUENCE bt_tutorial.product_id_seq; 58 | DROP SEQUENCE if exists bt_tutorial.order_id_seq; 59 | CREATE SEQUENCE bt_tutorial.order_id_seq; 60 | DROP SEQUENCE if exists bt_tutorial.order_line_id_seq; 61 | CREATE SEQUENCE bt_tutorial.order_line_id_seq; 62 | 63 | 64 | SELECT * FROM bitemporal_internal.ll_bitemporal_insert('bt_tutorial.staff_bt' 65 | ,$$staff_id, staff_name, staff_location$$ 66 | ,quote_literal(nextval('bt_tutorial.staff_id_seq'))||$$, 67 | 'mystaff', 'mylocation'$$ 68 | ,temporal_relationships.timeperiod(now(), 'infinity') --effective 69 | ,temporal_relationships.timeperiod(now(), 'infinity') --asserted 70 | ); 71 | 72 | SELECT * FROM bt_tutorial.staff; 73 | 74 | SELECT * FROM bitemporal_internal.ll_bitemporal_insert('bt_tutorial.cust_bt' 75 | ,$$cust_id, cust_name, phone$$ 76 | ,quote_literal(nextval('bt_tutorial.cust_id_seq'))||$$, 77 | 'mycust', '+6281197889890'$$ 78 | ,temporal_relationships.timeperiod(now(), 'infinity') --effective 79 | ,temporal_relationships.timeperiod(now(), 'infinity') --asserted 80 | ); 81 | 82 | SELECT * FROM bitemporal_internal.ll_bitemporal_insert('bt_tutorial.product_bt' 83 | ,$$product_id, product_name,weight,price$$ 84 | ,quote_literal(nextval('bt_tutorial.product_id_seq'))||$$, 85 | 'myproduct', 100,200$$ 86 | ,temporal_relationships.timeperiod(now(), 'infinity') --effective 87 | ,temporal_relationships.timeperiod(now(), 'infinity') --asserted 88 | ); 89 | 90 | SELECT * FROM bitemporal_internal.ll_bitemporal_insert('bt_tutorial.product_bt' 91 | ,$$product_id, product_name,weight,price$$ 92 | ,quote_literal(nextval('bt_tutorial.product_id_seq'))||$$, 93 | 'myproduct2', 200,250$$ 94 | ,temporal_relationships.timeperiod(now(), 'infinity') --effective 95 | ,temporal_relationships.timeperiod(now(), 'infinity') --asserted 96 | ); 97 | 98 | SELECT * FROM bitemporal_internal.ll_bitemporal_insert('bt_tutorial.order_bt' 99 | ,$$order_id, staff_id,cust_id,order_created_at$$ 100 | ,quote_literal(nextval('bt_tutorial.order_id_seq'))||$$, 101 | 1,1,$$||quote_literal(now()) 102 | ,temporal_relationships.timeperiod(now(), 'infinity') --effective 103 | ,temporal_relationships.timeperiod(now(), 'infinity') --asserted 104 | ); 105 | 106 | SELECT * FROM bitemporal_internal.ll_bitemporal_insert('bt_tutorial.order_line_bt' 107 | ,$$order_line_id,order_id, product_id,qty, order_line_created_at$$ 108 | ,quote_literal(nextval('bt_tutorial.order_line_id_seq'))||$$, 109 | 1,1,10$$||quote_literal(now()) 110 | ,temporal_relationships.timeperiod(now(), 'infinity') --effective 111 | ,temporal_relationships.timeperiod(now(), 'infinity') --asserted 112 | ); 113 | 114 | SELECT * FROM bitemporal_internal.ll_bitemporal_insert('bt_tutorial.order_line_bt' 115 | ,$$order_line_id,order_id, product_id,qty, order_line_created_at$$ 116 | ,quote_literal(nextval('bt_tutorial.order_line_id_seq'))||$$, 117 | 1,2,15$$||quote_literal(now()) 118 | ,temporal_relationships.timeperiod(now(), 'infinity') --effective 119 | ,temporal_relationships.timeperiod(now(), 'infinity') --asserted 120 | ); 121 | 122 | SELECT * FROM bitemporal_internal.ll_bitemporal_update('bt_tutorial' 123 | ,'staff_bt' 124 | ,'staff_location'-- fields to update' 125 | ,$$'newlocation'$$ -- values to update with 126 | ,'staff_id' -- search fields 127 | ,'1' -- search values 128 | ,temporal_relationships.timeperiod(now(), 'infinity') 129 | ,temporal_relationships.timeperiod(now(), 'infinity') 130 | ) ; 131 | 132 | SELECT 133 | o.order_id, 134 | staff_name, 135 | staff_location, 136 | c.cust_name, 137 | c.phone AS cust_phone, 138 | p.product_name, 139 | p.price, 140 | l.qty 141 | FROM bt_tutorial.order_line_bt l 142 | JOIN bt_tutorial.order_bt o ON o.order_id = l.order_id 143 | JOIN bt_tutorial.product_bt p ON p.product_id = l.product_id 144 | JOIN bt_tutorial.staff_bt s ON s.staff_id = o.staff_id 145 | JOIN bt_tutorial.cust_bt c ON c.cust_id = o.cust_id 146 | WHERE l.order_id=1 147 | AND order_line_created_at<@l.effective AND now()<@l.asserted 148 | AND order_created_at<@o.effective AND now()<@o.asserted 149 | AND order_created_at<@c.effective AND now()<@c.asserted 150 | AND order_created_at<@p.effective AND now()<@p.asserted 151 | AND order_created_at<@s.effective AND now()<@s.asserted; 152 | 153 | 154 | SELECT * FROM bitemporal_internal.ll_bitemporal_correction( 155 | 'bt_tutorial', 156 | 'product_bt', 157 | 'price', 158 | '275', 159 | 'product_id', 160 | '2', 161 | temporal_relationships.timeperiod ('2020-10-11 18:33:26.816311-05'::timestamptz,'infinity'), 162 | now() ); 163 | 164 | ---corrected price 165 | SELECT 166 | o.order_id, 167 | staff_name, 168 | staff_location, 169 | c.cust_name, 170 | c.phone AS cust_phone, 171 | p.product_name, 172 | p.price, 173 | l.qty 174 | FROM bt_tutorialo.rder_line_bt l 175 | JOIN bt_tutorial.order_bt o ON o.order_id = l.order_id 176 | JOIN bt_tutorial.product_bt p ON p.product_id = l.product_id 177 | JOIN bt_tutorial.staff_bt s ON s.staff_id = o.staff_id 178 | JOIN bt_tutorial.cust_bt c ON c.cust_id = o.cust_id 179 | WHERE l.order_id=1 180 | AND order_line_created_at<@l.effective AND now()<@l.asserted 181 | AND order_created_at<@o.effective AND now()<@o.asserted 182 | AND order_created_at<@c.effective AND now()<@c.asserted 183 | AND order_created_at<@p.effective AND now()<@p.asserted 184 | and order_created_at<@s.effective AND now()<@s.asserted; 185 | 186 | --original price 187 | 188 | SELECT 189 | o.order_id, 190 | staff_name, 191 | staff_location, 192 | c.cust_name, 193 | c.phone AS cust_phone, 194 | p.product_name, 195 | p.price, 196 | l.qty 197 | FROM bt_tutorial.order_line_bt l 198 | JOIN bt_tutorial.order_bt o ON o.order_id = l.order_id 199 | JOIN bt_tutorial.product_bt p ON p.product_id = l.product_id 200 | JOIN bt_tutorial.staff_bt s ON s.staff_id = o.staff_id 201 | JOIN bt_tutorial.cust_bt c ON c.cust_id = o.cust_id 202 | WHERE l.order_id=1 203 | AND order_line_created_at<@l.effective AND order_line_created_at<@l.asserted 204 | AND order_created_at<@o.effective AND order_created_at<@o.asserted 205 | AND order_created_at<@c.effective AND order_created_at<@c.asserted 206 | AND order_created_at<@p.effective AND order_created_at<@p.asserted 207 | AND order_created_at<@s.effective AND order_created_at<@s.asserted; -------------------------------------------------------------------------------- /tutorial/bt_tutorial.pptx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/bt_tutorial.pptx -------------------------------------------------------------------------------- /tutorial/ex_2.sql: -------------------------------------------------------------------------------- 1 | SELECT * FROM bitemporal_internal.ll_create_bitemporal_table( 2 | 'bt_tutorial', 3 | 'staff_bt', 4 | $$staff_id int, 5 | staff_name TEXT NOT NULL, 6 | staff_location TEXT NOT NULL 7 | $$, 8 | 'staff_id'); 9 | 10 | SELECT * FROM bitemporal_internal.ll_create_bitemporal_table( 11 | 'bt_tutorial', 12 | 'cust_bt', 13 | $$cust_id int NOT NULL, 14 | cust_name TEXT NOT NULL, 15 | phone TEXT 16 | $$, 17 | 'cust_id'); 18 | 19 | SELECT * FROM bitemporal_internal.ll_create_bitemporal_table( 20 | 'bt_tutorial', 21 | 'product_bt', 22 | $$product_id INT, 23 | product_name text NOT NULL, 24 | weight INTEGER NOT NULL DEFAULT(0), 25 | price INTEGER NOT NULL DEFAULT(0) 26 | $$, 27 | 'product_id'); 28 | 29 | SELECT * FROM bitemporal_internal.ll_create_bitemporal_table( 30 | 'bt_tutorial', 31 | 'order_bt', 32 | $$order_id INT NOT NULL, 33 | staff_id INT NOT NULL, 34 | cust_id INT NOT NULL, 35 | order_created_at timestamptz 36 | $$, 37 | 'order_id'); 38 | 39 | SELECT * FROM bitemporal_internal.ll_create_bitemporal_table( 40 | 'bt_tutorial', 41 | 'order_line_bt', 42 | $$order_line_id INT NOT NULL, 43 | order_id INT NOT NULL, 44 | product_id INT NOT NULL, 45 | qty int NOT NULL, 46 | order_line_created_at timestamptz 47 | $$, 48 | 'order_id,order_line_id'); 49 | 50 | 51 | 52 | DROP SEQUENCE IF EXISTS bt_tutorial.staff_id_seq; 53 | CREATE SEQUENCE bt_tutorial.staff_id_seq; 54 | DROP SEQUENCE IF EXISTS bt_tutorial.cust_id_seq; 55 | CREATE SEQUENCE bt_tutorial.cust_id_seq; 56 | DROP SEQUENCE IF EXISTS bt_tutorial.product_id_seq; 57 | CREATE SEQUENCE bt_tutorial.product_id_seq; 58 | DROP SEQUENCE IF EXISTS bt_tutorial.order_id_seq; 59 | CREATE SEQUENCE bt_tutorial.order_id_seq; 60 | DROP SEQUENCE IF EXISTS bt_tutorial.order_line_id_seq; 61 | CREATE SEQUENCE bt_tutorial.order_line_id_seq; 62 | 63 | 64 | select * from bitemporal_internal.ll_bitemporal_insert('bt_tutorial.staff_bt' 65 | ,$$staff_id, staff_name, staff_location$$ 66 | ,quote_literal(nextval('staff_id_seq'))||$$, 67 | 'mystaff', 'mylocation'$$ 68 | ,temporal_relationships.timeperiod(now(), 'infinity') --effective 69 | ,temporal_relationships.timeperiod(now(), 'infinity') --asserted 70 | ); 71 | 72 | select * from bitemporal_internal.ll_bitemporal_insert('bt_tutorial.cust_bt' 73 | ,$$cust_id, cust_name, phone$$ 74 | ,quote_literal(nextval('cust_id_seq'))||$$, 75 | 'mycust', '+6281197889890'$$ 76 | ,temporal_relationships.timeperiod(now(), 'infinity') --effective 77 | ,temporal_relationships.timeperiod(now(), 'infinity') --asserted 78 | ); 79 | 80 | select * from bitemporal_internal.ll_bitemporal_insert('bt_tutorial.product_bt' 81 | ,$$product_id, product_name,weight,price$$ 82 | ,quote_literal(nextval('product_id_seq'))||$$, 83 | 'myproduct', 100,200$$ 84 | ,temporal_relationships.timeperiod(now(), 'infinity') --effective 85 | ,temporal_relationships.timeperiod(now(), 'infinity') --asserted 86 | ); 87 | 88 | select * from bitemporal_internal.ll_bitemporal_insert('bt_tutorial.product_bt' 89 | ,$$product_id, product_name,weight,price$$ 90 | ,quote_literal(nextval('product_id_seq'))||$$, 91 | 'myproduct2', 200,250$$ 92 | ,temporal_relationships.timeperiod(now(), 'infinity') --effective 93 | ,temporal_relationships.timeperiod(now(), 'infinity') --asserted 94 | ); 95 | 96 | select * from bitemporal_internal.ll_bitemporal_insert('bt_tutorial.order_bt' 97 | ,$$order_id, staff_id,cust_id,order_created_at$$ 98 | ,quote_literal(nextval('order_id_seq'))||$$, 99 | 1,1,$$||quote_literal(now()) 100 | ,temporal_relationships.timeperiod(now(), 'infinity') --effective 101 | ,temporal_relationships.timeperiod(now(), 'infinity') --asserted 102 | ); 103 | 104 | select * from bitemporal_internal.ll_bitemporal_insert('bt_tutorial.order_line_bt' 105 | ,$$order_line_id,order_id, product_id,qty$$ 106 | ,quote_literal(nextval('order_line_id_seq'))||$$, 107 | 1,1,10$$ 108 | ,temporal_relationships.timeperiod(now(), 'infinity') --effective 109 | ,temporal_relationships.timeperiod(now(), 'infinity') --asserted 110 | ); 111 | 112 | select * from bitemporal_internal.ll_bitemporal_insert('bt_tutorial.order_line_bt' 113 | ,$$order_line_id,order_id, product_id,qty$$ 114 | ,quote_literal(nextval('order_line_id_seq'))||$$, 115 | 1,2,15$$ 116 | ,temporal_relationships.timeperiod(now(), 'infinity') --effective 117 | ,temporal_relationships.timeperiod(now(), 'infinity') --asserted 118 | ); 119 | 120 | SELECT * FROM bitemporal_internal.ll_bitemporal_update('bt_tutorial' 121 | ,'staff_bt' 122 | ,'staff_location'-- fields to update' 123 | ,$$'newlocation'$$ -- values to update with 124 | ,'staff_id' -- search fields 125 | ,'1' -- search values 126 | ,temporal_relationships.timeperiod(now(), 'infinity') 127 | ,temporal_relationships.timeperiod(now(), 'infinity') 128 | ) ; 129 | 130 | select 131 | o.order_id, 132 | staff_name, 133 | staff_location, 134 | c.cust_name, 135 | c.phone AS cust_phone, 136 | p.product_name, 137 | p.price, 138 | l.qty 139 | FROM order_line_bt l 140 | JOIN order_bt o ON o.order_id = l.order_id 141 | JOIN product_bt p ON p.product_id = l.product_id 142 | JOIN staff_bt s ON s.staff_id = o.staff_id 143 | JOIN cust_bt c ON c.cust_id = o.cust_id 144 | WHERE l.order_id=1 145 | AND order_line_created_at<@l.effective AND now()<@l.asserted 146 | AND order_created_at<@o.effective AND now()<@o.asserted 147 | AND order_created_at<@c.effective AND now()<@c.asserted 148 | AND order_created_at<@p.effective AND now()<@p.asserted 149 | AND order_created_at<@s.effective AND now()<@s.asserted; 150 | 151 | 152 | SELECT * FROM bitemporal_internal.ll_bitemporal_correction( 153 | 'bt_tutorial', 154 | 'product_bt', 155 | 'price', 156 | '275', 157 | 'product_id', 158 | '2', 159 | temporal_relationships.timeperiod ('2020-10-11 18:33:26.816311-05'::timestamptz,'infinity'), 160 | now() ); 161 | 162 | ---corrected price 163 | select 164 | o.order_id, 165 | staff_name, 166 | staff_location, 167 | c.cust_name, 168 | c.phone AS cust_phone, 169 | p.product_name, 170 | p.price, 171 | l.qty 172 | FROM order_line_bt l 173 | JOIN order_bt o ON o.order_id = l.order_id 174 | JOIN product_bt p ON p.product_id = l.product_id 175 | JOIN staff_bt s ON s.staff_id = o.staff_id 176 | JOIN cust_bt c ON c.cust_id = o.cust_id 177 | WHERE l.order_id=1 178 | AND order_line_created_at<@l.effective AND now()<@l.asserted 179 | AND order_created_at<@o.effective AND now()<@o.asserted 180 | AND order_created_at<@c.effective AND now()<@c.asserted 181 | AND order_created_at<@p.effective AND now()<@p.asserted 182 | AND order_created_at<@s.effective AND now()<@s.asserted; 183 | 184 | --original price 185 | 186 | select 187 | o.order_id, 188 | staff_name, 189 | staff_location, 190 | c.cust_name, 191 | c.phone AS cust_phone, 192 | p.product_name, 193 | p.price, 194 | l.qty 195 | FROM order_line_bt l 196 | JOIN order_bt o ON o.order_id = l.order_id 197 | JOIN product_bt p ON p.product_id = l.product_id 198 | JOIN staff_bt s ON s.staff_id = o.staff_id 199 | JOIN cust_bt c ON c.cust_id = o.cust_id 200 | WHERE l.order_id=1 201 | AND order_line_created_at<@l.effective AND order_line_created_at<@l.asserted 202 | AND order_created_at<@o.effective AND order_created_at<@o.asserted 203 | AND order_created_at<@c.effective AND order_created_at<@c.asserted 204 | AND order_created_at<@p.effective AND order_created_at<@p.asserted 205 | AND order_created_at<@s.effective AND order_created_at<@s.asserted; -------------------------------------------------------------------------------- /tutorial/first_example_select.sql: -------------------------------------------------------------------------------- 1 | 2 | SELECT 3 | o.order_id, 4 | s.name AS staff_name, 5 | s.location AS staff_loc, 6 | c.cust_name, 7 | c.phone AS cust_phone, 8 | p.product_name, 9 | p.price, 10 | l.qty 11 | FROM bt_tutorial.t_order_line l 12 | JOIN bt_tutorial.t_order o ON o.order_id = l.order_id 13 | JOIN bt_tutorial.product p ON p.product_id = l.product_id 14 | JOIN bt_tutorial.staff s ON s.staff_id = o.staff_id 15 | JOIN bt_tutorial.cust c ON c.cust_id = o.cust_id; 16 | 17 | 18 | UPDATE bt_tutorial.staff SET location = 'newlocation' WHERE staff_id = 1; 19 | UPDATE bt_tutorial.cust SET phone = '+6281111111111' WHERE cust_id = 1; 20 | UPDATE bt_tutorial.product SET price = 300 WHERE product_id = 1; 21 | 22 | ---select the same order 23 | 24 | SELECT o.order_id, 25 | s.name AS staff_name, 26 | s.location AS staff_loc, 27 | c.cust_name, 28 | c.phone AS cust_phone, 29 | p.product_name, 30 | p.price, 31 | l.qty 32 | FROM bt_tutorial.t_order_line l 33 | JOIN bt_tutorial.t_order o ON o.order_id = l.order_id 34 | JOIN bt_tutorial.product p ON p.product_id = l.product_id 35 | JOIN bt_tutorial.staff s ON s.staff_id = o.staff_id 36 | JOIN bt_tutorial.cust c ON c.cust_id = o.cust_id; 37 | 38 | ---incorrect result 39 | 40 | 41 | -------------------------------------------------------------------------------- /tutorial/images/12-1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/images/12-1.png -------------------------------------------------------------------------------- /tutorial/images/13-1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/images/13-1.png -------------------------------------------------------------------------------- /tutorial/images/20-1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/images/20-1.png -------------------------------------------------------------------------------- /tutorial/images/24-1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/images/24-1.png -------------------------------------------------------------------------------- /tutorial/images/26-1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/images/26-1.png -------------------------------------------------------------------------------- /tutorial/images/27-1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/images/27-1.png -------------------------------------------------------------------------------- /tutorial/images/30-1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/images/30-1.png -------------------------------------------------------------------------------- /tutorial/images/33-1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/images/33-1.png -------------------------------------------------------------------------------- /tutorial/images/35-1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/images/35-1.png -------------------------------------------------------------------------------- /tutorial/images/36-1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/images/36-1.png -------------------------------------------------------------------------------- /tutorial/images/4-1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/images/4-1.png -------------------------------------------------------------------------------- /tutorial/images/4-2.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/images/4-2.png -------------------------------------------------------------------------------- /tutorial/images/5-1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/images/5-1.png -------------------------------------------------------------------------------- /tutorial/images/5-2.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/images/5-2.png -------------------------------------------------------------------------------- /tutorial/images/6-1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/images/6-1.png -------------------------------------------------------------------------------- /tutorial/images/6-2.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/hettie-d/pg_bitemporal/89ada7372a2a974614e341baba417a66d5156ef9/tutorial/images/6-2.png -------------------------------------------------------------------------------- /tutorial/instructions.md: -------------------------------------------------------------------------------- 1 | # Bitemporal Tutorial 2 | 3 | Authors: Hettie Dombrovskaya & Braviant Holdings 4 | 5 | ## Overview 6 | 7 | Let’s quickly review bitemporal concepts. Terminology: 8 | 9 | - effective time 10 | - asserted time 11 | - the combination of effective and asserted times: time regions 12 | 13 | Why we need two time dimensions? 14 | 15 | ## Bitemporal operations 16 | 17 | Operations: 18 | - create bitemporal table 19 | - bitemporal insert 20 | - bitemporal update 21 | - bitemporal correction 22 | - inactivate 23 | - bitemporal delete 24 | 25 | ## Bitemporal Insert 26 | 27 | now = 2015-05-01 28 | 29 | ```sql 30 | select ll_bitemporal_insert( 31 | 'customers’, 32 | , $$’customer_no’, name', ’type' $$, 33 | , $$'C100','John Doe', 'Silver' $$, 34 | timeperiod('2015-06-01','infinity'), 35 | timeperiod('2015-05-01','infinity') 36 | ``` 37 | 38 | ![Bitemporal Insert - Part A](images/4-1.png) 39 | 40 | ![Bitemporal Insert - Part B](images/4-2.png) 41 | 42 | ## Bitemporal Update 43 | 44 | now = 2015-09-15 45 | 46 | ```sql 47 | select ll_bitemporal_update($$customers$$, 48 | $$customer_no$$, $$100$$, 49 | $$type$$, $$Gold$$, 50 | timeperiod(‘2015-09-15’, ‘infinity’), 51 | timeperiod(‘2015-09-15’, ‘infinity’)) 52 | ``` 53 | ![Bitemporal Update - Part A](images/5-1.png) 54 | 55 | ![Bitemporal Update - Part B](images/5-2.png) 56 | 57 | ## Bitemporal Correction 58 | 59 | now = 2015-09-15 60 | 61 | ```sql 62 | select ll_bitemporal_correction($$customers$$, 63 | $$type $$, 64 | $$ Platinum$$, 65 | $$ customer_no $$, 66 | $$ C100$$, 67 | timeperiod('2015-09-15','infinity'), 68 | now()) 69 | ``` 70 | 71 | ![Bitemporal Correction - Part A](images/6-1.png) 72 | 73 | ![Bitemporal Correction - Part B](images/6-2.png) 74 | 75 | ## Example – Courtesy of albert-kam 76 | 77 | ### Create tables 78 | 79 | ```sql 80 | CREATE TABLE staff 81 | (staff_id int GENERATED BY DEFAULT AS 82 | IDENTITY PRIMARY KEY, 83 | name TEXT NOT NULL, 84 | location TEXT NOT NULL, 85 | created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()); 86 | ``` 87 | 88 | ```sql 89 | CREATE TABLE cust 90 | (cust_id int GENERATED BY DEFAULT AS 91 | IDENTITY PRIMARY KEY, 92 | cust_name TEXT NOT NULL, 93 | phone TEXT, 94 | created_at TIMESTAMPTZ NOT NULL 95 | DEFAULT NOW()); 96 | ``` 97 | 98 | ```sql 99 | CREATE TABLE product 100 | (product_id INT GENERATED BY DEFAULT AS 101 | IDENTITY PRIMARY KEY, 102 | product_name text NOT NULL, 103 | weight INTEGER NOT NULL DEFAULT(0), 104 | price INTEGER NOT NULL DEFAULT(0), 105 | deleted BOOLEAN NOT NULL DEFAULT(FALSE), 106 | created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()); 107 | ``` 108 | 109 | ```sql 110 | CREATE TABLE t_order 111 | (order_id INT GENERATED BY DEFAULT AS IDENTITY 112 | PRIMARY KEY, 113 | staff_id INT NOT NULL REFERENCES staff(staff_id), 114 | cust_id INT NOT NULL REFERENCES cust(cust_id), 115 | created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()); 116 | --- 117 | 118 | CREATE TABLE t_order_line 119 | (order_line_id INT GENERATED BY DEFAULT AS IDENTITY 120 | PRIMARY KEY, 121 | order_id INT REFERENCES t_order(order_id), 122 | product_id INT REFERENCES product(product_id), 123 | qty INTEGER NOT NULL, 124 | created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()); 125 | ``` 126 | 127 | ### Populate tables 128 | 129 | ```sql 130 | INSERT INTO cust (cust_name, phone) VALUES ('mycust’, 131 | '+6281197889890’); 132 | 133 | INSERT INTO staff (name, location) VALUES ('mystaff’, 134 | 'mylocation’); 135 | 136 | INSERT INTO product (product_name, weight, price) VALUES 137 | ('myproduct2', 200, 100); 138 | 139 | INSERT INTO t_order (staff_id, cust_id) VALUES (1, 1); 140 | 141 | INSERT INTO t_order_line (order_id, product_id, qty) 142 | VALUES (1, 1, 10); 143 | ``` 144 | 145 | ### Read data 146 | 147 | ```sql 148 | SELECT o.order_id, 149 | s.name AS staff_name, 150 | s.location AS staff_loc, 151 | c.cust_name, 152 | c.phone AS cust_phone, 153 | p.product_name, 154 | p.price, 155 | l.qty 156 | FROM t_order_line l 157 | JOIN t_order o ON o.order_id = l.order_id 158 | JOIN product p ON p.product_id = l.product_id 159 | JOIN staff s ON s.staff_id = o.staff_id 160 | JOIN cust c ON c.cust_id = o.cust_id; 161 | ``` 162 | 163 | ![Bitemporal Read Data](images/12-1.png) 164 | 165 | ### Performing regular updates – incorrect result 166 | 167 | ```sql 168 | UPDATE staff SET location = 'newlocation' WHERE staff_id = 1; 169 | UPDATE cust SET phone = '+6281111111111' WHERE cust_id = 1; 170 | UPDATE product SET price = 300 WHERE product_id = 1; 171 | ``` 172 | 173 | ![Bitemporal Incorrect Result](images/13-1.png) 174 | 175 | ## Bitemporal Solution 176 | 177 | ### Create bitemporal tables 178 | 179 | ```sql 180 | SELECT * FROM 181 | bitemporal_internal.ll_create_bitemporal_table( 182 | 'bt_tutorial', 183 | 'staff_bt', 184 | $$staff_id int, 185 | staff_name TEXT NOT NULL, 186 | staff_location TEXT NOT NULL 187 | $$, 188 | 'staff_id’); 189 | ``` 190 | returns `true` or `false`, errors are included into messages. 191 | 192 | ### How bitemporal table looks 193 | 194 | ```sql 195 | CREATE TABLE bt_tutorial.staff_bt 196 | ( staff_bt_key integer NOT NULL DEFAULT 197 | nextval('bt_tutorial.staff_bt_staff_bt_key_seq'::regclass), 198 | staff_id integer, 199 | staff_name text NOT NULL, 200 | staff_location text NOT NULL, 201 | effective temporal_relationships.timeperiod, 202 | asserted temporal_relationships.timeperiod, 203 | row_created_at timestamp with time zone NOT NULL DEFAULT now(), 204 | CONSTRAINT staff_bt_pk PRIMARY KEY (staff_bt_key), 205 | CONSTRAINT staff_bt_staff_id_assert_eff_excl EXCLUDE USING gist ( 206 | effective WITH &&, 207 | asserted WITH &&, 208 | staff_id WITH =) 209 | ); 210 | ``` 211 | 212 | ```sql 213 | SELECT * FROM bitemporal_internal.ll_create_bitemporal_table( 214 | 'bt_tutorial', 215 | 'cust_bt', 216 | $$cust_id int NOT NULL, 217 | cust_name TEXT NOT NULL, 218 | phone TEXT$$, 219 | 'cust_id’); 220 | --- 221 | SELECT * FROM bitemporal_internal.ll_create_bitemporal_table( 222 | 'bt_tutorial', 223 | 'product_bt', 224 | $$product_id INT, 225 | product_name text NOT NULL, 226 | weight INTEGER NOT NULL DEFAULT(0), 227 | price INTEGER NOT NULL DEFAULT(0)$$, 228 | 'product_id'); 229 | ``` 230 | 231 | ```sql 232 | SELECT * FROM bitemporal_internal.ll_create_bitemporal_table( 233 | 'bt_tutorial', 234 | 'order_bt', 235 | $$order_id INT NOT NULL, 236 | staff_id INT NOT NULL, 237 | cust_id INT NOT NULL, 238 | order_created_at timestamptz 239 | $$, 240 | 'order_id’); 241 | 242 | SELECT * FROM bitemporal_internal.ll_create_bitemporal_table( 243 | 'bt_tutorial', 244 | 'order_line_bt', 245 | $$order_line_id INT NOT NULL, 246 | order_id INT NOT NULL, 247 | product_id INT NOT NULL, 248 | qty int NOT NULL, 249 | order_line_created_at timestamptz 250 | $$, 251 | ‘order_id,order_line_id'); 252 | ``` 253 | 254 | **Business key is not a primary key!** 255 | 256 | ```sql 257 | drop SEQUENCE if exists bt_tutorial.staff_id_seq; 258 | CREATE SEQUENCE bt_tutorial.staff_id_seq; 259 | 260 | drop SEQUENCE if exists bt_tutorial.cust_id_seq; 261 | CREATE SEQUENCE bt_tutorial.cust_id_seq; 262 | 263 | drop SEQUENCE if exists bt_tutorial.product_id_seq; 264 | CREATE SEQUENCE bt_tutorial.product_id_seq; 265 | 266 | drop SEQUENCE if exists bt_tutorial.order_id_seq; 267 | CREATE SEQUENCE bt_tutorial.order_id_seq; 268 | 269 | drop SEQUENCE if exists bt_tutorial.order_line_id_seq; 270 | CREATE SEQUENCE bt_tutorial.order_line_id_seq; 271 | ``` 272 | 273 | ### Bitemporal inserts 274 | 275 | ```sql 276 | select * from bitemporal_internal.ll_bitemporal_insert( 277 | 'bt_tutorial.staff_bt' 278 | ,$$staff_id, staff_name, staff_location$$ 279 | ,quote_literal(nextval('staff_id_seq'))||$$, 280 | 'mystaff', 'mylocation'$$ 281 | ,temporal_relationships.timeperiod(now(), 'infinity') --effective 282 | ,temporal_relationships.timeperiod(now(), 'infinity') --asserted 283 | ); 284 | ``` 285 | 286 | ![Bitemporal Inserts](images/20-1.png) 287 | 288 | ```sql 289 | select * from bitemporal_internal.ll_bitemporal_insert('bt_tutorial.cust_bt' 290 | ,$$cust_id, cust_name, phone$$ 291 | ,quote_literal(nextval('cust_id_seq'))||$$, 292 | 'mycust', '+6281197889890'$$ 293 | ,temporal_relationships.timeperiod(now(), 'infinity') 294 | ,temporal_relationships.timeperiod(now(), 'infinity') 295 | ); 296 | 297 | select * from bitemporal_internal.ll_bitemporal_insert('bt_tutorial.product_bt' 298 | ,$$product_id, product_name,weight,price$$ 299 | ,quote_literal(nextval('product_id_seq'))||$$, 300 | 'myproduct', 100,200$$ 301 | ,temporal_relationships.timeperiod(now(), 'infinity’), 302 | ,temporal_relationships.timeperiod(now(), 'infinity') 303 | ); 304 | 305 | select * from bitemporal_internal.ll_bitemporal_insert('bt_tutorial.product_bt' 306 | ,$$product_id, product_name,weight,price$$ 307 | ,quote_literal(nextval('product_id_seq'))||$$, 308 | 'myproduct2', 200,250$$ 309 | ,temporal_relationships.timeperiod(now(), 'infinity') --effective 310 | ,temporal_relationships.timeperiod(now(), 'infinity') --asserted 311 | ); 312 | ``` 313 | 314 | ```sql 315 | 316 | ORDER: 317 | 318 | select * from bitemporal_internal.ll_bitemporal_insert('bt_tutorial.order_bt' 319 | ,$$order_id, staff_id,cust_id,order_created_at$$ 320 | ,quote_literal(nextval('order_id_seq'))||$$, 321 | 1,1,$$||quote_literal(now()) 322 | ,temporal_relationships.timeperiod(now(), 'infinity') 323 | ,temporal_relationships.timeperiod(now(), 'infinity’)); 324 | ``` 325 | 326 | ```sql 327 | ORDER LINES 328 | 329 | select * from bitemporal_internal.ll_bitemporal_insert('bt_tutorial.order_line_bt' 330 | ,$$order_line_id,order_id, product_id,qty, order_line_created_at$$ 331 | ,quote_literal(nextval('order_line_id_seq'))||$$, 332 | 1,1,10 ,$$||quote_literal(now()) 333 | ,temporal_relationships.timeperiod(now(), 'infinity') 334 | ,temporal_relationships.timeperiod(now(), 'infinity')); 335 | 336 | select * from bitemporal_internal.ll_bitemporal_insert('bt_tutorial.order_line_bt' 337 | ,$$order_line_id,order_id, product_id,qty$$ 338 | ,quote_literal(nextval('order_line_id_seq'))||$$, 339 | 1,2,15 ,$$||quote_literal(now()) 340 | ,temporal_relationships.timeperiod(now(), 'infinity') 341 | ,temporal_relationships.timeperiod(now(), 'infinity’)); 342 | ``` 343 | 344 | ### order_line_bt table 345 | 346 | ![Order line bt table](images/24-1.png) 347 | 348 | ### Bitemporal SELECT 349 | 350 | ```sql 351 | SELECT o.order_id, 352 | staff_name, 353 | staff_location, 354 | c.cust_name, 355 | c.phone AS cust_phone, 356 | p.product_name, 357 | p.price, 358 | l.qty 359 | FROM order_line_bt l 360 | JOIN order_bt o ON o.order_id = l.order_id 361 | JOIN product_bt p ON p.product_id = l.product_id 362 | JOIN staff_bt s ON s.staff_id = o.staff_id 363 | JOIN cust_bt c ON c.cust_id = o.cust_id 364 | WHERE now()<@l.effective AND now()<@l.asserted 365 | AND now()<@o.effective AND now()<@o.asserted 366 | AND now()<@c.effective AND now()<@c.asserted 367 | AND now()<@p.effective AND now()<@p.asserted 368 | AND now()<@s.effective AND now()<@s.asserted 369 | ``` 370 | 371 | ![Bitemporal select](images/26-1.png) 372 | 373 | ### Bitemportal update 374 | 375 | ```sql 376 | SELECT * FROM bitemporal_internal.ll_bitemporal_update('bt_tutorial' 377 | ,'staff_bt' 378 | ,'staff_location’ -- fields to update 379 | ,$$'newlocation'$$ -- values to update with 380 | ,'staff_id' -- search fields 381 | ,'1' -- search values 382 | ,temporal_relationships.timeperiod(now(),'infinity’) 383 | ,temporal_relationships.timeperiod(now(),'infinity’)); 384 | ``` 385 | 386 | ![Bitemporal update](images/27-1.png) 387 | 388 | ```sql 389 | SELECT * FROM bitemporal_internal.ll_bitemporal_update('bt_tutorial' 390 | ,'product_bt' 391 | ,'price' 392 | ,$$300$$ 393 | ,'product_id' 394 | ,'1’ 395 | ,temporal_relationships.timeperiod(now(), 'infinity') 396 | ,temporal_relationships.timeperiod(now(), 'infinity’)) ; 397 | 398 | SELECT * FROM bitemporal_internal.ll_bitemporal_update('bt_tutorial' 399 | ,'cust_bt' 400 | ,'phone' 401 | ,$$'+628111111111'$$ 402 | ,'cust_id' -- search fields 403 | ,$$1$$ -- search values 404 | ,temporal_relationships.timeperiod(now(), 'infinity') 405 | ,temporal_relationships.timeperiod(now(), 'infinity')) 406 | ``` 407 | 408 | ### SELECT at the time of order 409 | 410 | ```sql 411 | SELECT o.order_id, staff_name, staff_location, c.cust_name, c.phone AS cust_phone, 412 | p.product_name, p.price, l.qty 413 | FROM order_line_bt l 414 | JOIN order_bt o ON o.order_id = l.order_id 415 | JOIN product_bt p ON p.product_id = l.product_id 416 | JOIN staff_bt s ON s.staff_id = o.staff_id 417 | JOIN cust_bt c ON c.cust_id = o.cust_id 418 | WHERE l.order_id=1 419 | AND order_line_created_at<@l.effective AND now()<@l.asserted 420 | AND order_created_at<@o.effective AND now()<@o.asserted 421 | AND order_created_at<@c.effective AND now()<@c.asserted 422 | AND order_created_at<@p.effective AND now()<@p.asserted 423 | AND order_created_at<@s.effective AND now()<@s.asserted 424 | ``` 425 | 426 | ![SELECT at the time of order](images/30-1.png) 427 | 428 | ### Bitemporal correction 429 | 430 | ```sql 431 | SELECT * FROM 432 | bitemporal_internal.ll_bitemporal_correction( 433 | 'bt_tutorial', 434 | 'product_bt', 435 | 'price', 436 | '275', 437 | 'product_id', 438 | '2', 439 | temporal_relationships.timeperiod 440 | ('2020-10-11 18:33:26.816311-05'::timestamptz, 441 | 'infinity'), 442 | now()); 443 | ``` 444 | 445 | ### SELECT at the time of order 446 | 447 | ```sql 448 | SELECT o.order_id, staff_name, staff_location, c.cust_name, c.phone AS cust_phone, 449 | p.product_name, p.price, l.qty 450 | FROM order_line_bt l 451 | JOIN order_bt o ON o.order_id = l.order_id 452 | JOIN product_bt p ON p.product_id = l.product_id 453 | JOIN staff_bt s ON s.staff_id = o.staff_id 454 | JOIN cust_bt c ON c.cust_id = o.cust_id 455 | WHERE l.order_id=1 456 | AND order_line_created_at<@l.effective AND now()<@l.asserted 457 | AND order_created_at<@o.effective AND now()<@o.asserted 458 | AND order_created_at<@c.effective AND now()<@c.asserted 459 | AND order_created_at<@p.effective AND now()<@p.asserted 460 | AND order_created_at<@s.effective AND now()<@s.asserted 461 | ``` 462 | 463 | ### Results are corrected 464 | 465 | ![Results are corrected](images/33-1.png) 466 | 467 | ### SELECT with assertion at the time of order 468 | 469 | ```sql 470 | SELECT o.order_id, staff_name, staff_location, c.cust_name, c.phone AS cust_phone, 471 | p.product_name, p.price, l.qty 472 | FROM order_line_bt l 473 | JOIN order_bt o ON o.order_id = l.order_id 474 | JOIN product_bt p ON p.product_id = l.product_id 475 | JOIN staff_bt s ON s.staff_id = o.staff_id 476 | JOIN cust_bt c ON c.cust_id = o.cust_id 477 | WHERE l.order_id=1 478 | AND order_line_created_at<@l.effective 479 | AND order_line_created_at<@l.asserted 480 | AND order_created_at<@o.effective AND order_created_at<@o.asserted 481 | AND order_created_at<@c.effective AND order_created_at<@c.asserted 482 | AND order_created_at<@p.effective AND order_created_at<@p.asserted 483 | AND order_created_at<@s.effective AND order_created_at<@s.asserted 484 | ``` 485 | 486 | ### Result at the time of order 487 | 488 | ![Result at the time of order](images/35-1.png) 489 | 490 | ### Table product_dt 491 | 492 | ![Table product_dt](images/36-1.png) --------------------------------------------------------------------------------