~singpolyma/jmp-schemas

871e2063ac1f4dc3f72c0438cfc608dc09099105 — Stephen Paul Weber 1 year, 3 months ago 6b2466f
Do not bill over user limit without consent

If the user has no configured limit in Redis, limit is 0
If the CDR would cost less than their limit, bill normally
If they have already spent more than within buffer of their limit, bill normally
Else, bill only enough to get up to their limit
M deploy/cdr_charge.sql => deploy/cdr_charge.sql +29 -14
@@ 1,4 1,5 @@
-- Deploy jmp:cdr_charge to pg
-- requires: customers
-- requires: customer_plans
-- requires: plans
-- requires: cdr_with_charge


@@ 8,30 9,44 @@ BEGIN;
CREATE FUNCTION cdr_charge(
	cdr_start TIMESTAMP,
	cdr_customer_id TEXT,
	cdr_rate NUMERIC,
	cdr_charge NUMERIC -- Basic rate*ceil(billsec/60)
) RETURNS NUMERIC AS $$
WITH unincluded_charge AS (SELECT
	(
		SELECT (plan->'minutes'->'included')::numeric / 10000.0
WITH
	customer_limit AS (
		SELECT COALESCE(MAX((data->>'monthly_overage_limit')::numeric), 0) AS customer_limit
		FROM customers
		WHERE customer_id=cdr_customer_id
	),
	included_charge AS (
		SELECT ((plan->'minutes'->'included')::numeric / 10000.0) AS included_charge
		FROM plans INNER JOIN customer_plans ON plan_name=plan->>'name'
		WHERE customer_id=cdr_customer_id
	) - (
		SELECT SUM(charge)
	),
	used AS (
		SELECT COALESCE(SUM(charge), 0) AS used
		FROM cdr_with_charge
		WHERE
			customer_id=cdr_customer_id AND
			start >= DATE_TRUNC('month', cdr_start) AND
			start <= cdr_start
			start < cdr_start
	)
AS unincluded_charge)

SELECT GREATEST(
	cdr_charge -
		CASE WHEN unincluded_charge < 0
		THEN 0
		ELSE unincluded_charge END,
	0
) FROM unincluded_charge;
SELECT
	CASE
		WHEN cdr_charge IS NULL OR included_charge IS NULL THEN
			0
		WHEN used + cdr_charge < included_charge + customer_limit THEN
			GREATEST(cdr_charge - GREATEST(included_charge - used, 0), 0)
		WHEN included_charge + customer_limit - (cdr_rate * 10) < used THEN
			GREATEST(cdr_charge - GREATEST(included_charge - used, 0), 0)
		ELSE
			LEAST(customer_limit + included_charge - used, customer_limit)
	END
FROM
	customer_limit
	FULL JOIN included_charge ON true
	FULL JOIN used ON true;
$$ LANGUAGE sql;

COMMIT;

M deploy/insert_charge_for_cdr.sql => deploy/insert_charge_for_cdr.sql +5 -2
@@ 8,11 8,14 @@ BEGIN;
CREATE OR REPLACE FUNCTION insert_charge_for_cdr() RETURNS TRIGGER AS
$insert_charge_for_cdr$
	DECLARE
		raw_rate NUMERIC;
		raw_charge NUMERIC;
		final_charge NUMERIC;
	BEGIN
		SELECT charge FROM cdr_with_charge WHERE cdr_id=NEW.cdr_id INTO raw_charge;
		final_charge := cdr_charge(NEW.start, NEW.customer_id, raw_charge);
		SELECT
			rate, charge INTO raw_rate, raw_charge
		FROM cdr_with_charge WHERE cdr_id=NEW.cdr_id;
		final_charge := cdr_charge(NEW.start, NEW.customer_id, raw_rate, raw_charge);
		IF final_charge > 0.0 THEN
			INSERT INTO transactions (
				customer_id, transaction_id, created_at, amount, note

M verify/cdr_charge.sql => verify/cdr_charge.sql +47 -1
@@ 2,6 2,52 @@

BEGIN;

SELECT cdr_charge(localtimestamp, 'abc', 1.12);
INSERT INTO plans VALUES ('{
	"name": "test",
	"minutes": { "included": 10440 }
}');

INSERT INTO call_rates (prefix, direction, plan_name, rate)
	VALUES('+1', 'outbound', 'test', 0.0087);

INSERT INTO plan_log (customer_id, plan_name, date_range)
	VALUES('test', 'test', TSRANGE(LOCALTIMESTAMP, LOCALTIMESTAMP + '5 minutes'));

DO $$
DECLARE
	n numeric;
BEGIN
	SELECT cdr_charge(localtimestamp, 'test', 0.0087, 1) INTO n;

	IF n IS NULL OR n <> 0 THEN
		RAISE EXCEPTION 'Expected 0, got: %', n;
	END IF;

	SELECT cdr_charge(localtimestamp, 'test', 0.0087, 2) INTO n;

	IF n IS NULL OR n <> 0 THEN
		RAISE EXCEPTION 'Expected 0, got: %', n;
	END IF;
END $$;

INSERT INTO cdr (cdr_id, customer_id, start, billsec, disposition, tel) VALUES(
	'test1',
	'test',
	LOCALTIMESTAMP - MAKE_INTERVAL(secs := 10),
	20000,
	'ANSWERED',
	'+15551234567'
);

DO $$
DECLARE
	n numeric;
BEGIN
	SELECT cdr_charge(localtimestamp, 'test', 0.0087, 100) INTO n;

	IF n IS NULL OR n <> 100 THEN
		RAISE EXCEPTION 'Expected 100, got: %', n;
	END IF;
END $$;

ROLLBACK;

M verify/insert_charge_for_cdr.sql => verify/insert_charge_for_cdr.sql +20 -13
@@ 33,11 33,23 @@ INSERT INTO cdr (cdr_id, customer_id, start, billsec, disposition, tel)
INSERT INTO call_rates (prefix, direction, plan_name, rate)
	VALUES('+1', 'outbound', 'test', 0.0087);

INSERT INTO cdr (cdr_id, customer_id, start, billsec, disposition, tel)
	VALUES('test3', 'test', LOCALTIMESTAMP, 3600, 'ANSWERED', '+15551234567');
INSERT INTO cdr (cdr_id, customer_id, start, billsec, disposition, tel) VALUES(
	'test3',
	'test',
	LOCALTIMESTAMP - MAKE_INTERVAL(secs := 20),
	3600,
	'ANSWERED',
	'+15551234567'
);

INSERT INTO cdr (cdr_id, customer_id, start, billsec, disposition, tel)
	VALUES('test4', 'test', LOCALTIMESTAMP, 3480, 'ANSWERED', '+15551234567');
INSERT INTO cdr (cdr_id, customer_id, start, billsec, disposition, tel) VALUES(
	'test4',
	'test',
	LOCALTIMESTAMP - MAKE_INTERVAL(secs := 10),
	3660,
	'ANSWERED',
	'+15551234567'
);

INSERT INTO cdr (cdr_id, customer_id, start, billsec, disposition, tel)
	VALUES('test5', 'test', LOCALTIMESTAMP, 60000, 'ANSWERED', '+15551234567');


@@ 51,25 63,20 @@ BEGIN
	customer_id='test' AND transaction_id IN (
		'cdr_charge_for_test1',
		'cdr_charge_for_test2',
		'cdr_charge_for_test3'
		'cdr_charge_for_test3',
		'cdr_charge_for_test4'
	) INTO c;

	IF c > 0 THEN
		RAISE EXCEPTION 'One of test[123] present';
		RAISE EXCEPTION 'One of test[1234] present';
	END IF;

	SELECT COUNT(1) FROM transactions WHERE customer_id='test' INTO c;
	IF c <> 2 THEN
	IF c <> 1 THEN
		RAISE EXCEPTION 'Expected 2 transactions, got %', c;
	END IF;

	SELECT amount FROM transactions WHERE
	customer_id='test' AND transaction_id='cdr_charge_for_test4' INTO a;
	IF a <> -0.4872 THEN
		RAISE EXCEPTION 'Expected -2*rate, got %', a;
	END IF;

	SELECT amount FROM transactions WHERE
	customer_id='test' AND transaction_id='cdr_charge_for_test5' INTO a;
	IF a <> -8.7 THEN
		RAISE EXCEPTION 'Expected -8.7, got %', a;