add function to get subnets to schema

This also adds a view to get a list of all containers and their free
space in between.
This is needed for ippool_list to get a nice overview over everything.
This commit is contained in:
Gibheer 2021-05-21 17:42:10 +02:00
parent efecc60e9c
commit 5e06ba6b61
1 changed files with 47 additions and 0 deletions

View File

@ -196,3 +196,50 @@ create trigger trg_zones before insert or update or delete on zones for each row
create trigger trg_zoneviews before insert or update or delete on zoneviews for each row execute function record();
create trigger trg_zoneviews_outputgroups before insert or update or delete on zoneviews_outputgroups for each row execute function record();
create or replace function subnets_between(net_start inet, net_end inet) returns setof cidr as $$
declare
common cidr;
mask int;
begin
net_start := host(net_start)::inet;
net_end := host(net_end)::inet;
-- check if net_start and net_end are in the same subnet
common := inet_merge(host(net_start)::inet, host(net_end)::inet);
mask := masklen(common);
if set_masklen(net_start, mask) = common and broadcast(common) = set_masklen(net_end, mask) then
return next common;
return;
end if;
-- subnet is too big, so make it smaller
return query select * from subnets_between(net_start, broadcast(set_masklen(net_start, mask + 1)));
return query select * from subnets_between(network(set_masklen(net_end, mask + 1)), net_end);
end;
$$ language plpgsql;
comment on function subnets_between(inet, inet) is 'get a list of subnets between two IPs.';
create or replace view containers_free_list as
with subnets as (
select
c.layer3domain_id,
c.subnet,
ct.subnet child,
lag(ct.subnet) over (partition by c.subnet order by ct.subnet) has_before,
lead(ct.subnet) over (partition by c.subnet order by ct.subnet) has_after,
parents
from containers c
join containers_tree ct on c.layer3domain_id = ct.layer3domain_id and c.subnet = ct.parents[array_length(ct.parents, 1)]
where host(c.subnet) != host(ct.subnet) and host(broadcast(c.subnet)) != host(broadcast(ct.subnet))
)
select * from (
select layer3domain_id, parents, 'available' state, ls as subnet
from subnets, lateral subnets_between(subnet, child - 1) ls
where has_before is null
union all
select layer3domain_id, parents, 'available', ls
from subnets, lateral subnets_between(broadcast(child) + 1, broadcast(subnet)) ls
where has_after is null
union all
select layer3domain_id, parents, 'container', subnet
from containers_tree
) freelist order by layer3domain_id, subnet;
comment on view containers_free_list is 'Creates a list of free space between other containers.';