~singpolyma/jmp-schemas

a40dc7b43c222c2d19db87615424f327638192b0 — Stephen Paul Weber 4 months ago 3122e25 master 2023123
customer_plans.pending
A deploy/customer_plans_with_pending.sql => deploy/customer_plans_with_pending.sql +20 -0
@@ 0,0 1,20 @@
-- Deploy jmp:customer_plans_with_pending to pg
-- requires: plan_log
-- requires: customer_plans
-- requires: parent_customer_id
-- requires: plan_log_with_range

BEGIN;

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,
		UPPER(date_range) - LOWER(date_range) < '2 seconds' AS pending
	FROM plan_log
	WHERE NOT tsrange(LOCALTIMESTAMP, LOCALTIMESTAMP, '[]') << date_range
	ORDER BY customer_id, date_range DESC;

COMMIT;

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

BEGIN;

DROP VIEW balances; -- dependency must be re-created too, ugh
DROP VIEW cdr_with_charge; -- dependency must be re-created too, ugh
DROP VIEW customer_plans;

CREATE 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 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 VIEW cdr_with_charge AS
	SELECT DISTINCT ON (cdr_id, customer_id)
		cdr.*,
		rate,
		(CASE WHEN cdr.disposition IN ('VOICEMAIL', 'NO ANSWER', 'FAILED') THEN 0
		ELSE rate * ceiling(billsec / 60.0) END) AS charge
	FROM
		cdr
		LEFT JOIN customer_plans USING (customer_id)
		LEFT JOIN call_rates ON
			cdr.direction = call_rates.direction AND
			(
				customer_plans.plan_name IS NULL OR
				customer_plans.plan_name = call_rates.plan_name
			) AND
			cdr.tel LIKE call_rates.prefix || '%'
	ORDER BY cdr_id, customer_id, prefix DESC, rate DESC;

COMMIT;

M sqitch.plan => sqitch.plan +3 -0
@@ 57,3 57,6 @@ snikket_instances 2023-03-28T18:47:40Z Stephen Paul Weber,,, <singpolyma@singpol

cdr_with_charge_ignoring_failed_noanswer [cdr_with_charge] 2023-03-28T21:35:43Z Nico <nico@pop-os> # Added dispositions NO ANSWER and FAILED to cdr_with_charge ignore list
@2023100 2023-04-10T19:00:23Z Stephen Paul Weber,,, <singpolyma@singpolyma-beefy> # NO ANSWER and FAILED calls should also not bill

customer_plans_with_pending [plan_log customer_plans parent_customer_id plan_log_with_range] 2023-05-03T15:05:21Z Stephen Paul Weber,,, <singpolyma@singpolyma-beefy> # Add pending boolean to the customer_plans view
@2023123 2023-05-03T15:20:20Z Stephen Paul Weber,,, <singpolyma@singpolyma-beefy> # Deploy customer_plans.pending

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

BEGIN;

SELECT pending FROM customer_plans;

ROLLBACK;