~singpolyma/jmp-schemas

192715f08099b4c41742c788dd6e21def90c1a2c — Stephen Paul Weber a month ago 395bb79
Multi-account billing schema

Add parent_customer_id to plan_log
customer_plans view includes this new column
balances shows parent balance if there is a parent (non recursive)
INSERT INTO transactions inserts for parent if there is one (non recursive)
NOTIFY possible_renewal for self and all expired children
A deploy/parent_customer_id.sql => deploy/parent_customer_id.sql +63 -0
@@ 0,0 1,63 @@
-- Deploy jmp:parent_customer_id to pg
-- requires: plan_log
-- requires: customer_plans
-- requires: balances
-- requires: transactions

BEGIN;

ALTER TABLE plan_log ADD COLUMN parent_customer_id TEXT;
CREATE INDEX on plan_log (parent_customer_id);

CREATE OR REPLACE VIEW customer_plans AS
	SELECT DISTINCT ON (customer_id)
		customer_id,
		plan_name,
		upper(date_range) AS expires_at,
		parent_customer_id
	FROM plan_log
	WHERE NOT (tsrange(LOCALTIMESTAMP, LOCALTIMESTAMP, '[]') << date_range)
	ORDER BY customer_id, date_range DESC;

CREATE OR REPLACE VIEW balances AS
	SELECT customer_plans.customer_id, SUM(transactions.amount) AS balance
	FROM customer_plans INNER JOIN transactions ON
		transactions.customer_id =
			COALESCE(customer_plans.parent_customer_id, customer_plans.customer_id)
	GROUP BY customer_plans.customer_id;

CREATE OR REPLACE FUNCTION insert_to_parent_if_present() RETURNS TRIGGER AS $$
	DECLARE
		parent_id TEXT;
	BEGIN
		SELECT parent_customer_id INTO parent_id
		FROM customer_plans WHERE customer_id=NEW.customer_id;

		IF parent_id IS NOT NULL THEN
			NEW.customer_id := parent_id;
		END IF;

		RETURN NEW;
	END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER insert_to_parent_if_present BEFORE INSERT ON transactions
	FOR EACH ROW
	EXECUTE PROCEDURE insert_to_parent_if_present();

CREATE OR REPLACE FUNCTION check_and_notify_possible_renewal_on_expired_top_up_trigger() RETURNS TRIGGER AS $$
	DECLARE
		row RECORD;
	BEGIN
		FOR row IN SELECT customer_id FROM customer_plans WHERE
			expires_at < LOCALTIMESTAMP
			AND (customer_id=NEW.customer_id OR parent_customer_id=NEW.customer_id)
		LOOP
			PERFORM pg_notify('possible_renewal', row.customer_id);
		END LOOP;

		RETURN NEW;
	END;
$$ LANGUAGE plpgsql;

COMMIT;

A revert/parent_customer_id.sql => revert/parent_customer_id.sql +40 -0
@@ 0,0 1,40 @@
-- Revert jmp:parent_customer_id from pg

BEGIN;

DROP TRIGGER insert_to_parent_if_present ON transactions;
DROP FUNCTION insert_to_parent_if_present;

CREATE OR REPLACE VIEW customer_plans AS
	SELECT DISTINCT ON (customer_id)
		customer_id,
		plan_name,
		upper(date_range) AS expires_at,
		NULL as parent_customer_id -- cannot drop view column
	FROM plan_log
	WHERE NOT (tsrange(LOCALTIMESTAMP, LOCALTIMESTAMP, '[]') << date_range)
	ORDER BY customer_id, date_range DESC;

CREATE OR REPLACE VIEW balances AS
	SELECT customer_id, SUM(transactions.amount) AS balance
	FROM transactions
	GROUP BY customer_id;

ALTER TABLE plan_log DROP COLUMN parent_customer_id;

CREATE OR REPLACE FUNCTION check_and_notify_possible_renewal_on_expired_top_up_trigger() RETURNS TRIGGER AS $$
	DECLARE
		expired BOOLEAN;
	BEGIN
		SELECT expires_at < LOCALTIMESTAMP INTO expired
		FROM customer_plans WHERE customer_id=NEW.customer_id;

		IF expired THEN
			PERFORM pg_notify('possible_renewal', NEW.customer_id);
		END IF;

		RETURN NEW;
	END;
$$ LANGUAGE plpgsql;

COMMIT;

M sqitch.plan => sqitch.plan +2 -0
@@ 41,3 41,5 @@ require_settled_after [settled_after insert_charge_for_cdr] 2022-04-12T18:45:50Z

notify_possible_renewal_on_expired_top_up [transactions customer_plans] 2022-04-19T17:53:50Z Stephen Paul Weber,,, <singpolyma@singpolyma-beefy> # When an expired customer tops up, notify to try renewal
@2022110 2022-04-20T20:48:20Z Stephen Paul Weber,,, <singpolyma@singpolyma-beefy> # Notify when an expired customer tops up

parent_customer_id [plan_log customer_plans balances transactions] 2022-08-03T17:50:38Z Stephen Paul Weber,,, <singpolyma@singpolyma-beefy> # Add parent_customer_id to plan_log\n\ncustomer_plans should include the parent\nbalance comes from parent where present\ntransactions should insert to parent where present

A verify/parent_customer_id.sql => verify/parent_customer_id.sql +53 -0
@@ 0,0 1,53 @@
-- Verify jmp:parent_customer_id on pg

BEGIN;

SELECT parent_customer_id FROM plan_log;
SELECT parent_customer_id FROM customer_plans;

INSERT INTO plan_log
	(customer_id, plan_name, date_range)
	VALUES
	('testparent', 'testplan', '[now, now]');

INSERT INTO plan_log
	(customer_id, plan_name, date_range, parent_customer_id)
	VALUES
	('testchild', 'testplan', '[now, now]', 'testparent');

INSERT INTO transactions
	(customer_id, transaction_id, created_at, amount, settled_after)
	VALUES
	('testparent', 'parent_tx1', localtimestamp, 10, localtimestamp);

INSERT INTO transactions
	(customer_id, transaction_id, created_at, amount, settled_after)
	VALUES
	('testchild', 'child_tx1', localtimestamp, -1, localtimestamp);

DO $$
DECLARE
	n numeric;
BEGIN
	SELECT COUNT(*) INTO n FROM transactions WHERE customer_id='testparent';
	IF n IS NULL OR n <> 2 THEN
		RAISE EXCEPTION 'Expected 2 parent tx, got: %', n;
	END IF;

	SELECT COUNT(*) INTO n FROM transactions WHERE customer_id='testchild';
	IF n IS NULL OR n <> 0 THEN
		RAISE EXCEPTION 'Expected 0 child tx, got: %', n;
	END IF;

	SELECT balance INTO n FROM balances WHERE customer_id='testparent';
	IF n IS NULL OR n <> 9 THEN
		RAISE EXCEPTION 'Expected parent balance of 9, got: %', n;
	END IF;

	SELECT balance INTO n FROM balances WHERE customer_id='testchild';
	IF n IS NULL OR n <> 9 THEN
		RAISE EXCEPTION 'Expected child balance of 9, got: %', n;
	END IF;
END $$;

ROLLBACK;