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:
112
PluralKit.Core/Database/Migrations/0.sql
Normal file
112
PluralKit.Core/Database/Migrations/0.sql
Normal 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);
|
15
PluralKit.Core/Database/Migrations/1.sql
Normal file
15
PluralKit.Core/Database/Migrations/1.sql
Normal 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);
|
13
PluralKit.Core/Database/Migrations/2.sql
Normal file
13
PluralKit.Core/Database/Migrations/2.sql
Normal 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;
|
15
PluralKit.Core/Database/Migrations/3.sql
Normal file
15
PluralKit.Core/Database/Migrations/3.sql
Normal 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;
|
3
PluralKit.Core/Database/Migrations/4.sql
Normal file
3
PluralKit.Core/Database/Migrations/4.sql
Normal 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;
|
3
PluralKit.Core/Database/Migrations/5.sql
Normal file
3
PluralKit.Core/Database/Migrations/5.sql
Normal 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;
|
3
PluralKit.Core/Database/Migrations/6.sql
Normal file
3
PluralKit.Core/Database/Migrations/6.sql
Normal 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;
|
33
PluralKit.Core/Database/Migrations/7.sql
Normal file
33
PluralKit.Core/Database/Migrations/7.sql
Normal 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;
|
26
PluralKit.Core/Database/ProxyMember.cs
Normal file
26
PluralKit.Core/Database/ProxyMember.cs
Normal file
@@ -0,0 +1,26 @@
|
||||
#nullable enable
|
||||
using System.Collections.Generic;
|
||||
|
||||
namespace PluralKit.Core
|
||||
{
|
||||
/// <summary>
|
||||
/// Model for the `proxy_info` PL/pgSQL function in `functions.sql`
|
||||
/// </summary>
|
||||
public class ProxyMember
|
||||
{
|
||||
public int SystemId { get; set; }
|
||||
public int MemberId { get; set; }
|
||||
public bool ProxyEnabled { get; set; }
|
||||
public AutoproxyMode AutoproxyMode { get; set; }
|
||||
public bool IsAutoproxyMember { get; set; }
|
||||
public ulong? LatchMessage { get; set; }
|
||||
public string ProxyName { get; set; } = "";
|
||||
public string? ProxyAvatar { get; set; }
|
||||
public IReadOnlyCollection<ProxyTag> ProxyTags { get; set; } = new ProxyTag[0];
|
||||
public bool KeepProxy { get; set; }
|
||||
|
||||
public IReadOnlyCollection<ulong> ChannelBlacklist { get; set; } = new ulong[0];
|
||||
public IReadOnlyCollection<ulong> LogBlacklist { get; set; } = new ulong[0];
|
||||
public ulong? LogChannel { get; set; }
|
||||
}
|
||||
}
|
99
PluralKit.Core/Database/Schemas.cs
Normal file
99
PluralKit.Core/Database/Schemas.cs
Normal file
@@ -0,0 +1,99 @@
|
||||
using System;
|
||||
using System.Data;
|
||||
using System.IO;
|
||||
using System.Threading.Tasks;
|
||||
|
||||
using Dapper;
|
||||
|
||||
using Npgsql;
|
||||
|
||||
using Serilog;
|
||||
|
||||
namespace PluralKit.Core
|
||||
{
|
||||
public class Schemas
|
||||
{
|
||||
private const string RootPath = "PluralKit.Core.Database"; // "resource path" root for SQL files
|
||||
private const int TargetSchemaVersion = 7;
|
||||
|
||||
private DbConnectionFactory _conn;
|
||||
private ILogger _logger;
|
||||
|
||||
public Schemas(DbConnectionFactory conn, ILogger logger)
|
||||
{
|
||||
_conn = conn;
|
||||
_logger = logger.ForContext<Schemas>();
|
||||
}
|
||||
|
||||
public static void Initialize()
|
||||
{
|
||||
// Without these it'll still *work* but break at the first launch + probably cause other small issues
|
||||
NpgsqlConnection.GlobalTypeMapper.MapComposite<ProxyTag>("proxy_tag");
|
||||
NpgsqlConnection.GlobalTypeMapper.MapEnum<PrivacyLevel>("privacy_level");
|
||||
}
|
||||
|
||||
public async Task InitializeDatabase()
|
||||
{
|
||||
// Run everything in a transaction
|
||||
await using var conn = await _conn.Obtain();
|
||||
using var tx = conn.BeginTransaction();
|
||||
|
||||
// Before applying migrations, clean out views/functions to prevent type errors
|
||||
await ExecuteSqlFile($"{RootPath}.clean.sql", conn, tx);
|
||||
|
||||
// Apply all migrations between the current database version and the target version
|
||||
await ApplyMigrations(conn, tx);
|
||||
|
||||
// Now, reapply views/functions (we deleted them above, no need to worry about conflicts)
|
||||
await ExecuteSqlFile($"{RootPath}.views.sql", conn, tx);
|
||||
await ExecuteSqlFile($"{RootPath}.functions.sql", conn, tx);
|
||||
|
||||
// Finally, commit tx
|
||||
tx.Commit();
|
||||
}
|
||||
|
||||
private async Task ApplyMigrations(IAsyncDbConnection conn, IDbTransaction tx)
|
||||
{
|
||||
var currentVersion = await GetCurrentDatabaseVersion(conn);
|
||||
_logger.Information("Current schema version: {CurrentVersion}", currentVersion);
|
||||
for (var migration = currentVersion + 1; migration <= TargetSchemaVersion; migration++)
|
||||
{
|
||||
_logger.Information("Applying schema migration {MigrationId}", migration);
|
||||
await ExecuteSqlFile($"{RootPath}.Migrations.{migration}.sql", conn, tx);
|
||||
}
|
||||
}
|
||||
|
||||
private async Task ExecuteSqlFile(string resourceName, IDbConnection conn, IDbTransaction tx = null)
|
||||
{
|
||||
await using var stream = typeof(Schemas).Assembly.GetManifestResourceStream(resourceName);
|
||||
if (stream == null) throw new ArgumentException($"Invalid resource name '{resourceName}'");
|
||||
|
||||
using var reader = new StreamReader(stream);
|
||||
var query = await reader.ReadToEndAsync();
|
||||
|
||||
await conn.ExecuteAsync(query, transaction: tx);
|
||||
|
||||
// If the above creates new enum/composite types, we must tell Npgsql to reload the internal type caches
|
||||
// This will propagate to every other connection as well, since it marks the global type mapper collection dirty.
|
||||
// TODO: find a way to get around the cast to our internal tracker wrapper... this could break if that ever changes
|
||||
((PerformanceTrackingConnection) conn)._impl.ReloadTypes();
|
||||
}
|
||||
|
||||
private async Task<int> GetCurrentDatabaseVersion(IDbConnection conn)
|
||||
{
|
||||
// First, check if the "info" table exists (it may not, if this is a *really* old database)
|
||||
var hasInfoTable =
|
||||
await conn.QuerySingleOrDefaultAsync<int>(
|
||||
"select count(*) from information_schema.tables where table_name = 'info'") == 1;
|
||||
|
||||
// If we have the table, read the schema version
|
||||
if (hasInfoTable)
|
||||
return await conn.QuerySingleOrDefaultAsync<int>("select schema_version from info");
|
||||
|
||||
// If not, we return version "-1"
|
||||
// This means migration 0 will get executed, getting us into a consistent state
|
||||
// Then, migration 1 gets executed, which creates the info table and sets version to 1
|
||||
return -1;
|
||||
}
|
||||
}
|
||||
}
|
3
PluralKit.Core/Database/clean.sql
Normal file
3
PluralKit.Core/Database/clean.sql
Normal file
@@ -0,0 +1,3 @@
|
||||
drop view if exists system_last_switch;
|
||||
drop view if exists member_list;
|
||||
drop function if exists proxy_info;
|
85
PluralKit.Core/Database/functions.sql
Normal file
85
PluralKit.Core/Database/functions.sql
Normal file
@@ -0,0 +1,85 @@
|
||||
-- Giant "mega-function" to find all information relevant for message proxying
|
||||
-- Returns one row per member, computes several properties from others
|
||||
create function proxy_info(account_id bigint, guild_id bigint)
|
||||
returns table
|
||||
(
|
||||
-- Note: table type gets matched *by index*, not *by name* (make sure order here and in `select` match)
|
||||
system_id int, -- from: systems.id
|
||||
member_id int, -- from: members.id
|
||||
proxy_tags proxy_tag[], -- from: members.proxy_tags
|
||||
keep_proxy bool, -- from: members.keep_proxy
|
||||
proxy_enabled bool, -- from: system_guild.proxy_enabled
|
||||
proxy_name text, -- calculated: name we should proxy under
|
||||
proxy_avatar text, -- calculated: avatar we should proxy with
|
||||
autoproxy_mode int, -- from: system_guild.autoproxy_mode
|
||||
is_autoproxy_member bool, -- calculated: should this member be used for AP?
|
||||
latch_message bigint, -- calculated: last message from this account in this guild
|
||||
channel_blacklist bigint[], -- from: servers.blacklist
|
||||
log_blacklist bigint[], -- from: servers.log_blacklist
|
||||
log_channel bigint -- from: servers.log_channel
|
||||
)
|
||||
as
|
||||
$$
|
||||
select
|
||||
-- Basic data
|
||||
systems.id as system_id,
|
||||
members.id as member_id,
|
||||
members.proxy_tags as proxy_tags,
|
||||
members.keep_proxy as keep_proxy,
|
||||
|
||||
-- Proxy info
|
||||
coalesce(system_guild.proxy_enabled, true) as proxy_enabled,
|
||||
case
|
||||
when systems.tag is not null then (coalesce(member_guild.display_name, members.display_name, members.name) || ' ' || systems.tag)
|
||||
else coalesce(member_guild.display_name, members.display_name, members.name)
|
||||
end as proxy_name,
|
||||
coalesce(member_guild.avatar_url, members.avatar_url, systems.avatar_url) as proxy_avatar,
|
||||
|
||||
-- Autoproxy data
|
||||
coalesce(system_guild.autoproxy_mode, 1) as autoproxy_mode,
|
||||
|
||||
-- Autoproxy logic is essentially: "is this member the one we should autoproxy?"
|
||||
case
|
||||
-- Front mode: check if this is the first fronter
|
||||
when system_guild.autoproxy_mode = 2 then members.id = (select sls.members[1]
|
||||
from system_last_switch as sls
|
||||
where sls.system = systems.id)
|
||||
|
||||
-- Latch mode: check if this is the last proxier
|
||||
when system_guild.autoproxy_mode = 3 then members.id = last_message_in_guild.member
|
||||
|
||||
-- Member mode: check if this is the selected memebr
|
||||
when system_guild.autoproxy_mode = 4 then members.id = system_guild.autoproxy_member
|
||||
|
||||
-- no autoproxy: then this member definitely shouldn't be autoproxied :)
|
||||
else false end as is_autoproxy_member,
|
||||
|
||||
last_message_in_guild.mid as latch_message,
|
||||
|
||||
-- Guild info
|
||||
coalesce(servers.blacklist, array[]::bigint[]) as channel_blacklist,
|
||||
coalesce(servers.log_blacklist, array[]::bigint[]) as log_blacklist,
|
||||
servers.log_channel as log_channel
|
||||
from accounts
|
||||
-- Fetch guild info
|
||||
left join servers on servers.id = guild_id
|
||||
|
||||
-- Fetch the system for this account (w/ guild config)
|
||||
inner join systems on systems.id = accounts.system
|
||||
left join system_guild on system_guild.system = accounts.system and system_guild.guild = guild_id
|
||||
|
||||
-- Fetch all members from this system (w/ guild config)
|
||||
inner join members on members.system = systems.id
|
||||
left join member_guild on member_guild.member = members.id and member_guild.guild = guild_id
|
||||
|
||||
-- Find ID and member for the last message sent in this guild
|
||||
left join lateral (select mid, member
|
||||
from messages
|
||||
where messages.guild = guild_id
|
||||
and messages.sender = account_id
|
||||
and system_guild.autoproxy_mode = 3
|
||||
order by mid desc
|
||||
limit 1) as last_message_in_guild on true
|
||||
where accounts.uid = account_id;
|
||||
$$ language sql stable
|
||||
rows 10;
|
29
PluralKit.Core/Database/views.sql
Normal file
29
PluralKit.Core/Database/views.sql
Normal file
@@ -0,0 +1,29 @@
|
||||
create view system_last_switch as
|
||||
select systems.id as system,
|
||||
last_switch.id as switch,
|
||||
last_switch.timestamp as timestamp,
|
||||
array(select member from switch_members where switch_members.switch = last_switch.id) as members
|
||||
from systems
|
||||
inner join lateral (select * from switches where switches.system = systems.id order by timestamp desc limit 1) as last_switch on true;
|
||||
|
||||
create view member_list as
|
||||
select members.*,
|
||||
-- Find last message ID
|
||||
(select max(messages.mid) from messages where messages.member = members.id) as last_message,
|
||||
|
||||
-- Find last switch timestamp
|
||||
(
|
||||
select max(switches.timestamp)
|
||||
from switch_members
|
||||
inner join switches on switches.id = switch_members.switch
|
||||
where switch_members.member = members.id
|
||||
) as last_switch_time,
|
||||
|
||||
-- Extract month/day from birthday and "force" the year identical (just using 4) -> month/day only sorting!
|
||||
case when members.birthday is not null then
|
||||
make_date(
|
||||
4,
|
||||
extract(month from members.birthday)::integer,
|
||||
extract(day from members.birthday)::integer
|
||||
) end as birthday_md
|
||||
from members;
|
Reference in New Issue
Block a user