add view to get container hierarchy

This commit is contained in:
Gibheer 2021-05-18 15:04:57 +02:00
parent af625344a5
commit efecc60e9c
1 changed files with 20 additions and 8 deletions

View File

@ -20,19 +20,31 @@ create table if not exists pools(
primary key(layer3domain_id, id)
);
create table if not exists containers(
layer3domain_id integer not null references layer3domains(id),
network cidr not null,
pool_id integer,
create table containers(
layer3domain_id integer not null references layer3domains(id),
subnet cidr not null,
pool_id integer,
attributes jsonb not null default '{}'::jsonb,
created_at timestamptz not null default now(),
created_by varchar(128) not null,
modified_at timestamptz not null default now(),
modified_by varchar(128) not null,
attributes jsonb not null default '{}'::jsonb,
unique(layer3domain_id, network),
foreign key (layer3domain_id, pool_id) references pools(layer3domain_id, id)
unique(layer3domain_id, subnet),
foreign key (layer3domain_id, pool_id) references pools(layer3domain_id, id)
);
create index if not exists container_reference_key on containers(layer3domain_id, pool_id, network);
create or replace view containers_tree as
select
c.layer3domain_id,
c.subnet,
array_agg(p.subnet order by p.subnet) filter (where p.subnet is not null) as parents
from containers c
left join containers p
on c.subnet << p.subnet
and c.layer3domain_id = p.layer3domain_id
group by c.layer3domain_id, c.subnet
order by c.layer3domain_id, c.subnet;
comment on view containers_tree is 'This returns a tree of all containers so that sub trees can be shown.';
create table if not exists ips(
layer3domain_id integer not null,