TT#41552 TT#41556 billing fees "match mode"

+ add "match_mode" column
+ refactor indexes, triggers, copy proc
+ get_billing_fee_id proc implementing the 4 match modes:
  - regex_longest_pattern
  - regex_longest_match
  - prefix
  - exact_destination
+ get_billing_fee proc returning intervals/rates as a
  packed string for matching call-out fees and on/offpeak
  for the given time. to be used in kamailio/AoC

Change-Id: I7799c5a1ab33bb433c231bd4049c977bcb19b684
changes/70/22970/11
Rene Krenn 7 years ago
parent 676ded265b
commit 700d098232

@ -0,0 +1,60 @@
use billing;
alter table billing_fees
drop index bf_srcdestdir_idx,
drop index bf_destsrcdir_idx,
drop column match_mode,
add key profsrcdesdirtype_idx (billing_profile_id, source, destination, direction, type),
add constraint billing_fees_unique unique (billing_profile_id, source, destination, direction, type);
alter table billing_fees_history
drop index bfh_srcdestdir_idx,
drop index bfh_destsrcdir_idx,
drop column match_mode,
add key bfhsems_idx (billing_profile_id, bf_id, type, destination);
drop trigger billing.bill_fees_crepl_trig;
drop trigger billing.bill_fees_urepl_trig;
delimiter ;;
create trigger billing.bill_fees_crepl_trig after insert on billing_fees
for each row
begin
declare my_bzh_id int unsigned;
select id into my_bzh_id from billing.billing_zones_history where bz_id = NEW.billing_zone_id;
insert into billing.billing_fees_history
values(NULL, NEW.id, NEW.billing_profile_id, my_bzh_id,
NEW.source, NEW.destination, NEW.direction,
NEW.type, NEW.onpeak_init_rate, NEW.onpeak_init_interval, NEW.onpeak_follow_rate,
NEW.onpeak_follow_interval, NEW.offpeak_init_rate, NEW.offpeak_init_interval,
NEW.offpeak_follow_rate, NEW.offpeak_follow_interval, NEW.use_free_time);
end;
;;
create trigger billing.bill_fees_urepl_trig after update on billing_fees
for each row
begin
declare my_bzh_id int unsigned;
select id into my_bzh_id from billing.billing_zones_history where bz_id = NEW.billing_zone_id;
update billing.billing_fees_history
set bf_id = NEW.id, billing_profile_id = NEW.billing_profile_id,
billing_zones_history_id = my_bzh_id,
source = NEW.source, destination = NEW.destination, direction = NEW.direction,
type = NEW.type,
onpeak_init_rate = NEW.onpeak_init_rate, onpeak_init_interval = NEW.onpeak_init_interval,
onpeak_follow_rate = NEW.onpeak_follow_rate, onpeak_follow_interval = NEW.onpeak_follow_interval,
offpeak_init_rate = NEW.offpeak_init_rate, offpeak_init_interval = NEW.offpeak_init_interval,
offpeak_follow_rate = NEW.offpeak_follow_rate, offpeak_follow_interval = NEW.offpeak_follow_interval,
use_free_time = NEW.use_free_time
where bf_id = OLD.id;
end;
;;
delimiter ;

