From 5573078307ccb4fed4dec6e95a2bf38e91385424 Mon Sep 17 00:00:00 2001 From: Stephen Paul Weber Date: Mon, 3 May 2021 15:47:01 -0500 Subject: [PATCH] plan_log uses a tsrange instead of two timestamps now This is honestly just more correct, but also allows for easy checking of non-overlapping ranges, which we now do. --- .builds/debian-stable.yml | 1 + deploy/plan_log_with_range.sql | 30 ++++++++++++++++++++++++++++++ revert/plan_log_with_range.sql | 26 ++++++++++++++++++++++++++ sqitch.plan | 2 ++ verify/plan_log.sql | 8 +++++--- verify/plan_log_with_range.sql | 21 +++++++++++++++++++++ 6 files changed, 85 insertions(+), 3 deletions(-) create mode 100644 deploy/plan_log_with_range.sql create mode 100644 revert/plan_log_with_range.sql create mode 100644 verify/plan_log_with_range.sql diff --git a/.builds/debian-stable.yml b/.builds/debian-stable.yml index 5e34a0b..e48db58 100644 --- a/.builds/debian-stable.yml +++ b/.builds/debian-stable.yml @@ -10,6 +10,7 @@ tasks: - prep: | sudo -u postgres psql -c "CREATE ROLE $(id -un) LOGIN" sudo -u postgres psql -c "CREATE DATABASE jmp WITH OWNER $(id -un)" + sudo -u postgres psql -d jmp -c "CREATE EXTENSION btree_gist" - deploy: | cd jmp-schemas sqitch deploy diff --git a/deploy/plan_log_with_range.sql b/deploy/plan_log_with_range.sql new file mode 100644 index 0000000..a880c6b --- /dev/null +++ b/deploy/plan_log_with_range.sql @@ -0,0 +1,30 @@ +-- Deploy jmp:plan_log_with_range to pg +-- requires: plan_log +-- requires: customer_plans + +BEGIN; + +DROP VIEW customer_plans; + +ALTER TABLE plan_log ADD date_range tsrange; + +UPDATE plan_log SET date_range=tsrange(starts_at, expires_at); +ALTER TABLE plan_log ALTER date_range SET NOT NULL; + +ALTER TABLE plan_log DROP starts_at; +ALTER TABLE plan_log DROP expires_at; +ALTER TABLE plan_log ADD PRIMARY KEY (customer_id, date_range); + +ALTER TABLE plan_log ADD EXCLUDE USING GIST + (customer_id WITH =, date_range WITH &&); + +CREATE VIEW customer_plans AS + SELECT DISTINCT ON (customer_id) + customer_id, + plan_name, + upper(date_range) AS expires_at + FROM plan_log + WHERE NOT ('[now,now]' << date_range) + ORDER BY customer_id, date_range DESC; + +COMMIT; diff --git a/revert/plan_log_with_range.sql b/revert/plan_log_with_range.sql new file mode 100644 index 0000000..e2a1748 --- /dev/null +++ b/revert/plan_log_with_range.sql @@ -0,0 +1,26 @@ +-- Revert jmp:plan_log_with_range from pg + +BEGIN; + +DROP VIEW customer_plans; + +ALTER TABLE plan_log ADD starts_at TIMESTAMP; +ALTER TABLE plan_log ADD expires_at TIMESTAMP; + +UPDATE plan_log SET starts_at=lower(date_range), expires_at=upper(date_range); +ALTER TABLE plan_log ALTER starts_at SET NOT NULL; +ALTER TABLE plan_log ALTER expires_at SET NOT NULL; + +ALTER TABLE plan_log DROP date_range; +ALTER TABLE plan_log ADD PRIMARY KEY (customer_id, starts_at); + +CREATE VIEW customer_plans AS + SELECT DISTINCT ON (customer_id) + customer_id, + plan_name, + expires_at + FROM plan_log + WHERE starts_at <= NOW() + ORDER BY customer_id, starts_at DESC; + +COMMIT; diff --git a/sqitch.plan b/sqitch.plan index ba54454..e147fea 100644 --- a/sqitch.plan +++ b/sqitch.plan @@ -8,3 +8,5 @@ plan_log 2021-02-24T01:53:29Z Stephen Paul Weber # L customer_plans 2021-02-24T02:06:25Z Stephen Paul Weber # View of current customer plans cdr 2021-02-24T18:36:49Z Stephen Paul Weber # Create CDR table for Asterisk @2021062 2021-03-03T14:38:01Z Stephen Paul Weber # First production deploy of jmp-pay + +plan_log_with_range [plan_log customer_plans] 2021-05-03T19:30:36Z Stephen Paul Weber,,, # Switch plan_log to use a tsrange diff --git a/verify/plan_log.sql b/verify/plan_log.sql index 59455b8..d788e82 100644 --- a/verify/plan_log.sql +++ b/verify/plan_log.sql @@ -4,9 +4,11 @@ BEGIN; SELECT customer_id, - plan_name, - starts_at, - expires_at + plan_name +-- These were both removed by plan_log_with_range, commenting out here is a +-- hack pending https://stackoverflow.com/questions/61215808/is-it-possible-to-write-a-sqitch-change-that-drops-a-column-without-dooming-sqi +-- starts_at, +-- expires_at FROM plan_log WHERE FALSE; diff --git a/verify/plan_log_with_range.sql b/verify/plan_log_with_range.sql new file mode 100644 index 0000000..3194fae --- /dev/null +++ b/verify/plan_log_with_range.sql @@ -0,0 +1,21 @@ +-- Verify jmp:plan_log_with_range on pg + +BEGIN; + +SELECT date_range::tsrange FROM plan_log; + +INSERT INTO plan_log (customer_id, plan_name, date_range) + VALUES ('cust', 'plan', '[2001-01-01, 2002-01-01]'); + +DO $$ +BEGIN + INSERT INTO plan_log (customer_id, plan_name, date_range) + VALUES ('cust', 'plan', '[2001-11-01, 2001-12-01]'); + SELECT 1/0; +EXCEPTION WHEN exclusion_violation THEN +END $$; + +INSERT INTO plan_log (customer_id, plan_name, date_range) + VALUES ('cust2', 'plan', '[2001-01-01, 2002-01-01]'); + +ROLLBACK; -- 2.45.2