From bcc2fb9f2a847218babedcc2983b7880cf80ab52 Mon Sep 17 00:00:00 2001 From: Stephen Paul Weber Date: Tue, 23 Jul 2024 11:17:57 -0500 Subject: [PATCH] Speedup cdr_charge with a raw redis query Instead of going via the virtual table that does a bunch of extra work --- deploy/cdr_charge_raw_redis.sql | 56 +++++++++++++++++++++++++++++++++ revert/cdr_charge_raw_redis.sql | 50 +++++++++++++++++++++++++++++ sqitch.plan | 2 ++ verify/cdr_charge_raw_redis.sql | 7 +++++ 4 files changed, 115 insertions(+) create mode 100644 deploy/cdr_charge_raw_redis.sql create mode 100644 revert/cdr_charge_raw_redis.sql create mode 100644 verify/cdr_charge_raw_redis.sql diff --git a/deploy/cdr_charge_raw_redis.sql b/deploy/cdr_charge_raw_redis.sql new file mode 100644 index 0000000..d5d521e --- /dev/null +++ b/deploy/cdr_charge_raw_redis.sql @@ -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; diff --git a/revert/cdr_charge_raw_redis.sql b/revert/cdr_charge_raw_redis.sql new file mode 100644 index 0000000..5e5608c --- /dev/null +++ b/revert/cdr_charge_raw_redis.sql @@ -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; diff --git a/sqitch.plan b/sqitch.plan index 4c0e270..6372eea 100644 --- a/sqitch.plan +++ b/sqitch.plan @@ -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 # Add schema for tel inventory system @2023318 2023-11-14T17:45:48Z Stephen Paul Weber,,, # "Deploy tel_inventory" + +cdr_charge_raw_redis [cdr_charge] 2024-07-23T16:11:48Z Stephen Paul Weber,,, # Use raw redis for massive speedup diff --git a/verify/cdr_charge_raw_redis.sql b/verify/cdr_charge_raw_redis.sql new file mode 100644 index 0000000..8defc40 --- /dev/null +++ b/verify/cdr_charge_raw_redis.sql @@ -0,0 +1,7 @@ +-- Verify jmp:cdr_charge_raw_redis on pg + +BEGIN; + +-- Should not have changed, so cdr_charge verification is sufficient + +ROLLBACK; -- 2.45.2