TT#36660 new billing mappings tables, procedures, views

to optimize the heavyweight fraud events query (and similar
places), the billing.billing_mappings is refactored into 2
new tables that will hold a scan-line rendered representation
of the former billing_mapping records known with their
(nullable) start and (nullable) stop cols.

accessing this new tables (eg. insert a billing mapping to
switch a contract's billing_profile, or query for the
contracts current billing profile) is not supposed to be
done explicitly, but by the stored sql proc provided:

- "billing.create_contract_billing_profile_network_from_package":
set/add a bunch of profiles from a profile package at once.

- "billing.get_billing_profile_by_*":
get a contract's billing profile id at the given epoch.
+ by_contract_id: customer or system contract id
+ by_uuid: subscriber uuid
+ by_peer_host_id: peer server id

- "billing.get_billing_profile_by_*_network":
get a contract's billing profile id for the given IPv4 or IPv6
string at the given epoch.
+ by_contract_id: customer or system contract id
+ by_uuid: subscriber uuid
+ by_peer_host_id: peer server id

The enhanced fraud queries can finally make use of a view that
can be used to get the current billing profile id:

- "billing.v_actual_billing_profiles":
View showing all contracts' billing_profile_id at the
current time. In contrast to the procs, the view can
be used nicely in joins of stmts.

15418.up also cover copying+transforming the existing records
in billing.billing_mappings. the old table and records are left
for now but are subject to be dropped soon. if new contracts
were created during the upgrade (although discouraged), the
transformation of not yet transformed contracts can be done by
simply re-executing

call billing.transform_billing_mappings();

Change-Id: Ib5ddd620b2b08ed7db4b6448a44931d37ea5b06a
changes/72/21672/22
Rene Krenn 7 years ago
parent c38c9802a7
commit 719fd2750b

