Too many refactors in one:

- Allowed adding ephemeral(ish) views and functions
- Moved message_count to a concrete database field
- Moved most proxy logic to a stored procedure
- Moved database files around and refactored schema manager
This commit is contained in:
Ske
2020-06-12 20:29:50 +02:00
parent 24f1363bb0
commit ba441a15cc
37 changed files with 554 additions and 398 deletions

View File

@@ -0,0 +1,112 @@
-- SCHEMA VERSION 0, 2019-12-26
-- "initial version", considered a "starting point" for the migrations
-- also the assumed database layout of someone either migrating from an older version of PK or starting a new instance,
-- so everything here *should* be idempotent given a schema version older than this or nonexistent.
-- Create proxy_tag compound type if it doesn't exist
do $$ begin
create type proxy_tag as (
prefix text,
suffix text
);
exception when duplicate_object then null;
end $$;
create table if not exists systems
(
id serial primary key,
hid char(5) unique not null,
name text,
description text,
tag text,
avatar_url text,
token text,
created timestamp not null default (current_timestamp at time zone 'utc'),
ui_tz text not null default 'UTC'
);
create table if not exists system_guild
(
system serial not null references systems (id) on delete cascade,
guild bigint not null,
proxy_enabled bool not null default true,
primary key (system, guild)
);
create table if not exists members
(
id serial primary key,
hid char(5) unique not null,
system serial not null references systems (id) on delete cascade,
color char(6),
avatar_url text,
name text not null,
display_name text,
birthday date,
pronouns text,
description text,
proxy_tags proxy_tag[] not null default array[]::proxy_tag[], -- Rationale on making this an array rather than a separate table - we never need to query them individually, only access them as part of a selected Member struct
keep_proxy bool not null default false,
created timestamp not null default (current_timestamp at time zone 'utc')
);
create table if not exists member_guild
(
member serial not null references members (id) on delete cascade,
guild bigint not null,
display_name text default null,
primary key (member, guild)
);
create table if not exists accounts
(
uid bigint primary key,
system serial not null references systems (id) on delete cascade
);
create table if not exists messages
(
mid bigint primary key,
channel bigint not null,
member serial not null references members (id) on delete cascade,
sender bigint not null,
original_mid bigint
);
create table if not exists switches
(
id serial primary key,
system serial not null references systems (id) on delete cascade,
timestamp timestamp not null default (current_timestamp at time zone 'utc')
);
create table if not exists switch_members
(
id serial primary key,
switch serial not null references switches (id) on delete cascade,
member serial not null references members (id) on delete cascade
);
create table if not exists webhooks
(
channel bigint primary key,
webhook bigint not null,
token text not null
);
create table if not exists servers
(
id bigint primary key,
log_channel bigint,
log_blacklist bigint[] not null default array[]::bigint[],
blacklist bigint[] not null default array[]::bigint[]
);
create index if not exists idx_switches_system on switches using btree (system asc nulls last) include ("timestamp");
create index if not exists idx_switch_members_switch on switch_members using btree (switch asc nulls last) include (member);
create index if not exists idx_message_member on messages (member);

View File

@@ -0,0 +1,15 @@
-- SCHEMA VERSION 1: 2019-12-26
-- First version introducing the migration system, therefore we add the info/version table
create table info
(
id int primary key not null default 1, -- enforced only equal to 1
schema_version int,
constraint singleton check (id = 1) -- enforce singleton table/row
);
-- We do an insert here since we *just* added the table
-- Future migrations should do an update at the end
insert into info (schema_version) values (1);

View File

@@ -0,0 +1,13 @@
-- We're doing a psuedo-enum here since Dapper is wonky with enums
-- Still getting mapped to enums at the CLR level, though.
-- https://github.com/StackExchange/Dapper/issues/332 (from 2015, still unsolved!)
-- 1 = "public"
-- 2 = "private"
-- not doing a bool here since I want to open up for the possibliity of other privacy levels (eg. "mutuals only")
alter table systems add column description_privacy integer check (description_privacy in (1, 2)) not null default 1;
alter table systems add column member_list_privacy integer check (member_list_privacy in (1, 2)) not null default 1;
alter table systems add column front_privacy integer check (front_privacy in (1, 2)) not null default 1;
alter table systems add column front_history_privacy integer check (front_history_privacy in (1, 2)) not null default 1;
alter table members add column member_privacy integer check (member_privacy in (1, 2)) not null default 1;
update info set schema_version = 2;

View File

@@ -0,0 +1,15 @@
-- Same sort of psuedo-enum due to Dapper limitations. See 2.sql.
-- 1 = autoproxy off
-- 2 = front mode (first fronter)
-- 3 = latch mode (last proxyer)
-- 4 = member mode (specific member)
alter table system_guild add column autoproxy_mode int check (autoproxy_mode in (1, 2, 3, 4)) not null default 1;
-- for member mode
alter table system_guild add column autoproxy_member int references members (id) on delete set null;
-- for latch mode
-- not *really* nullable, null just means old (pre-schema-change) data.
alter table messages add column guild bigint default null;
update info set schema_version = 3;

View File

@@ -0,0 +1,3 @@
-- SCHEMA VERSION 4: 2020-02-12
alter table member_guild add column avatar_url text;
update info set schema_version = 4;

View File

@@ -0,0 +1,3 @@
-- SCHEMA VERSION 5: 2020-02-14
alter table servers add column log_cleanup_enabled bool not null default false;
update info set schema_version = 5;

View File

@@ -0,0 +1,3 @@
-- SCHEMA VERSION 6: 2020-03-21
alter table systems add column pings_enabled bool not null default true;
update info set schema_version = 6;

View File

@@ -0,0 +1,33 @@
-- SCHEMA VERSION 7: 2020-06-12
-- (in-db message count row)
-- Add message count row to members table, initialize it with the correct data
alter table members add column message_count int not null default 0;
update members set message_count = (select count(*) from messages where messages.member = members.id);
-- Create a trigger function to increment the message count on inserting to the messages table
create function trg_msgcount_increment() returns trigger as $$
begin
update members set message_count = message_count + 1 where id = NEW.member;
return NEW;
end;
$$ language plpgsql;
create trigger increment_member_message_count before insert on messages for each row execute procedure trg_msgcount_increment();
-- Create a trigger function to decrement the message count on deleting from the messages table
create function trg_msgcount_decrement() returns trigger as $$
begin
-- Don't decrement if count <= zero (shouldn't happen, but we don't want negative message counts)
update members set message_count = message_count - 1 where id = OLD.member and message_count > 0;
return OLD;
end;
$$ language plpgsql;
create trigger decrement_member_message_count before delete on messages for each row execute procedure trg_msgcount_decrement();
-- (update schema ver)
update info set schema_version = 7;