M .builds/debian-stable.yml => .builds/debian-stable.yml +1 -0
@@ 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
A deploy/plan_log_with_range.sql => deploy/plan_log_with_range.sql +30 -0
@@ 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;
A revert/plan_log_with_range.sql => revert/plan_log_with_range.sql +26 -0
@@ 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;
M sqitch.plan => sqitch.plan +2 -0
@@ 8,3 8,5 @@ plan_log 2021-02-24T01:53:29Z Stephen Paul Weber <singpolyma@singpolyma.net> # L
customer_plans 2021-02-24T02:06:25Z Stephen Paul Weber <singpolyma@singpolyma.net> # View of current customer plans
cdr 2021-02-24T18:36:49Z Stephen Paul Weber <singpolyma@singpolyma.net> # Create CDR table for Asterisk
@2021062 2021-03-03T14:38:01Z Stephen Paul Weber <singpolyma@singpolyma.net> # First production deploy of jmp-pay
+
+plan_log_with_range [plan_log customer_plans] 2021-05-03T19:30:36Z Stephen Paul Weber,,, <singpolyma@singpolyma-beefy> # Switch plan_log to use a tsrange
M verify/plan_log.sql => verify/plan_log.sql +5 -3
@@ 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;
A verify/plan_log_with_range.sql => verify/plan_log_with_range.sql +21 -0
@@ 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;