@ -0,0 +1,195 @@
use billing;
delimiter ;;
create procedure add_contract_billing_profile_network_schedule(
_contract_id int(11) unsigned,
_last tinyint(3),
_start_date datetime,
_end_date datetime,
_effective_start_date decimal(13,3),
_profile_id int(11) unsigned,
_network_id int(11) unsigned
) begin
declare _profile_network_id int(11) unsigned;
set _profile_network_id = (select id from billing.contracts_billing_profile_network where contract_id = _contract_id and billing_profile_id = _profile_id
and billing_network_id <=> _network_id and start_date <=> _start_date and end_date <=> _end_date and base = _last);
if _profile_network_id is null then
insert into billing.contracts_billing_profile_network values(null,_contract_id,_profile_id,_network_id,_start_date,_end_date,_last);
set _profile_network_id = last_insert_id();
end if;
insert into billing.contracts_billing_profile_network_schedule values(null,_profile_network_id,_effective_start_date);
end;;
create procedure schedule_contract_billing_profile_network(
in _contract_id int(11) unsigned,
in _now datetime,
in _future_mappings varchar(65535)
)
main: begin
declare _new boolean default false;
declare _line varchar(128);
declare _start_date_str,_end_date_str varchar(19);
declare _profile_id_str,_network_id_str varchar(11);
declare _last_str,_col_sep,_row_sep varchar(1);
declare _row_sep_length int;
declare _contract_id_locked,_max_id,_id int(11) unsigned;
if _future_mappings is null then
leave main;
end if;
if _contract_id is null then
signal sqlstate "45001" set message_text = "contract_id required";
else
set _contract_id_locked = (select id from billing.contracts where id = _contract_id for update);
end if;
drop temporary table if exists tmp_billing_mappings;
create temporary table tmp_billing_mappings
(index (id), index (contract_id,start_date,end_date)) engine = memory
select cbpn.id,cbpn.contract_id,cbpn.start_date,cbpn.end_date,cbpn.billing_profile_id,
cbpn.billing_network_id as network_id,cbpn.base from
billing.contracts_billing_profile_network_schedule cbpns join billing.contracts_billing_profile_network cbpn on cbpn.id = cbpns.profile_network_id
where cbpn.contract_id = _contract_id and floor(cbpns.effective_start_time) = cbpns.effective_start_time and (_now is null or
(cbpn.start_date <= _now or cbpn.start_date is null)) order by cbpns.effective_start_time asc, cbpn.base asc, cbpns.profile_network_id asc;
set _max_id = (select max(id) from tmp_billing_mappings);
set _new = if(_max_id is null,true,false);
set _id = if(_max_id is null,0,_max_id);
set _col_sep = ",";
set _row_sep = ";";
set _row_sep_length = length(_row_sep);
parse_loop: loop
if _future_mappings is null or length(_future_mappings) = 0 then
leave parse_loop;
end if;
set _line = substring_index(_future_mappings,_row_sep,1);
set _start_date_str = substring_index(substring_index(_line,_col_sep,1),_col_sep,-1);
set _end_date_str = substring_index(substring_index(_line,_col_sep,2),_col_sep,-1);
set _profile_id_str = substring_index(substring_index(_line,_col_sep,3),_col_sep,-1);
set _network_id_str = substring_index(substring_index(_line,_col_sep,4),_col_sep,-1);
set _last_str = substring_index(substring_index(_line,_col_sep,5),_col_sep,-1);
if length(_start_date_str) > 0 and dayname(_start_date_str) is null then
signal sqlstate "45001" set message_text = "invalid start date";
end if;
if length(_end_date_str) > 0 and dayname(_end_date_str) is null then
signal sqlstate "45001" set message_text = "invalid end date";
end if;
if length(_end_date_str) > 0 and length(_start_date_str) = 0 then
signal sqlstate "45001" set message_text = "mappings with end date but no start date are not allowed";
end if;
set _id = _id + 1;
insert into tmp_billing_mappings values(_id,_contract_id, if(length(_start_date_str) > 0,_start_date_str,null), if(length(_end_date_str) > 0,
_end_date_str,null), if(length(_profile_id_str) > 0,_profile_id_str,null), if(length(_network_id_str) > 0,_network_id_str,null),
if(length(_last_str) > 0,if(_last_str > 0,1,0),1));
set _future_mappings = insert(_future_mappings,1,length(_line) + _row_sep_length,"");
end loop parse_loop;
if _new and (select count(*) from tmp_billing_mappings where start_date is null and end_date is null and network_id is null) != 1 then
signal sqlstate "45001" set message_text = "there must be exactly one initial mapping with open start date, open end date and no network";
end if;
if not _new and (select count(*) from tmp_billing_mappings where start_date is null and end_date is null and id > _max_id) > 0 then
signal sqlstate "45001" set message_text = "adding mappings with open start date and open end date is not allowed";
end if;
drop temporary table if exists tmp_billing_mappings_clone;
create temporary table tmp_billing_mappings_clone
(index (id), index (contract_id,start_date,end_date)) engine = memory select * from tmp_billing_mappings;
if not _new then
delete from billing.contracts_billing_profile_network where contract_id = _contract_id;
end if;
nested1: begin
declare _events_done, _mappings_done, _is_end boolean default false;
declare _t datetime;
declare _old_bm_ids varchar(65535);
declare events_cur cursor for select t,is_end from (
(select coalesce(bm.start_date,from_unixtime(0)) as t, 0 as is_end
from tmp_billing_mappings bm join contracts c on bm.contract_id = c.id where contract_id = _contract_id)
union all
(select coalesce(end_date,from_unixtime(2147483647) - 0.001) as t, 1 as is_end from tmp_billing_mappings_clone where contract_id = _contract_id)
) as events group by t, is_end order by t, is_end;
declare continue handler for not found set _events_done = true;
set _old_bm_ids = "";
set _events_done = false;
open events_cur;
events_loop: loop
fetch events_cur into _t, _is_end;
if _events_done then
leave events_loop;
end if;
nested2: begin
declare _bm_id, _default_bm_id, _profile_id, _network_id int(11) unsigned;
declare _start_date, _end_date datetime;
declare _effective_start_time decimal(13,3);
declare _bm_ids varchar(65535);
declare mappings_cur cursor for select bm1.id, bm1.start_date, bm1.end_date, bm1.billing_profile_id, bm1.network_id from
tmp_billing_mappings bm1 where bm1.contract_id = _contract_id and bm1.start_date <=> (select bm2.start_date
from tmp_billing_mappings_clone bm2 where
bm2.contract_id = _contract_id
and (bm2.start_date <= _t or bm2.start_date is null)
and (if(_is_end,bm2.end_date > _t,bm2.end_date >= _t) or bm2.end_date is null)
order by bm2.start_date desc limit 1) order by bm1.base asc, bm1.id asc;
declare continue handler for not found set _mappings_done = true;
set _effective_start_time = (select unix_timestamp(if(_is_end,_t + 0.001,_t)));
set _bm_ids = "";
set _mappings_done = false;
open mappings_cur;
mappings_loop1: loop
fetch mappings_cur into _bm_id, _start_date, _end_date, _profile_id, _network_id;
if _mappings_done then
leave mappings_loop1;
end if;
set _bm_ids = (select concat(_bm_ids,"-",_bm_id));
set _default_bm_id = _bm_id;
end loop mappings_loop1;
close mappings_cur;
if _old_bm_ids != _bm_ids then
set _mappings_done = false;
open mappings_cur;
mappings_loop2: loop
fetch mappings_cur into _bm_id, _start_date, _end_date, _profile_id, _network_id;
if _mappings_done then
leave mappings_loop2;
end if;
call billing.add_contract_billing_profile_network_schedule(_contract_id,if(_bm_id = _default_bm_id,1,0),_start_date,_end_date,
_effective_start_time,_profile_id,_network_id);
end loop mappings_loop2;
close mappings_cur;
end if;
set _old_bm_ids = _bm_ids;
end nested2;
end loop events_loop;
close events_cur;
end nested1;
drop temporary table tmp_billing_mappings;
drop temporary table tmp_billing_mappings_clone;
end;;
delimiter ;

