dim/schema/01_initial.sql

187 lines
7.4 KiB
PL/PgSQL

create table if not exists layer3domains(
id serial not null primary key,
name varchar(128) not null unique,
attributes jsonb not null default '{}',
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
);
create table if not exists pools(
id serial not null,
layer3domain_id integer not null references layer3domains(id),
name varchar(128) unique,
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,
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,
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)
);
create index if not exists container_reference_key on containers(layer3domain_id, pool_id, network);
create table if not exists ips(
layer3domain_id integer not null,
version smallint not null,
address inet not null,
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,
unique(layer3domain_id, version, address)
);
create table if not exists zones(
id serial not null primary key,
name varchar not null unique,
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
);
create table if not exists zoneviews(
id serial not null primary key,
zone_id integer not null references zones(id),
name varchar not null,
serial bigint not null default 0,
ttl integer not null default 3600,
primary_name_server varchar not null,
mail varchar not null,
refresh integer not null default 10800,
retry integer not null default 900,
expire integer not null default 604800,
minimum bigint not null default 86400,
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
);
create index if not exists zoneviews_reference_key on zoneviews(zone_id, id);
create table if not exists records(
zoneview_id integer not null references zoneviews(id) on delete cascade,
name varchar(254) not null,
type varchar(11) not null,
ttl integer,
value text not null,
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,
unique(zoneview_id, name, type, value)
);
create table if not exists outputgroups(
id serial not null primary key,
name varchar(128) not null unique,
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
);
create table if not exists zoneviews_outputgroups(
outputgroup_id integer not null references outputgroups(id),
zoneview_id integer not null references zoneviews(id),
unique(outputgroup_id, zoneview_id)
);
create table if not exists outputs(
id serial not null primary key,
name varchar(128) not null unique,
plugin varchar(20) not null,
db_uri varchar(250) not null,
status varchar(250) not null,
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
);
create table if not exists outputgroup_outputs(
outputgroups_id integer not null references outputgroups(id),
output_id integer not null references outputs(id),
unique(outputgroups_id, output_id)
);
-- create history functionality
create table if not exists history(
transaction text not null,
created_at timestamptz not null default now(),
created_by text not null,
type text not null,
action text not null,
old_entity jsonb default '{}',
new_entity jsonb default '{}'
);
comment on table history is 'History is the log of all changes happening in DIM.';
comment on column history.transaction is 'The transaction ID is the same for all changes originating in the same request.';
comment on column history.created_by is 'The username is not a foreign key to keep the history around';
comment on column history.type is 'Type represents the table that originated the change.';
comment on column history.action is 'The action can be one of insert, update or delete.';
create or replace function record() returns trigger as $$
begin
insert into history(transaction, created_by, type, action, old_entity, new_entity)
values (
current_setting('dim.transaction'),
current_setting('dim.username'),
TG_TABLE_NAME, TG_OP,
row_to_json(OLD),
row_to_json(NEW)
);
if TG_OP = 'DELETE' then
return OLD;
else
return NEW;
end if;
end;$$ language plpgsql;
-- drop existing triggers
drop trigger if exists trg_containers on containers;
drop trigger if exists trg_ips on ips;
drop trigger if exists trg_layer3domains on layer3domains;
drop trigger if exists trg_outputgroup_outputs on outputgroup_outputs;
drop trigger if exists trg_outputgroups on outputgroups;
drop trigger if exists trg_outputs on outputs;
drop trigger if exists trg_pools on pools;
drop trigger if exists trg_records on records;
drop trigger if exists trg_zones on zones;
drop trigger if exists trg_zoneviews on zoneviews;
drop trigger if exists trg_zoneviews_outputgroups on zoneviews_outputgroups;
-- recreate history triggers
create trigger trg_containers before insert or update or delete on containers for each row execute function record();
create trigger trg_ips before insert or update or delete on ips for each row execute function record();
create trigger trg_layer3domains before insert or update or delete on layer3domains for each row execute function record();
create trigger trg_outputgroup_outputs before insert or update or delete on outputgroup_outputs for each row execute function record();
create trigger trg_outputgroups before insert or update or delete on outputgroups for each row execute function record();
create trigger trg_outputs before insert or update or delete on outputs for each row execute function record();
create trigger trg_pools before insert or update or delete on pools for each row execute function record();
create trigger trg_records before insert or update or delete on records for each row execute function record();
create trigger trg_zones before insert or update or delete on zones for each row execute function record();
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();