~singpolyma/jmp-schemas

1b4103433271ac1ce3e99152382849b401beb2c2 — Stephen Paul Weber 3 years ago b3dca71
Insert charge for CDR

Trigger to insert a transaction charging the customer for the amount owed for
an INSERTed CDR.
A deploy/insert_charge_for_cdr.sql => deploy/insert_charge_for_cdr.sql +36 -0
@@ 0,0 1,36 @@
-- Deploy jmp:insert_charge_for_cdr to pg
-- requires: cdr_charge
-- requires: cdr_with_charge
-- requires: transactions

BEGIN;

CREATE OR REPLACE FUNCTION insert_charge_for_cdr() RETURNS TRIGGER AS
$insert_charge_for_cdr$
	DECLARE
		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);
		IF final_charge > 0.0 THEN
			INSERT INTO transactions (
				customer_id, transaction_id, created_at, amount, note
			) VALUES (
				NEW.customer_id,
				'cdr_charge_for_' || NEW.cdr_id,
				NEW.start + MAKE_INTERVAL(secs := NEW.billsec),
				-final_charge,
				'Charge for ' || (CEIL(NEW.billsec / 60.0)) || ' minute call'
			);
		END IF;
		RETURN NEW;
	END;
$insert_charge_for_cdr$ LANGUAGE plpgsql;

CREATE TRIGGER insert_charge_for_cdr
	AFTER INSERT ON cdr
	FOR EACH ROW
	EXECUTE PROCEDURE insert_charge_for_cdr();

COMMIT;

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

BEGIN;

DROP TRIGGER insert_charge_for_cdr ON cdr;
DROP FUNCTION insert_charge_for_cdr;

COMMIT;

M sqitch.plan => sqitch.plan +1 -0
@@ 19,3 19,4 @@ call_rates 2021-11-17T01:29:07Z Stephen Paul Weber,,, <singpolyma@singpolyma-bee
cdr_with_charge [cdr call_rates customer_plans] 2021-11-17T01:44:14Z Stephen Paul Weber,,, <singpolyma@singpolyma-beefy> # View to get CDR records augmented with rate and charge amount
plans 2021-11-17T18:06:30Z Stephen Paul Weber,,, <singpolyma@singpolyma-beefy> # Table for plan metadata\n\nIdeally this would come from a dhall_fdw, but for now we can import to this.
cdr_charge [customer_plans plans cdr_with_charge] 2021-11-17T18:09:49Z Stephen Paul Weber,,, <singpolyma@singpolyma-beefy> # Get the amount to charge a customer for a given CDR
insert_charge_for_cdr [cdr_charge cdr_with_charge transactions] 2021-11-23T14:41:15Z Stephen Paul Weber,,, <singpolyma@singpolyma-beefy> # Trigger to insert a transaction for the charge for this CDR

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

BEGIN;

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

INSERT INTO plans VALUES ('{
	"name": "test",
	"minutes": { "included": 10440 }
}');

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

INSERT INTO cdr (cdr_id, customer_id, start, billsec, disposition, tel)
	VALUES(
		'test2',
		'test',
		LOCALTIMESTAMP - MAKE_INTERVAL(months := 1),
		10000,
		'ANSWERED',
		'+15551234567'
);

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('test4', 'test', LOCALTIMESTAMP, 3480, 'ANSWERED', '+15551234567');

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

DO $$
DECLARE
	c integer;
	a numeric;
BEGIN
	SELECT COUNT(1) FROM transactions WHERE
	customer_id='test' AND transaction_id IN (
		'cdr_charge_for_test1',
		'cdr_charge_for_test2',
		'cdr_charge_for_test3'
	) INTO c;

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

	SELECT COUNT(1) FROM transactions WHERE customer_id='test' INTO c;
	IF c <> 2 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;
	END IF;
END $$;

ROLLBACK;