@ -0,0 +1,96 @@
use billing;
delimiter ;;
create procedure transform_billing_mappings() begin
declare _contracts_done, _events_done, _mappings_done, _is_end boolean default false;
declare _contract_id, _bm_id, _default_bm_id, _profile_id, _network_id int(11) unsigned;
declare _t, _start_date, _end_date datetime;
declare _effective_start_time decimal(13,3);
declare _bm_ids, _old_bm_ids varchar(65535);
declare contracts_cur cursor for select bm.contract_id
from billing_mappings bm left join contracts_billing_profile_network cbpn on bm.contract_id = cbpn.contract_id
where cbpn.id is null group by bm.contract_id;
declare continue handler for not found set _contracts_done = true;
set _old_bm_ids = "";
open contracts_cur;
contracts_loop: loop
fetch contracts_cur into _contract_id;
if _contracts_done then
leave contracts_loop;
end if;
nested1: begin
declare events_cur cursor for select t,is_end from (
(select coalesce(bm.start_date,from_unixtime(0)) as t, 0 as is_end
from billing_mappings bm join contracts c on bm.contract_id = c.id where contract_id = _contract_id)
union all
(select coalesce(end_date,from_unixtime(2147483647) - 0.001) as t, 1 as is_end from billing_mappings where contract_id = _contract_id)
) as events group by t, is_end order by t, is_end;
declare continue handler for not found set _events_done = true;
set _events_done = false;
open events_cur;
events_loop: loop
fetch events_cur into _t, _is_end;
if _events_done then
leave events_loop;
end if;
nested2: begin
declare mappings_cur cursor for select bm1.id, bm1.start_date, bm1.end_date, bm1.billing_profile_id, bm1.network_id from
billing_mappings bm1 where bm1.contract_id = _contract_id and bm1.start_date <=> (select bm2.start_date
from billing_mappings bm2 where
bm2.contract_id = _contract_id
and (bm2.start_date <= _t or bm2.start_date is null)
and (if(_is_end,bm2.end_date > _t,bm2.end_date >= _t) or bm2.end_date is null)
order by bm2.start_date desc limit 1) order by bm1.id asc;
declare continue handler for not found set _mappings_done = true;
set _effective_start_time = (select unix_timestamp(if(_is_end,_t + 0.001,_t)));
set _bm_ids = "";
set _mappings_done = false;
open mappings_cur;
mappings_loop1: loop
fetch mappings_cur into _bm_id, _start_date, _end_date, _profile_id, _network_id;
if _mappings_done then
leave mappings_loop1;
end if;
set _bm_ids = (select concat(_bm_ids,"-",_bm_id));
set _default_bm_id = _bm_id;
end loop mappings_loop1;
close mappings_cur;
if _old_bm_ids != _bm_ids then
set _mappings_done = false;
open mappings_cur;
mappings_loop2: loop
fetch mappings_cur into _bm_id, _start_date, _end_date, _profile_id, _network_id;
if _mappings_done then
leave mappings_loop2;
end if;
call add_contract_billing_profile_network_schedule(_contract_id,if(_bm_id = _default_bm_id,1,0),_start_date,_end_date,
_effective_start_time,_profile_id,_network_id);
end loop mappings_loop2;
close mappings_cur;
end if;
set _old_bm_ids = _bm_ids;
end nested2;
end loop events_loop;
close events_cur;
end nested1;
end loop contracts_loop;
close contracts_cur;
end;;
delimiter ;
start transaction;
call transform_billing_mappings();
commit;