@ -0,0 +1,109 @@
use billing;
alter table billing_fees_history
drop index bfhsems_idx,
add column match_mode enum('regex_longest_pattern', 'regex_longest_match', 'prefix', 'exact_destination') not null default 'regex_longest_pattern',
add key bfh_srcdestdir_idx (billing_profile_id, type, match_mode, direction, bf_id, source, destination),
add key bfh_destsrcdir_idx (billing_profile_id, type, match_mode, destination, bf_id, source, direction);
alter table billing_fees
drop index billing_fees_unique,
drop index profsrcdesdirtype_idx,
add column match_mode enum('regex_longest_pattern', 'regex_longest_match', 'prefix', 'exact_destination') not null default 'regex_longest_pattern',
add unique key bf_srcdestdir_idx (billing_profile_id, type, match_mode, direction, source, destination),
add key bf_destsrcdir_idx (billing_profile_id, type, match_mode, destination, source, direction);
alter table billing_fees_raw
drop index profsrcdesdirtype_idx,
add column match_mode enum('regex_longest_pattern', 'regex_longest_match', 'prefix', 'exact_destination') not null default 'regex_longest_pattern',
add unique key bfr_srcdestdir_idx (billing_profile_id, type, match_mode, direction, source, destination),
add key bfr_destsrcdir_idx (billing_profile_id, type, match_mode, destination, source, direction);
drop trigger billing.bill_fees_crepl_trig;
drop trigger billing.bill_fees_urepl_trig;
update billing_fees set match_mode = "exact_destination" where destination like "lnp:%";
update billing_fees_raw set match_mode = "exact_destination" where destination like "lnp:%";
update billing_fees_history set match_mode = "exact_destination" where destination like "lnp:%";
delimiter ;;
create trigger billing.bill_fees_crepl_trig after insert on billing_fees
for each row
begin
declare my_bzh_id int unsigned;
select id into my_bzh_id from billing.billing_zones_history where bz_id = NEW.billing_zone_id;
insert into billing.billing_fees_history
values(NULL, NEW.id, NEW.billing_profile_id, my_bzh_id,
NEW.source, NEW.destination, NEW.direction,
NEW.type, NEW.onpeak_init_rate, NEW.onpeak_init_interval, NEW.onpeak_follow_rate,
NEW.onpeak_follow_interval, NEW.offpeak_init_rate, NEW.offpeak_init_interval,
NEW.offpeak_follow_rate, NEW.offpeak_follow_interval, NEW.use_free_time, NEW.match_mode);
end;
;;
create trigger billing.bill_fees_urepl_trig after update on billing_fees
for each row
begin
declare my_bzh_id int unsigned;
select id into my_bzh_id from billing.billing_zones_history where bz_id = NEW.billing_zone_id;
update billing.billing_fees_history
set bf_id = NEW.id, billing_profile_id = NEW.billing_profile_id,
billing_zones_history_id = my_bzh_id,
source = NEW.source, destination = NEW.destination, direction = NEW.direction,
type = NEW.type,
onpeak_init_rate = NEW.onpeak_init_rate, onpeak_init_interval = NEW.onpeak_init_interval,
onpeak_follow_rate = NEW.onpeak_follow_rate, onpeak_follow_interval = NEW.onpeak_follow_interval,
offpeak_init_rate = NEW.offpeak_init_rate, offpeak_init_interval = NEW.offpeak_init_interval,
offpeak_follow_rate = NEW.offpeak_follow_rate, offpeak_follow_interval = NEW.offpeak_follow_interval,
use_free_time = NEW.use_free_time, match_mode = NEW.match_mode
where bf_id = OLD.id;
end;
;;
create or replace procedure fill_billing_fees(in in_profile_id int)
begin
declare columns varchar(1023);
declare statement varchar(1023);
set @profile_id = in_profile_id;
select group_concat(column_name) into columns from information_schema.columns where table_schema = database() and table_name = "billing_fees_raw" and column_name not in ("id");
set @statement = concat("insert into billing.billing_fees(id,",columns,")
select min_id,",columns,"
from billing.billing_fees_raw bnu
inner join (
select min(i_nu.id) min_id
from billing.billing_fees_raw i_nu
left join billing.billing_fees i_u
on i_nu.billing_profile_id=i_u.billing_profile_id
and i_nu.type=i_u.type
and i_nu.match_mode=i_u.match_mode
and i_nu.direction=i_u.direction
and i_nu.source=i_u.source
and i_nu.destination=i_u.destination
where i_u.id is null ",
if( @profile_id is not null, " and i_nu.billing_profile_id = ? ", " and 1 = ? "),
" group by i_nu.billing_profile_id,i_nu.type,i_nu.match_mode,i_nu.direction,i_nu.source,i_nu.destination
) u on bnu.id=u.min_id");
if @profile_id is null then
set @profile_id = 1;
end if;
prepare stmt from @statement;
execute stmt using @profile_id;
deallocate prepare stmt;
end;
;;
delimiter ;

@ -0,0 +1,138 @@
use billing;
delimiter ;;
create function get_billing_fee_id(
_billing_profile_id int(11),
_type enum('call','sms'),
_direction enum('in','out'),
_source varchar(511),
_destination varchar(511),
_match_mode enum('regex_longest_pattern', 'regex_longest_match', 'prefix', 'exact_destination')
) returns int(11)
reads sql data
begin
declare _destination_prefix,_source_prefix varchar(511);
declare _i, _j int(3) unsigned;
declare _fee_id int(11);
if _fee_id is null and (_match_mode is null or _match_mode = "exact_destination")
and (select id from billing.billing_fees_history where
billing_profile_id = _billing_profile_id
and type = _type
and match_mode = "exact_destination"
and direction = _direction
and bf_id is not null
limit 1) is not null then
set _fee_id = (select id from billing.billing_fee_history where
billing_profile_id = _billing_profile_id
and type = _type
and match_mode = "exact_destination"
and direction = _direction
and bf_id is not null
and destination = _destination
limit 1);
end if;
if _fee_id is null and (_match_mode is null or _match_mode = "prefix")
and (select id from billing.billing_fees_history where
billing_profile_id = _billing_profile_id
and type = _type
and match_mode = "prefix"
and direction = _direction
and bf_id is not null
limit 1) is not null then
set _j = length(_destination);
destination_loop: loop
if _j < 0 or _fee_id is not null then
leave destination_loop;
end if;
set _destination_prefix = substr(coalesce(_destination,""),1,_j);
if (select id from billing.billing_fees_history where
billing_profile_id = _billing_profile_id
and type = _type
and match_mode = "prefix"
and direction = _direction
and bf_id is not null
and destination = _destination_prefix
limit 1) is not null then
set _i = length(_source);
source_loop: loop
if _i < 0 or _fee_id is not null then
leave source_loop;
end if;
set _source_prefix = substr(coalesce(_source,""),1,_i);
set _fee_id = (select id from billing.billing_fees_history where
billing_profile_id = _billing_profile_id
and type = _type
and match_mode = "prefix"
and direction = _direction
and bf_id is not null
and source = _source_prefix
and destination = _destination_prefix
limit 1);
set _i = _i - 1;
end loop source_loop;
end if;
set _j = _j - 1;
end loop destination_loop;
end if;
if _fee_id is null and (_match_mode is null or _match_mode = "regex_longest_match")
and (select id from billing.billing_fees_history where
billing_profile_id = _billing_profile_id
and type = _type
and match_mode = "regex_longest_match"
and direction = _direction
and bf_id is not null
limit 1) is not null then
set _fee_id = (select id from billing.billing_fees_history where
billing_profile_id = _billing_profile_id
and type = _type
and match_mode = "regex_longest_match"
and direction = _direction
and bf_id is not null
and _source regexp(source)
and _destination regexp(destination)
order by
length(regexp_substr(_destination,destination)) desc,
length(regexp_substr(_source,source)) desc limit 1);
end if;
if _fee_id is null and (_match_mode is null or _match_mode = "regex_longest_pattern")
and (select id from billing.billing_fees_history where
billing_profile_id = _billing_profile_id
and type = _type
and match_mode = "regex_longest_pattern"
and direction = _direction
and bf_id is not null
limit 1) is not null then
set _fee_id = (select id from billing.billing_fees_history where
billing_profile_id = _billing_profile_id
and type = _type
and match_mode = "regex_longest_pattern"
and direction = _direction
and bf_id is not null
and _source regexp(source)
and _destination regexp(destination)
order by
length(destination) desc,
length(source) desc limit 1);
end if;
return _fee_id;
end;;
delimiter ;

@ -0,0 +1,109 @@
use billing;
delimiter ;;
create function check_billing_fee_offpeak(
_billing_profile_id int(11),
_t decimal(13,3),
_contract_id int(11)
) returns boolean
reads sql data
begin
declare _call_start, _call_end decimal(13,3);
declare _is_offpeak boolean;
set _call_start = _t;
set _call_end = _t;
set _is_offpeak = (select coalesce((select 1 from (
select
unix_timestamp(
if(_contract_id is null,
concat(date_enum.d," ",pw.start),
convert_tz(concat(date_enum.d," ",pw.start),
@@session.time_zone,
(select coalesce((select tz.name FROM billing.v_contract_timezone tz WHERE tz.contract_id = _contract_id LIMIT 1),@@session.time_zone))
)
)
) as start,
unix_timestamp(
if(_contract_id is null,
concat(date_enum.d," ",pw.end),
convert_tz(concat(date_enum.d," ",pw.end),
@@session.time_zone,
(select coalesce((select tz.name FROM billing.v_contract_timezone tz WHERE tz.contract_id = _contract_id LIMIT 1),@@session.time_zone))
)
)
) as end
from
ngcp.date_range_helper as date_enum
join billing.billing_peaktime_weekdays pw on pw.weekday=weekday(date_enum.d)
where
pw.billing_profile_id = _billing_profile_id
and date_enum.d >= date(from_unixtime(_call_start))
and date_enum.d <= date(from_unixtime(_call_end))
) as offpeaks where offpeaks.start <= _t and offpeaks.end >= _t limit 1),0));
if _is_offpeak != 1 then
set _is_offpeak = (select coalesce((select 1 from (
select
unix_timestamp(
if(_contract_id is null,
ps.start,
convert_tz(ps.start,
@@session.time_zone,
(select coalesce((select tz.name FROM billing.v_contract_timezone tz WHERE tz.contract_id = _contract_id LIMIT 1),@@session.time_zone))
)
)
) as start,
unix_timestamp(
if(_contract_id is null,
ps.end,
convert_tz(ps.end,
@@session.time_zone,
(select coalesce((select tz.name FROM billing.v_contract_timezone tz WHERE tz.contract_id = _contract_id LIMIT 1),@@session.time_zone))
)
)
) as end
from
billing.billing_peaktime_special as ps
where
ps.billing_profile_id = _billing_profile_id
and (ps.start <= from_unixtime(_call_end) and ps.end >= from_unixtime(_call_start))
) as offpeaks where offpeaks.start <= _t and offpeaks.end >= _t limit 1),0));
end if;
return _is_offpeak;
end;;
create function get_billing_fee(
_billing_profile_id int(11),
_t decimal(13,3),
_source varchar(511),
_destination varchar(511),
_contract_id int(11)
) returns varchar(100)
reads sql data
begin
declare _fee_string varchar(100);
set _fee_string = (select concat(
if(pt.is_offpeak,bfh.offpeak_init_rate,bfh.onpeak_init_rate),":",
if(pt.is_offpeak,bfh.offpeak_init_interval,bfh.onpeak_init_interval),":",
if(pt.is_offpeak,bfh.offpeak_follow_rate,bfh.onpeak_follow_rate),":",
if(pt.is_offpeak,bfh.offpeak_follow_interval,bfh.onpeak_follow_interval)
) from
billing.billing_fees_history bfh
join (select billing.check_billing_fee_offpeak(_billing_profile_id,_t,_contract_id) as is_offpeak) pt
where
bfh.id = billing.get_billing_fee_id(_billing_profile_id,"call","out",_source,_destination,null));
return _fee_string;
end;;
delimiter ;
Loading…
Cancel
Save