mirror of https://github.com/sipwise/db-schema.git
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 52b3341599
)
mr9.5.5
parent
791851d1a5
commit
d7b14a892e
@ -0,0 +1,4 @@
|
||||
use billing;
|
||||
|
||||
drop function if exists get_billing_profile_contract_cnt;
|
||||
drop function if exists get_billing_network_contract_cnt;
|
@ -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 ;
|
Loading…
Reference in new issue