@ -0,0 +1,149 @@
use billing;
delimiter ;;
create procedure create_contract_billing_profile_network_from_package(
in _contract_id int(11) unsigned,
in _start int(13) unsigned,
in _package_id int(11) unsigned,
in _package_profile_set varchar(32)
)
begin
call billing.schedule_contract_billing_profile_network(_contract_id,null,(select group_concat(concat(from_unixtime(_start),",,",profile_id,",",
if(network_id is null,"",network_id),",") order by id separator ";") from billing.package_profile_sets
where package_id = _package_id and discriminator = _package_profile_set));
end;;
create function get_billing_profile_by_contract_id(
_contract_id int(11),
_epoch decimal(13,3)
) returns int(11)
reads sql data
begin
declare _effective_start_date decimal(13,3);
declare _cbpn_id,_profile_id int(11);
if _contract_id is null or _epoch is null then
return null;
end if;
set _effective_start_date = (select max(cbpns.effective_start_time) from billing.contracts_billing_profile_network_schedule cbpns join
billing.contracts_billing_profile_network cbpn on cbpn.id = cbpns.profile_network_id
where cbpn.contract_id = _contract_id and cbpns.effective_start_time <= _epoch and cbpn.base = 1);
if _effective_start_date is null then
set _cbpn_id = (select min(id) from billing.contracts_billing_profile_network cbpn
where cbpn.contract_id = _contract_id and cbpn.base = 1);
else
set _cbpn_id = (select cbpn.id from billing.contracts_billing_profile_network_schedule cbpns join
billing.contracts_billing_profile_network cbpn on cbpn.id = cbpns.profile_network_id
where cbpn.contract_id = _contract_id and cbpns.effective_start_time = _effective_start_date and cbpn.base = 1);
end if;
set _profile_id = (select billing_profile_id from billing.contracts_billing_profile_network where id = _cbpn_id);
return _profile_id;
end;;
create function get_billing_profile_by_contract_id_network(
_contract_id int(11),
_epoch decimal(13,3),
_ip varchar(46)
) returns int(11)
reads sql data
begin
declare _effective_start_date decimal(13,3);
declare _cbpn_id,_profile_id int(11);
declare _network_bytes varbinary(16);
declare _is_valid_ip,_is_ipv6 boolean default false;
if _contract_id is null or _epoch is null then
return null;
end if;
set _network_bytes = inet6_aton(_ip);
set _is_valid_ip = if(_network_bytes is null or hex(_network_bytes) = "00000000",0,1);
set _is_ipv6 = if(locate(".",_ip) = 0,1,0);
set _effective_start_date = (select max(cbpns.effective_start_time) from billing.contracts_billing_profile_network_schedule cbpns join
billing.contracts_billing_profile_network cbpn on cbpn.id = cbpns.profile_network_id
left join billing.billing_networks bn on cbpn.billing_network_id = bn.id
left join billing.billing_network_blocks bnb on bn.id = bnb.network_id
where cbpn.contract_id = _contract_id and cbpns.effective_start_time <= _epoch
and ((_is_valid_ip and if(_is_ipv6,bnb._ipv6_net_from <= _network_bytes and bnb._ipv6_net_to >= _network_bytes,
bnb._ipv4_net_from <= _network_bytes and bnb._ipv4_net_to >= _network_bytes)) or cbpn.billing_network_id is null));
if _effective_start_date is null then
return null;
else
set _cbpn_id = (select cbpn.id from billing.contracts_billing_profile_network_schedule cbpns join
billing.contracts_billing_profile_network cbpn on cbpn.id = cbpns.profile_network_id
left join billing.billing_networks bn on cbpn.billing_network_id = bn.id
left join billing.billing_network_blocks bnb on bn.id = bnb.network_id
where cbpn.contract_id = _contract_id and cbpns.effective_start_time = _effective_start_date
and ((_is_valid_ip and if(_is_ipv6,bnb._ipv6_net_from <= _network_bytes and bnb._ipv6_net_to >= _network_bytes,
bnb._ipv4_net_from <= _network_bytes and bnb._ipv4_net_to >= _network_bytes)) or cbpn.billing_network_id is null)
order by cbpn.billing_network_id desc limit 1);
end if;
set _profile_id = (select billing_profile_id from billing.contracts_billing_profile_network where id = _cbpn_id);
return _profile_id;
end;;
create function get_billing_profile_by_uuid(
_uuid varchar(36),
_epoch decimal(13,3)
) returns int(11)
reads sql data
begin
return billing.get_billing_profile_by_contract_id((select account_id from provisioning.voip_subscribers where uuid = _uuid),_epoch);
end;;
create function get_billing_profile_by_uuid_network(
_uuid varchar(36),
_epoch decimal(13,3),
_ip varchar(46)
) returns int(11)
reads sql data
begin
return billing.get_billing_profile_by_contract_id_network((select account_id from provisioning.voip_subscribers where uuid = _uuid),
_epoch,_ip);
end;;
create function get_billing_profile_by_peer_host_id(
_peer_host_id int(11),
_epoch decimal(13,3)
) returns int(11)
reads sql data
begin
return billing.get_billing_profile_by_contract_id((select pg.peering_contract_id from provisioning.voip_peer_hosts ph join
provisioning.voip_peer_groups pg on pg.id = ph.group_id where ph.id = _peer_host_id),_epoch);
end;;
create function get_billing_profile_by_peer_host_id_network(
_peer_host_id int(11),
_epoch decimal(13,3),
_ip varchar(46)
) returns int(11)
reads sql data
begin
return billing.get_billing_profile_by_contract_id_network((select pg.peering_contract_id from provisioning.voip_peer_hosts ph join
provisioning.voip_peer_groups pg on pg.id = ph.group_id where ph.id = _peer_host_id),_epoch,_ip);
end;;
delimiter ;

