From aea38d7f5bd3538eac0247721e003dd057d8bd12 Mon Sep 17 00:00:00 2001 From: Jason Lubken Date: Thu, 11 Feb 2021 11:22:25 -0500 Subject: [PATCH] Always patch on startup --- docker-compose.yml | 2 +- postgres/docker-entrypoint.sh | 339 +++++++++++++++++++++ postgres/dockerfile | 6 +- postgres/sql/004.migrate.sql | 329 -------------------- postgres/sql/{ => initdb.d}/003.create.sql | 0 postgres/sql/patchdb.d/004.patch.sql | 95 ++++++ postgres/sql/patchdb.d/005.public.sql | 128 ++++++++ postgres/sql/patchdb.d/006.private.sql | 47 +++ postgres/sql/patchdb.d/007.epic.sql | 53 ++++ 9 files changed, 667 insertions(+), 332 deletions(-) create mode 100755 postgres/docker-entrypoint.sh delete mode 100644 postgres/sql/004.migrate.sql rename postgres/sql/{ => initdb.d}/003.create.sql (100%) create mode 100644 postgres/sql/patchdb.d/004.patch.sql create mode 100644 postgres/sql/patchdb.d/005.public.sql create mode 100644 postgres/sql/patchdb.d/006.private.sql create mode 100644 postgres/sql/patchdb.d/007.epic.sql diff --git a/docker-compose.yml b/docker-compose.yml index c8ab03a..fdc0a6d 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -33,4 +33,4 @@ services: stop_signal: SIGINT volumes: - postgres-data:/var/lib/postgresql/data - - ./secrets:/secrets:ro + - ./postgres/sql/patchdb.d:/docker-entrypoint-patchdb.d diff --git a/postgres/docker-entrypoint.sh b/postgres/docker-entrypoint.sh new file mode 100755 index 0000000..55df74d --- /dev/null +++ b/postgres/docker-entrypoint.sh @@ -0,0 +1,339 @@ +#!/usr/bin/env bash +set -Eeo pipefail +# TODO swap to -Eeuo pipefail above (after handling all potentially-unset variables) + +# usage: file_env VAR [DEFAULT] +# ie: file_env 'XYZ_DB_PASSWORD' 'example' +# (will allow for "$XYZ_DB_PASSWORD_FILE" to fill in the value of +# "$XYZ_DB_PASSWORD" from a file, especially for Docker's secrets feature) +file_env() { + local var="$1" + local fileVar="${var}_FILE" + local def="${2:-}" + if [ "${!var:-}" ] && [ "${!fileVar:-}" ]; then + echo >&2 "error: both $var and $fileVar are set (but are exclusive)" + exit 1 + fi + local val="$def" + if [ "${!var:-}" ]; then + val="${!var}" + elif [ "${!fileVar:-}" ]; then + val="$(< "${!fileVar}")" + fi + export "$var"="$val" + unset "$fileVar" +} + +# check to see if this file is being run or sourced from another script +_is_sourced() { + # https://unix.stackexchange.com/a/215279 + [ "${#FUNCNAME[@]}" -ge 2 ] \ + && [ "${FUNCNAME[0]}" = '_is_sourced' ] \ + && [ "${FUNCNAME[1]}" = 'source' ] +} + +# used to create initial postgres directories and if run as root, ensure ownership to the "postgres" user +docker_create_db_directories() { + local user; user="$(id -u)" + + mkdir -p "$PGDATA" + # ignore failure since there are cases where we can't chmod (and PostgreSQL might fail later anyhow - it's picky about permissions of this directory) + chmod 700 "$PGDATA" || : + + # ignore failure since it will be fine when using the image provided directory; see also https://github.com/docker-library/postgres/pull/289 + mkdir -p /var/run/postgresql || : + chmod 775 /var/run/postgresql || : + + # Create the transaction log directory before initdb is run so the directory is owned by the correct user + if [ -n "$POSTGRES_INITDB_WALDIR" ]; then + mkdir -p "$POSTGRES_INITDB_WALDIR" + if [ "$user" = '0' ]; then + find "$POSTGRES_INITDB_WALDIR" \! -user postgres -exec chown postgres '{}' + + fi + chmod 700 "$POSTGRES_INITDB_WALDIR" + fi + + # allow the container to be started with `--user` + if [ "$user" = '0' ]; then + find "$PGDATA" \! -user postgres -exec chown postgres '{}' + + find /var/run/postgresql \! -user postgres -exec chown postgres '{}' + + fi +} + +# initialize empty PGDATA directory with new database via 'initdb' +# arguments to `initdb` can be passed via POSTGRES_INITDB_ARGS or as arguments to this function +# `initdb` automatically creates the "postgres", "template0", and "template1" dbnames +# this is also where the database user is created, specified by `POSTGRES_USER` env +docker_init_database_dir() { + # "initdb" is particular about the current user existing in "/etc/passwd", so we use "nss_wrapper" to fake that if necessary + # see https://github.com/docker-library/postgres/pull/253, https://github.com/docker-library/postgres/issues/359, https://cwrap.org/nss_wrapper.html + if ! getent passwd "$(id -u)" &> /dev/null && [ -e /usr/lib/libnss_wrapper.so ]; then + export LD_PRELOAD='/usr/lib/libnss_wrapper.so' + export NSS_WRAPPER_PASSWD="$(mktemp)" + export NSS_WRAPPER_GROUP="$(mktemp)" + echo "postgres:x:$(id -u):$(id -g):PostgreSQL:$PGDATA:/bin/false" > "$NSS_WRAPPER_PASSWD" + echo "postgres:x:$(id -g):" > "$NSS_WRAPPER_GROUP" + fi + + if [ -n "$POSTGRES_INITDB_WALDIR" ]; then + set -- --waldir "$POSTGRES_INITDB_WALDIR" "$@" + fi + + eval 'initdb --username="$POSTGRES_USER" --pwfile=<(echo "$POSTGRES_PASSWORD") '"$POSTGRES_INITDB_ARGS"' "$@"' + + # unset/cleanup "nss_wrapper" bits + if [ "${LD_PRELOAD:-}" = '/usr/lib/libnss_wrapper.so' ]; then + rm -f "$NSS_WRAPPER_PASSWD" "$NSS_WRAPPER_GROUP" + unset LD_PRELOAD NSS_WRAPPER_PASSWD NSS_WRAPPER_GROUP + fi +} + +# print large warning if POSTGRES_PASSWORD is long +# error if both POSTGRES_PASSWORD is empty and POSTGRES_HOST_AUTH_METHOD is not 'trust' +# print large warning if POSTGRES_HOST_AUTH_METHOD is set to 'trust' +# assumes database is not set up, ie: [ -z "$DATABASE_ALREADY_EXISTS" ] +docker_verify_minimum_env() { + # check password first so we can output the warning before postgres + # messes it up + if [ "${#POSTGRES_PASSWORD}" -ge 100 ]; then + cat >&2 <<-'EOWARN' + + WARNING: The supplied POSTGRES_PASSWORD is 100+ characters. + + This will not work if used via PGPASSWORD with "psql". + + https://www.postgresql.org/message-id/flat/E1Rqxp2-0004Qt-PL%40wrigleys.postgresql.org (BUG #6412) + https://github.com/docker-library/postgres/issues/507 + + EOWARN + fi + if [ -z "$POSTGRES_PASSWORD" ] && [ 'trust' != "$POSTGRES_HOST_AUTH_METHOD" ]; then + # The - option suppresses leading tabs but *not* spaces. :) + cat >&2 <<-'EOE' + Error: Database is uninitialized and superuser password is not specified. + You must specify POSTGRES_PASSWORD to a non-empty value for the + superuser. For example, "-e POSTGRES_PASSWORD=password" on "docker run". + + You may also use "POSTGRES_HOST_AUTH_METHOD=trust" to allow all + connections without a password. This is *not* recommended. + + See PostgreSQL documentation about "trust": + https://www.postgresql.org/docs/current/auth-trust.html + EOE + exit 1 + fi + if [ 'trust' = "$POSTGRES_HOST_AUTH_METHOD" ]; then + cat >&2 <<-'EOWARN' + ******************************************************************************** + WARNING: POSTGRES_HOST_AUTH_METHOD has been set to "trust". This will allow + anyone with access to the Postgres port to access your database without + a password, even if POSTGRES_PASSWORD is set. See PostgreSQL + documentation about "trust": + https://www.postgresql.org/docs/current/auth-trust.html + In Docker's default configuration, this is effectively any other + container on the same system. + + It is not recommended to use POSTGRES_HOST_AUTH_METHOD=trust. Replace + it with "-e POSTGRES_PASSWORD=password" instead to set a password in + "docker run". + ******************************************************************************** + EOWARN + fi +} + +# usage: docker_process_init_files [file [file [...]]] +# ie: docker_process_init_files /always-initdb.d/* +# process initializer files, based on file extensions and permissions +docker_process_init_files() { + # psql here for backwards compatibility "${psql[@]}" + psql=( docker_process_sql ) + + echo + local f + for f; do + case "$f" in + *.sh) + # https://github.com/docker-library/postgres/issues/450#issuecomment-393167936 + # https://github.com/docker-library/postgres/pull/452 + if [ -x "$f" ]; then + echo "$0: running $f" + "$f" + else + echo "$0: sourcing $f" + . "$f" + fi + ;; + *.sql) echo "$0: running $f"; docker_process_sql -f "$f"; echo ;; + *.sql.gz) echo "$0: running $f"; gunzip -c "$f" | docker_process_sql; echo ;; + *.sql.xz) echo "$0: running $f"; xzcat "$f" | docker_process_sql; echo ;; + *) echo "$0: ignoring $f" ;; + esac + echo + done +} + +# Execute sql script, passed via stdin (or -f flag of pqsl) +# usage: docker_process_sql [psql-cli-args] +# ie: docker_process_sql --dbname=mydb <<<'INSERT ...' +# ie: docker_process_sql -f my-file.sql +# ie: docker_process_sql > "$PGDATA/pg_hba.conf" +} + +# start socket-only postgresql server for setting up or running scripts +# all arguments will be passed along as arguments to `postgres` (via pg_ctl) +docker_temp_server_start() { + if [ "$1" = 'postgres' ]; then + shift + fi + + # internal start of server in order to allow setup using psql client + # does not listen on external TCP/IP and waits until start finishes + set -- "$@" -c listen_addresses='' -p "${PGPORT:-5432}" + + PGUSER="${PGUSER:-$POSTGRES_USER}" \ + pg_ctl -D "$PGDATA" \ + -o "$(printf '%q ' "$@")" \ + -w start +} + +# stop postgresql server after done setting up user and running scripts +docker_temp_server_stop() { + PGUSER="${PGUSER:-postgres}" \ + pg_ctl -D "$PGDATA" -m fast -w stop +} + +# check arguments for an option that would cause postgres to stop +# return true if there is one +_pg_want_help() { + local arg + for arg; do + case "$arg" in + # postgres --help | grep 'then exit' + # leaving out -C on purpose since it always fails and is unhelpful: + # postgres: could not access the server configuration file "/var/lib/postgresql/data/postgresql.conf": No such file or directory + -'?'|--help|--describe-config|-V|--version) + return 0 + ;; + esac + done + return 1 +} + +_main() { + # if first arg looks like a flag, assume we want to run postgres server + if [ "${1:0:1}" = '-' ]; then + set -- postgres "$@" + fi + + if [ "$1" = 'postgres' ] && ! _pg_want_help "$@"; then + docker_setup_env + # setup data directories and permissions (when run as root) + docker_create_db_directories + if [ "$(id -u)" = '0' ]; then + # then restart script as postgres user + exec su-exec postgres "$BASH_SOURCE" "$@" + fi + + docker_verify_minimum_env + # PGPASSWORD is required for psql when authentication is required for 'local' connections via pg_hba.conf and is otherwise harmless + # e.g. when '--auth=md5' or '--auth-local=md5' is used in POSTGRES_INITDB_ARGS + export PGPASSWORD="${PGPASSWORD:-$POSTGRES_PASSWORD}" + + # check dir permissions to reduce likelihood of half-patched database + ls /docker-entrypoint-patchdb.d/ > /dev/null + + # only run initialization on an empty data directory + if [ -z "$DATABASE_ALREADY_EXISTS" ]; then + + # check dir permissions to reduce likelihood of half-initialized database + ls /docker-entrypoint-initdb.d/ > /dev/null + + docker_init_database_dir + pg_setup_hba_conf + + docker_temp_server_start "$@" + + docker_setup_db + docker_process_init_files /docker-entrypoint-initdb.d/* + + echo + echo 'PostgreSQL init process complete.' + echo + else + docker_temp_server_start "$@" + + echo + echo 'PostgreSQL Database directory appears to contain a database; Skipping initialization' + echo + fi + + docker_process_init_files /docker-entrypoint-patchdb.d/* + + docker_temp_server_stop + unset PGPASSWORD + + echo + echo 'PostgreSQL patch process complete; ready for start up.' + echo + fi + + exec "$@" +} + +if ! _is_sourced; then + _main "$@" +fi diff --git a/postgres/dockerfile b/postgres/dockerfile index f0a3ea1..247c05c 100644 --- a/postgres/dockerfile +++ b/postgres/dockerfile @@ -1,3 +1,5 @@ FROM timescale/timescaledb-postgis:latest-pg11 as postgres -ENV IMAGE postgres -COPY ./sql/*.sql /docker-entrypoint-initdb.d/ +LABEL name=postgres +COPY ./docker-entrypoint.sh /usr/local/bin/ +COPY ./sql/initdb.d/*.sql /docker-entrypoint-initdb.d/ +COPY ./sql/patchdb.d/*.sql /docker-entrypoint-patchdb.d/ diff --git a/postgres/sql/004.migrate.sql b/postgres/sql/004.migrate.sql deleted file mode 100644 index ac9da5a..0000000 --- a/postgres/sql/004.migrate.sql +++ /dev/null @@ -1,329 +0,0 @@ -set search_path = dsdk; - - -create or replace function up_patch() -returns void as $$ -begin - create table if not exists patches ( - id varchar primary key, - applied timestamptz not null default now(), - applied_by varchar not null - ); - create table if not exists patch_requires ( - patch_id varchar not null, - require_id varchar not null, - constraint patch_requires_have_natural_keys - unique (patch_id, require_id), - constraint patch_requires_belong_to_patches - foreign key (patch_id) - references patches (id) - on update cascade - on delete cascade, - constraint patch_requires_have_many_patches - foreign key (require_id) - references patches(id) - ); - - begin - create function install(in in_id varchar, in_requires varchar[]) - returns bool - as $function$ - declare - result int; - begin - lock table patches in exclusive mode; - select 1 into result from patches where id = in_id; - if found then - return false; - end if; - raise notice 'Installing patch: %', in_id; - insert into patches - (id, applied_by) - values - (in_id, current_user); - insert into patch_requires - (patch_id, require_id) - select - in_id, unnest(in_requires); - return true; - end; - $function$ language plpgsql; - exception when duplicate_function then - end; - - begin - create function uninstall(in in_id varchar) - returns bool - as $function$ - declare - result int; - begin - lock table patches in exclusive mode; - select 1 into result from patches where id = in_id; - if not found then - return false; - end if; - raise notice 'Uninstalling patch: %', in_id; - delete from patches where id = in_id; - return true; - end; - $function$ language plpgsql; - exception when duplicate_function then - end; - - if not install('patch'::varchar, array[]::varchar[]) then - return; - end if; -end; -$$ language plpgsql; - - -create or replace function down_patch() -returns void as -$$ -begin - if not uninstall('patch'::varchar) then - return; - end if; - - drop table patch_requires; - drop table patches; -end; -$$ language plpgsql; - - -create or replace function up_public() -returns void as $$ -begin - if not install('public'::varchar, array['patch']::varchar[]) then - return; - end if; - - create or replace function is_timezone(time_zone varchar) - returns boolean as $function$ - declare valid timestamptz; - begin - valid := now() at time zone time_zone; - return true; - exception when invalid_parameter_value or others then - return false; - end; - $function$ language plpgsql stable; - - create domain timezone as varchar - check ( is_timezone(value) ); - - create function call_notify() - returns trigger as $function$ - declare last_id text; - begin - select max(id) - into last_id - from inserted; - perform pg_notify(TG_TABLE_SCHEMA || '.' || TG_TABLE_NAME, last_id); - return null; - end; - $function$ language plpgsql; - - create table models ( - id int primary key generated always as identity, - version varchar not null, - constraint model_version_must_be_unique - unique (version) - ); - - create table microservices ( - id int primary key generated always as identity, - version varchar not null, - constraint microservice_version_must_be_unique - unique (version) - ); - - -- `set timezone` for the session reinterprets all tztimestamp during select with the new time zone - -- but the data stored in tztimestamp remains unambiguous - create table runs ( - id int primary key generated always as identity, - microservice_id int not null, - model_id int not null, - duration tstzrange not null default tstzrange((now() at time zone 'Etc/UTC'), 'infinity', '[)'), - -- allow as-of to be in the past - as_of timestamptz not null default (now() at time zone 'Etc/UTC'), - -- allow run to use a non-utc timezone for selection criteria visit date/timestamp intervals - -- time zone from the IANA (Olson) database - -- time zone column name matches underscore convention here. - time_zone timezone not null default 'America/New_York', - constraint runs_require_a_microservice - foreign key (microservice_id) references microservices (id) - on delete cascade - on update cascade, - constraint runs_require_a_model - foreign key (model_id) references models (id) - on delete cascade - on update cascade - -- maybe pick one of the following two constaints on the index - -- constraint only_one_run_per_duration -- no overlaps or outstanding (crashed) runs - -- exclude using gist (duration with &&), - -- constraint only_one_run_per_duration_microservice_and_model -- simultaneous, blue-green deploys allowed - -- exclude using gist (microservice_id with =, model_id with =, duration with &&) - ); - - create index runs_duration_index on runs using gist (duration); - create table predictions ( - id int primary key generated always as identity, - run_id int not null, - subject_id int not null, - score double precision not null, - constraint predictions_require_a_run - foreign key (run_id) references runs (id) - on delete cascade - on update cascade, - -- document your assumptions about how many predictions are made per subject - -- per visit? - -- per run? - constraint only_one_prediction_per_subject_and_run - unique (run_id, subject_id), - -- pick one of the following two constaints - constraint prediction_score_must_be_a_normal - check (0.0 <= score and score <= 1.0), - constraint prediction_score_must_be_a_valence - check (-1.0 <= score and score <= 1.0) - ); - - create trigger predictions_inserted after insert on predictions - referencing new table as inserted - for each statement - execute procedure call_notify(); -end; -$$ language plpgsql; - - -create or replace function down_public() -returns void as $$ -begin - if not uninstall('public'::varchar) then - return; - end if; - - drop trigger predictions_inserted on predictions; - drop table predictions; - drop table runs cascade; - drop table microservices; - drop table models cascade; - drop function call_notify; - drop domain timezone; - drop function is_timezone; -end; -$$ language plpgsql; - - -create or replace function up_private() -returns void as $$ -begin - if not install('private'::varchar, array['public']::varchar[]) then - return; - end if; - - create table features ( - id int primary key, - greenish float not null, - is_animal boolean not null, - is_vegetable boolean not null, - is_mineral boolean not null, - constraint features_require_a_prediction - foreign key (id) references predictions (id) - on delete cascade - on update cascade, - constraint greenish_is_a_normal - check ((0.0 <= greenish) and (greenish <= 1.0)), - constraint kind_must_be_one_hot_encoded - check ( - cast(is_animal as int) - + cast(is_vegetable as int) - + cast(is_mineral as int) - = 1 - ) - ); -end; -$$ language plpgsql; - - -create or replace function down_private() -returns void as $$ -begin - if not uninstall('private'::varchar) then - return; - end if; - - drop table features; -end; -$$ language plpgsql; - - -create or replace function up_epic() -returns void as $$ -begin - if not install('epic'::varchar, array['public']::varchar[]) then - return; - end if; - - create table epic_notifications ( - id int primary key generated always as identity, - prediction_id int not null, - notified_on timestamptz default statement_timestamp(), - constraint only_one_epic_notification_per_prediction - unique (prediction_id), - constraint prediction_epic_notifications_required_a_prediction - foreign key (prediction_id) references predictions (id) - on delete cascade - on update cascade - ); - - create table epic_errors ( - id int primary key generated always as identity, - prediction_id int not null, - recorded_on timestamptz default statement_timestamp(), - acknowledged_on timestamptz default statement_timestamp(), - error_name varchar, - error_description varchar, - constraint prediction_epic_error_required_a_prediction - foreign key (prediction_id) references predictions (id) - on delete cascade - on update cascade - ); -end; -$$ language plpgsql; - - -create or replace function down_epic() -returns void as -$$ -begin - if not uninstall('epic'::varchar) then - return; - end if; - - drop table epic_errors; - drop table epic_notifications; -end; -$$ language plpgsql; - - -create or replace function up() -returns void as $$ - select up_patch(); - select up_public(); - select up_private(); - select up_epic(); -$$ language sql; - - -create or replace function down() -returns void as $$ - select down_epic(); - select down_private(); - select down_public(); - select down_patch(); -$$ language sql; - - -select up(); diff --git a/postgres/sql/003.create.sql b/postgres/sql/initdb.d/003.create.sql similarity index 100% rename from postgres/sql/003.create.sql rename to postgres/sql/initdb.d/003.create.sql diff --git a/postgres/sql/patchdb.d/004.patch.sql b/postgres/sql/patchdb.d/004.patch.sql new file mode 100644 index 0000000..8ad9686 --- /dev/null +++ b/postgres/sql/patchdb.d/004.patch.sql @@ -0,0 +1,95 @@ +set search_path = dsdk; + + +create or replace function up_patch() +returns void as $$ +begin + create table if not exists patches ( + id varchar primary key, + applied timestamptz not null default now(), + applied_by varchar not null + ); + create table if not exists patch_requires ( + patch_id varchar not null, + require_id varchar not null, + constraint patch_requires_have_natural_keys + unique (patch_id, require_id), + constraint patch_requires_belong_to_patches + foreign key (patch_id) + references patches (id) + on update cascade + on delete cascade, + constraint patch_requires_have_many_patches + foreign key (require_id) + references patches(id) + ); + + begin + create function install(in in_id varchar, in_requires varchar[]) + returns bool + as $function$ + declare + result int; + begin + lock table patches in exclusive mode; + select 1 into result from patches where id = in_id; + if found then + return false; + end if; + raise notice 'Installing patch: %', in_id; + insert into patches + (id, applied_by) + values + (in_id, current_user); + insert into patch_requires + (patch_id, require_id) + select + in_id, unnest(in_requires); + return true; + end; + $function$ language plpgsql; + exception when duplicate_function then + end; + + begin + create function uninstall(in in_id varchar) + returns bool + as $function$ + declare + result int; + begin + lock table patches in exclusive mode; + select 1 into result from patches where id = in_id; + if not found then + return false; + end if; + raise notice 'Uninstalling patch: %', in_id; + delete from patches where id = in_id; + return true; + end; + $function$ language plpgsql; + exception when duplicate_function then + end; + + if not install('patch'::varchar, array[]::varchar[]) then + return; + end if; +end; +$$ language plpgsql; + + +create or replace function down_patch() +returns void as +$$ +begin + if not uninstall('patch'::varchar) then + return; + end if; + + drop table patch_requires; + drop table patches; +end; +$$ language plpgsql; + + +select up_patch(); diff --git a/postgres/sql/patchdb.d/005.public.sql b/postgres/sql/patchdb.d/005.public.sql new file mode 100644 index 0000000..eac214a --- /dev/null +++ b/postgres/sql/patchdb.d/005.public.sql @@ -0,0 +1,128 @@ +set search_path = dsdk; + + +create or replace function up_public() +returns void as $$ +begin + if not install('public'::varchar, array['patch']::varchar[]) then + return; + end if; + + create or replace function is_timezone(time_zone varchar) + returns boolean as $function$ + declare valid timestamptz; + begin + valid := now() at time zone time_zone; + return true; + exception when invalid_parameter_value or others then + return false; + end; + $function$ language plpgsql stable; + + create domain timezone as varchar + check ( is_timezone(value) ); + + create function call_notify() + returns trigger as $function$ + declare last_id text; + begin + select max(id) + into last_id + from inserted; + perform pg_notify(TG_TABLE_SCHEMA || '.' || TG_TABLE_NAME, last_id); + return null; + end; + $function$ language plpgsql; + + create table models ( + id int primary key generated always as identity, + version varchar not null, + constraint model_version_must_be_unique + unique (version) + ); + + create table microservices ( + id int primary key generated always as identity, + version varchar not null, + constraint microservice_version_must_be_unique + unique (version) + ); + + -- `set timezone` for the session reinterprets all tztimestamp during select with the new time zone + -- but the data stored in tztimestamp remains unambiguous + create table runs ( + id int primary key generated always as identity, + microservice_id int not null, + model_id int not null, + duration tstzrange not null default tstzrange((now() at time zone 'Etc/UTC'), 'infinity', '[)'), + -- allow as-of to be in the past + as_of timestamptz not null default (now() at time zone 'Etc/UTC'), + -- allow run to use a non-utc timezone for selection criteria visit date/timestamp intervals + -- time zone from the IANA (Olson) database + -- time zone column name matches underscore convention here. + time_zone timezone not null default 'America/New_York', + constraint runs_require_a_microservice + foreign key (microservice_id) references microservices (id) + on delete cascade + on update cascade, + constraint runs_require_a_model + foreign key (model_id) references models (id) + on delete cascade + on update cascade + -- maybe pick one of the following two constaints on the index + -- constraint only_one_run_per_duration -- no overlaps or outstanding (crashed) runs + -- exclude using gist (duration with &&), + -- constraint only_one_run_per_duration_microservice_and_model -- simultaneous, blue-green deploys allowed + -- exclude using gist (microservice_id with =, model_id with =, duration with &&) + ); + + create index runs_duration_index on runs using gist (duration); + create table predictions ( + id int primary key generated always as identity, + run_id int not null, + subject_id int not null, + score double precision not null, + constraint predictions_require_a_run + foreign key (run_id) references runs (id) + on delete cascade + on update cascade, + -- document your assumptions about how many predictions are made per subject + -- per visit? + -- per run? + constraint only_one_prediction_per_subject_and_run + unique (run_id, subject_id), + -- pick one of the following two constaints + constraint prediction_score_must_be_a_normal + check (0.0 <= score and score <= 1.0), + constraint prediction_score_must_be_a_valence + check (-1.0 <= score and score <= 1.0) + ); + + create trigger predictions_inserted after insert on predictions + referencing new table as inserted + for each statement + execute procedure call_notify(); +end; +$$ language plpgsql; + + +create or replace function down_public() +returns void as $$ +begin + if not uninstall('public'::varchar) then + return; + end if; + + drop trigger predictions_inserted on predictions; + drop table predictions; + drop table runs cascade; + drop table microservices; + drop table models cascade; + drop function call_notify; + drop domain timezone; + drop function is_timezone; +end; +$$ language plpgsql; + + +select up_public(); diff --git a/postgres/sql/patchdb.d/006.private.sql b/postgres/sql/patchdb.d/006.private.sql new file mode 100644 index 0000000..0847a61 --- /dev/null +++ b/postgres/sql/patchdb.d/006.private.sql @@ -0,0 +1,47 @@ +set search_path = dsdk; + + +create or replace function up_private() +returns void as $$ +begin + if not install('private'::varchar, array['public']::varchar[]) then + return; + end if; + + create table features ( + id int primary key, + greenish float not null, + is_animal boolean not null, + is_vegetable boolean not null, + is_mineral boolean not null, + constraint features_require_a_prediction + foreign key (id) references predictions (id) + on delete cascade + on update cascade, + constraint greenish_is_a_normal + check ((0.0 <= greenish) and (greenish <= 1.0)), + constraint kind_must_be_one_hot_encoded + check ( + cast(is_animal as int) + + cast(is_vegetable as int) + + cast(is_mineral as int) + = 1 + ) + ); +end; +$$ language plpgsql; + + +create or replace function down_private() +returns void as $$ +begin + if not uninstall('private'::varchar) then + return; + end if; + + drop table features; +end; +$$ language plpgsql; + + +select up_private(); diff --git a/postgres/sql/patchdb.d/007.epic.sql b/postgres/sql/patchdb.d/007.epic.sql new file mode 100644 index 0000000..311f46b --- /dev/null +++ b/postgres/sql/patchdb.d/007.epic.sql @@ -0,0 +1,53 @@ +set search_path = dsdk; + + +create or replace function up_epic() +returns void as $$ +begin + if not install('epic'::varchar, array['public']::varchar[]) then + return; + end if; + + create table epic_notifications ( + id int primary key generated always as identity, + prediction_id int not null, + notified_on timestamptz default statement_timestamp(), + constraint only_one_epic_notification_per_prediction + unique (prediction_id), + constraint prediction_epic_notifications_required_a_prediction + foreign key (prediction_id) references predictions (id) + on delete cascade + on update cascade + ); + + create table epic_errors ( + id int primary key generated always as identity, + prediction_id int not null, + recorded_on timestamptz default statement_timestamp(), + acknowledged_on timestamptz default statement_timestamp(), + error_name varchar, + error_description varchar, + constraint prediction_epic_error_required_a_prediction + foreign key (prediction_id) references predictions (id) + on delete cascade + on update cascade + ); +end; +$$ language plpgsql; + + +create or replace function down_epic() +returns void as +$$ +begin + if not uninstall('epic'::varchar) then + return; + end if; + + drop table epic_errors; + drop table epic_notifications; +end; +$$ language plpgsql; + + +select up_epic();