~singpolyma/jmp-schemas

bcc2fb9f2a847218babedcc2983b7880cf80ab52 — Stephen Paul Weber a month ago 97031b9
Speedup cdr_charge with a raw redis query

Instead of going via the virtual table that does a bunch of extra work
A deploy/cdr_charge_raw_redis.sql => deploy/cdr_charge_raw_redis.sql +56 -0
@@ 0,0 1,56 @@
-- Deploy jmp:cdr_charge_raw_redis to pg
-- requires: cdr_charge

BEGIN;

DROP FUNCTION cdr_charge;

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 $$
DECLARE
	r NUMERIC;
BEGIN
WITH
	customer_limit AS (
		SELECT COALESCE(MAX((val)::numeric), 0) AS customer_limit
		FROM raw_customer_data
		WHERE "key"=('jmp_customer_monthly_overage_limit-'||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
	),
	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
	)

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 INTO r
FROM
	customer_limit
	FULL JOIN included_charge ON true
	FULL JOIN used ON true;
RETURN r;
END;
$$ LANGUAGE plpgsql;

COMMIT;

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

BEGIN;

DROP FUNCTION cdr_charge;

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
	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
	),
	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
	)

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 sqitch.plan => sqitch.plan +2 -0
@@ 63,3 63,5 @@ customer_plans_with_pending [plan_log customer_plans parent_customer_id plan_log

tel_inventory 2023-09-18T17:54:30Z Amolith <amolith@secluded.site> # Add schema for tel inventory system
@2023318 2023-11-14T17:45:48Z Stephen Paul Weber,,, <singpolyma@singpolyma-beefy> # "Deploy tel_inventory"

cdr_charge_raw_redis [cdr_charge] 2024-07-23T16:11:48Z Stephen Paul Weber,,, <singpolyma@singpolyma-beefy> # Use raw redis for massive speedup

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

BEGIN;

-- Should not have changed, so cdr_charge verification is sufficient

ROLLBACK;