@ -0,0 +1,36 @@
use billing;
create view _v_actual_effective_start_time as select
cbpn.contract_id as contract_id,
max(cbpns.effective_start_time) as effective_start_time
from billing.contracts_billing_profile_network_schedule cbpns
join billing.contracts_billing_profile_network cbpn on cbpns.profile_network_id = cbpn.id
where cbpns.effective_start_time <= unix_timestamp(now()) and cbpn.base = 1
group by cbpn.contract_id;
create or replace view v_actual_billing_profiles as select
est.contract_id as contract_id,
cbpn.billing_profile_id as billing_profile_id
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
where cbpn.base = 1;
create view v_contract_billing_profile_network_schedules as select
cbpns.id,
contract_id,
start_date,
end_date,
billing_profile_id as billing_profile_id,
billing_network_id as network_id,
effective_start_time,
from_unixtime(effective_start_time) as effective_start_date,
bp.name as billing_profile_name,
bp.handle as billing_profile_handle,
bn.name as billing_network_name
from
billing.contracts_billing_profile_network cbpn
join billing.contracts_billing_profile_network_schedule cbpns on cbpns.profile_network_id = cbpn.id
join billing.billing_profiles bp on bp.id = cbpn.billing_profile_id
left join billing.billing_networks bn on bn.id = cbpn.billing_network_id;
Loading…
Cancel
Save