From ad75b90f028fa5eaf2e0801233b47ee12c418644 Mon Sep 17 00:00:00 2001 From: Rene Krenn Date: Fri, 29 Oct 2021 20:28:52 +0200 Subject: [PATCH] TT#147151 UDFs for fast usage count of billing profile&network mariadb does not support variable referals in correlated subqueries if the nesting depth is 2 or beyond. so in short: below works -> select (select count(*) from table1 where id = root.id ) as cnt from table2 as root; ... while this not unfortunately: select (select count(1) from (select 1 from table1 where id = root.id LIMIT 1001) as q ) as cnt_limited from table2 as root; this can be solved by declaring the topical subqueries in dedicated user-defined functions, so involved panel/api parts will load quickly even with millions of subscribers. Change-Id: If96603cb4115259d719297af46c5bc7c10aadf76 (cherry picked from commit 52b3341599d9780bf1889b8c2442791c4024ea04) --- db_scripts/diff/15703.down | 4 ++ db_scripts/diff/15703.up | 78 ++++++++++++++++++++++++++++++++++++++ 2 files changed, 82 insertions(+) create mode 100644 db_scripts/diff/15703.down create mode 100644 db_scripts/diff/15703.up diff --git a/db_scripts/diff/15703.down b/db_scripts/diff/15703.down new file mode 100644 index 00000000..b8d346a5 --- /dev/null +++ b/db_scripts/diff/15703.down @@ -0,0 +1,4 @@ +use billing; + +drop function if exists get_billing_profile_contract_cnt; +drop function if exists get_billing_network_contract_cnt; \ No newline at end of file diff --git a/db_scripts/diff/15703.up b/db_scripts/diff/15703.up new file mode 100644 index 00000000..b6d7d49f --- /dev/null +++ b/db_scripts/diff/15703.up @@ -0,0 +1,78 @@ +use billing; + +delimiter ;; +drop function if exists get_billing_profile_contract_cnt;; +create function get_billing_profile_contract_cnt( + _profile_id int, + _limit int +) returns int(11) +deterministic reads sql data +begin + + if _limit >= 0 then + return (select + count(1) + from (select + 1 + from billing.contracts_billing_profile_network_schedule cbpns + join billing.contracts_billing_profile_network cbpn on cbpns.profile_network_id = cbpn.id + join billing._v_actual_effective_start_time est on est.contract_id = cbpn.contract_id and cbpns.effective_start_time = est.effective_start_time + join billing.contracts as c on est.contract_id = c.id + where + cbpn.billing_profile_id = _profile_id + and c.status != 'terminated' + limit _limit) as q + ); + end if; + + return (select + count(1) + from billing.contracts_billing_profile_network_schedule cbpns + join billing.contracts_billing_profile_network cbpn on cbpns.profile_network_id = cbpn.id + join billing._v_actual_effective_start_time est on est.contract_id = cbpn.contract_id and cbpns.effective_start_time = est.effective_start_time + join billing.contracts as c on est.contract_id = c.id + where + cbpn.billing_profile_id = _profile_id + and c.status != 'terminated' + ); + +end;; + +drop function if exists get_billing_network_contract_cnt;; +create function get_billing_network_contract_cnt( + _network_id int, + _limit int +) returns int(11) +deterministic reads sql data +begin + + if _limit >= 0 then + return (select + count(1) + from (select + 1 + from billing.contracts_billing_profile_network_schedule cbpns + join billing.contracts_billing_profile_network cbpn on cbpns.profile_network_id = cbpn.id + join billing._v_actual_effective_start_time est on est.contract_id = cbpn.contract_id and cbpns.effective_start_time = est.effective_start_time + join billing.contracts as c on est.contract_id = c.id + where + cbpn.billing_network_id = _network_id + and c.status != 'terminated' + limit _limit) as q + ); + end if; + + return (select + count(1) + from billing.contracts_billing_profile_network_schedule cbpns + join billing.contracts_billing_profile_network cbpn on cbpns.profile_network_id = cbpn.id + join billing._v_actual_effective_start_time est on est.contract_id = cbpn.contract_id and cbpns.effective_start_time = est.effective_start_time + join billing.contracts as c on est.contract_id = c.id + where + cbpn.billing_network_id = _network_id + and c.status != 'terminated' + ); + +end;; + +delimiter ; \ No newline at end of file