mirror of
https://github.com/PluralKit/PluralKit.git
synced 2026-02-04 04:56:49 +00:00
chore: move migrations to rust
also adds some basic test seed data
This commit is contained in:
parent
277bfebb33
commit
47c5990218
66 changed files with 173 additions and 10 deletions
16
crates/migrate/data/clean.sql
Normal file
16
crates/migrate/data/clean.sql
Normal file
|
|
@ -0,0 +1,16 @@
|
|||
-- This gets run on every bot startup and makes sure we're starting from a clean slate
|
||||
-- Then, the views/functions.sql files get run, and they recreate the necessary objects
|
||||
-- This does mean we can't use any functions in row triggers, etc. Still unsure how to handle this.
|
||||
|
||||
drop view if exists system_last_switch;
|
||||
drop view if exists system_fronters;
|
||||
drop view if exists member_list;
|
||||
drop view if exists group_list;
|
||||
|
||||
drop function if exists message_context;
|
||||
drop function if exists proxy_members;
|
||||
drop function if exists has_private_members;
|
||||
drop function if exists generate_hid;
|
||||
drop function if exists find_free_system_hid;
|
||||
drop function if exists find_free_member_hid;
|
||||
drop function if exists find_free_group_hid;
|
||||
185
crates/migrate/data/functions.sql
Normal file
185
crates/migrate/data/functions.sql
Normal file
|
|
@ -0,0 +1,185 @@
|
|||
create function message_context(account_id bigint, guild_id bigint, channel_id bigint, thread_id bigint)
|
||||
returns table (
|
||||
allow_autoproxy bool,
|
||||
|
||||
system_id int,
|
||||
system_tag text,
|
||||
system_avatar text,
|
||||
|
||||
latch_timeout integer,
|
||||
case_sensitive_proxy_tags bool,
|
||||
proxy_error_message_enabled bool,
|
||||
proxy_switch int,
|
||||
name_format text,
|
||||
|
||||
tag_enabled bool,
|
||||
proxy_enabled bool,
|
||||
system_guild_tag text,
|
||||
system_guild_avatar text,
|
||||
guild_name_format text,
|
||||
|
||||
last_switch int,
|
||||
last_switch_members int[],
|
||||
last_switch_timestamp timestamp,
|
||||
|
||||
log_channel bigint,
|
||||
in_blacklist bool,
|
||||
in_log_blacklist bool,
|
||||
log_cleanup_enabled bool,
|
||||
require_system_tag bool,
|
||||
suppress_notifications bool,
|
||||
|
||||
deny_bot_usage bool
|
||||
)
|
||||
as $$
|
||||
select
|
||||
-- accounts table
|
||||
accounts.allow_autoproxy as allow_autoproxy,
|
||||
|
||||
-- systems table
|
||||
systems.id as system_id,
|
||||
systems.tag as system_tag,
|
||||
systems.avatar_url as system_avatar,
|
||||
|
||||
-- system_config table
|
||||
system_config.latch_timeout as latch_timeout,
|
||||
system_config.case_sensitive_proxy_tags as case_sensitive_proxy_tags,
|
||||
system_config.proxy_error_message_enabled as proxy_error_message_enabled,
|
||||
system_config.proxy_switch as proxy_switch,
|
||||
system_config.name_format as name_format,
|
||||
|
||||
-- system_guild table
|
||||
coalesce(system_guild.tag_enabled, true) as tag_enabled,
|
||||
coalesce(system_guild.proxy_enabled, true) as proxy_enabled,
|
||||
system_guild.tag as system_guild_tag,
|
||||
system_guild.avatar_url as system_guild_avatar,
|
||||
system_guild.name_format as guild_name_format,
|
||||
|
||||
-- system_last_switch view
|
||||
system_last_switch.switch as last_switch,
|
||||
system_last_switch.members as last_switch_members,
|
||||
system_last_switch.timestamp as last_switch_timestamp,
|
||||
|
||||
-- servers table
|
||||
servers.log_channel as log_channel,
|
||||
((channel_id = any (servers.blacklist))
|
||||
or (thread_id = any (servers.blacklist))) as in_blacklist,
|
||||
((channel_id = any (servers.log_blacklist))
|
||||
or (thread_id = any (servers.log_blacklist))) as in_log_blacklist,
|
||||
coalesce(servers.log_cleanup_enabled, false) as log_cleanup_enabled,
|
||||
coalesce(servers.require_system_tag, false) as require_system_tag,
|
||||
coalesce(servers.suppress_notifications, false) as suppress_notifications,
|
||||
|
||||
-- abuse_logs table
|
||||
coalesce(abuse_logs.deny_bot_usage, false) as deny_bot_usage
|
||||
|
||||
-- We need a "from" clause, so we just use some bogus data that's always present
|
||||
-- This ensure we always have exactly one row going forward, so we can left join afterwards and still get data
|
||||
from (select 1) as _placeholder
|
||||
left join accounts on accounts.uid = account_id
|
||||
left join servers on servers.id = guild_id
|
||||
left join systems on systems.id = accounts.system
|
||||
left join system_config on system_config.system = accounts.system
|
||||
left join system_guild on system_guild.system = accounts.system
|
||||
and system_guild.guild = guild_id
|
||||
left join system_last_switch on system_last_switch.system = accounts.system
|
||||
left join abuse_logs on abuse_logs.id = accounts.abuse_log
|
||||
$$ language sql stable rows 1;
|
||||
|
||||
-- Fetches info about proxying related to a given account/guild
|
||||
-- Returns one row per member in system, should be used in conjuction with `message_context` too
|
||||
create function proxy_members(account_id bigint, guild_id bigint)
|
||||
returns table (
|
||||
id int,
|
||||
proxy_tags proxy_tag[],
|
||||
keep_proxy bool,
|
||||
tts bool,
|
||||
server_keep_proxy bool,
|
||||
|
||||
server_name text,
|
||||
display_name text,
|
||||
name text,
|
||||
|
||||
server_avatar text,
|
||||
webhook_avatar text,
|
||||
avatar text,
|
||||
|
||||
color char(6),
|
||||
|
||||
allow_autoproxy bool
|
||||
)
|
||||
as $$
|
||||
select
|
||||
-- Basic data
|
||||
members.id as id,
|
||||
members.proxy_tags as proxy_tags,
|
||||
members.keep_proxy as keep_proxy,
|
||||
members.tts as tts,
|
||||
member_guild.keep_proxy as server_keep_proxy,
|
||||
|
||||
-- Name info
|
||||
member_guild.display_name as server_name,
|
||||
members.display_name as display_name,
|
||||
members.name as name,
|
||||
|
||||
-- Avatar info
|
||||
member_guild.avatar_url as server_avatar,
|
||||
members.webhook_avatar_url as webhook_avatar,
|
||||
members.avatar_url as avatar,
|
||||
|
||||
members.color as color,
|
||||
|
||||
members.allow_autoproxy as allow_autoproxy
|
||||
from accounts
|
||||
inner join systems on systems.id = accounts.system
|
||||
inner join members on members.system = systems.id
|
||||
left join member_guild on member_guild.member = members.id and member_guild.guild = guild_id
|
||||
where accounts.uid = account_id
|
||||
$$ language sql stable rows 10;
|
||||
|
||||
create function has_private_members(system_hid int) returns bool as $$
|
||||
declare m int;
|
||||
begin
|
||||
m := count(id) from members where system = system_hid and member_visibility = 2;
|
||||
if m > 0 then return true;
|
||||
else return false;
|
||||
end if;
|
||||
end
|
||||
$$ language plpgsql;
|
||||
|
||||
create function generate_hid() returns char(6) as $$
|
||||
select string_agg(substr('abcefghjknoprstuvwxyz', ceil(random() * 21)::integer, 1), '') from generate_series(1, 6)
|
||||
$$ language sql volatile;
|
||||
|
||||
|
||||
create function find_free_system_hid() returns char(6) as $$
|
||||
declare new_hid char(6);
|
||||
begin
|
||||
loop
|
||||
new_hid := generate_hid();
|
||||
if not exists (select 1 from systems where hid = new_hid) then return new_hid; end if;
|
||||
end loop;
|
||||
end
|
||||
$$ language plpgsql volatile;
|
||||
|
||||
|
||||
create function find_free_member_hid() returns char(6) as $$
|
||||
declare new_hid char(6);
|
||||
begin
|
||||
loop
|
||||
new_hid := generate_hid();
|
||||
if not exists (select 1 from members where hid = new_hid) then return new_hid; end if;
|
||||
end loop;
|
||||
end
|
||||
$$ language plpgsql volatile;
|
||||
|
||||
|
||||
create function find_free_group_hid() returns char(6) as $$
|
||||
declare new_hid char(6);
|
||||
begin
|
||||
loop
|
||||
new_hid := generate_hid();
|
||||
if not exists (select 1 from groups where hid = new_hid) then return new_hid; end if;
|
||||
end loop;
|
||||
end
|
||||
$$ language plpgsql volatile;
|
||||
112
crates/migrate/data/migrations/0.sql
Normal file
112
crates/migrate/data/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
crates/migrate/data/migrations/1.sql
Normal file
15
crates/migrate/data/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);
|
||||
11
crates/migrate/data/migrations/10.sql
Normal file
11
crates/migrate/data/migrations/10.sql
Normal file
|
|
@ -0,0 +1,11 @@
|
|||
-- SCHEMA VERSION 10: 2020-10-09 --
|
||||
-- Member/group limit override per-system
|
||||
|
||||
alter table systems add column member_limit_override smallint default null;
|
||||
alter table systems add column group_limit_override smallint default null;
|
||||
|
||||
-- Lowering global limit to 1000 in this commit, so increase it for systems already above that
|
||||
update systems s set member_limit_override = 1500
|
||||
where (select count(*) from members m where m.system = s.id) > 1000;
|
||||
|
||||
update info set schema_version = 10;
|
||||
10
crates/migrate/data/migrations/11.sql
Normal file
10
crates/migrate/data/migrations/11.sql
Normal file
|
|
@ -0,0 +1,10 @@
|
|||
-- SCHEMA VERSION 11: 2020-10-23 --
|
||||
-- Create command message table --
|
||||
|
||||
create table command_messages
|
||||
(
|
||||
message_id bigint primary key not null,
|
||||
author_id bigint not null
|
||||
);
|
||||
|
||||
update info set schema_version = 11;
|
||||
10
crates/migrate/data/migrations/12.sql
Normal file
10
crates/migrate/data/migrations/12.sql
Normal file
|
|
@ -0,0 +1,10 @@
|
|||
-- SCHEMA VERSION 12: 2020-12-08 --
|
||||
-- Add disabling front/latch autoproxy per-member --
|
||||
-- Add disabling autoproxy per-account --
|
||||
-- Add configurable latch timeout --
|
||||
|
||||
alter table members add column allow_autoproxy bool not null default true;
|
||||
alter table accounts add column allow_autoproxy bool not null default true;
|
||||
alter table systems add column latch_timeout int; -- in seconds
|
||||
|
||||
update info set schema_version = 12;
|
||||
7
crates/migrate/data/migrations/13.sql
Normal file
7
crates/migrate/data/migrations/13.sql
Normal file
|
|
@ -0,0 +1,7 @@
|
|||
-- SCHEMA VERSION 13: 2021-03-28 --
|
||||
-- Add system and group colors --
|
||||
|
||||
alter table systems add column color char(6);
|
||||
alter table groups add column color char(6);
|
||||
|
||||
update info set schema_version = 13;
|
||||
15
crates/migrate/data/migrations/14.sql
Normal file
15
crates/migrate/data/migrations/14.sql
Normal file
|
|
@ -0,0 +1,15 @@
|
|||
-- SCHEMA VERSION 14: 2021-06-10 --
|
||||
-- Add shard status table --
|
||||
|
||||
create table shards (
|
||||
id int not null primary key,
|
||||
|
||||
-- 0 = down, 1 = up
|
||||
status smallint not null default 0,
|
||||
|
||||
ping float,
|
||||
last_heartbeat timestamptz,
|
||||
last_connection timestamptz
|
||||
);
|
||||
|
||||
update info set schema_version = 14;
|
||||
8
crates/migrate/data/migrations/15.sql
Normal file
8
crates/migrate/data/migrations/15.sql
Normal file
|
|
@ -0,0 +1,8 @@
|
|||
-- SCHEMA VERSION 15: 2021-08-01
|
||||
-- add banner (large) images to entities with "cards"
|
||||
|
||||
alter table systems add column banner_image text;
|
||||
alter table members add column banner_image text;
|
||||
alter table groups add column banner_image text;
|
||||
|
||||
update info set schema_version = 15;
|
||||
7
crates/migrate/data/migrations/16.sql
Normal file
7
crates/migrate/data/migrations/16.sql
Normal file
|
|
@ -0,0 +1,7 @@
|
|||
-- SCHEMA VERSION 16: 2021-08-02 --
|
||||
-- Add server-specific system tag --
|
||||
|
||||
alter table system_guild add column tag text default null;
|
||||
alter table system_guild add column tag_enabled bool not null default true;
|
||||
|
||||
update info set schema_version = 16;
|
||||
8
crates/migrate/data/migrations/17.sql
Normal file
8
crates/migrate/data/migrations/17.sql
Normal file
|
|
@ -0,0 +1,8 @@
|
|||
-- schema version 17: 2021-09-26 --
|
||||
-- add channel_id to command message table
|
||||
|
||||
alter table command_messages add column channel_id bigint;
|
||||
update command_messages set channel_id = 0;
|
||||
alter table command_messages alter column channel_id set not null;
|
||||
|
||||
update info set schema_version = 17;
|
||||
18
crates/migrate/data/migrations/18.sql
Normal file
18
crates/migrate/data/migrations/18.sql
Normal file
|
|
@ -0,0 +1,18 @@
|
|||
-- schema version 18: 2021-09-26 --
|
||||
-- Add UUIDs for APIs
|
||||
|
||||
create extension if not exists pgcrypto;
|
||||
|
||||
alter table systems add column uuid uuid default gen_random_uuid();
|
||||
create index systems_uuid_idx on systems(uuid);
|
||||
|
||||
alter table members add column uuid uuid default gen_random_uuid();
|
||||
create index members_uuid_idx on members(uuid);
|
||||
|
||||
alter table switches add column uuid uuid default gen_random_uuid();
|
||||
create index switches_uuid_idx on switches(uuid);
|
||||
|
||||
alter table groups add column uuid uuid default gen_random_uuid();
|
||||
create index groups_uuid_idx on groups(uuid);
|
||||
|
||||
update info set schema_version = 18;
|
||||
10
crates/migrate/data/migrations/19.sql
Normal file
10
crates/migrate/data/migrations/19.sql
Normal file
|
|
@ -0,0 +1,10 @@
|
|||
-- schema version 19: 2021-10-15 --
|
||||
-- add stats to info table
|
||||
|
||||
alter table info add column system_count int;
|
||||
alter table info add column member_count int;
|
||||
alter table info add column group_count int;
|
||||
alter table info add column switch_count int;
|
||||
alter table info add column message_count int;
|
||||
|
||||
update info set schema_version = 19;
|
||||
13
crates/migrate/data/migrations/2.sql
Normal file
13
crates/migrate/data/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;
|
||||
7
crates/migrate/data/migrations/20.sql
Normal file
7
crates/migrate/data/migrations/20.sql
Normal file
|
|
@ -0,0 +1,7 @@
|
|||
-- schema version 20: insert date
|
||||
-- add outgoing webhook to systems
|
||||
|
||||
alter table systems add column webhook_url text;
|
||||
alter table systems add column webhook_token text;
|
||||
|
||||
update info set schema_version = 20;
|
||||
29
crates/migrate/data/migrations/21.sql
Normal file
29
crates/migrate/data/migrations/21.sql
Normal file
|
|
@ -0,0 +1,29 @@
|
|||
-- schema version 21
|
||||
-- create `system_config` table
|
||||
|
||||
create table system_config (
|
||||
system int primary key references systems(id) on delete cascade,
|
||||
ui_tz text not null default 'UTC',
|
||||
pings_enabled bool not null default true,
|
||||
latch_timeout int,
|
||||
member_limit_override int,
|
||||
group_limit_override int
|
||||
);
|
||||
|
||||
insert into system_config select
|
||||
id as system,
|
||||
ui_tz,
|
||||
pings_enabled,
|
||||
latch_timeout,
|
||||
member_limit_override,
|
||||
group_limit_override
|
||||
from systems;
|
||||
|
||||
alter table systems
|
||||
drop column ui_tz,
|
||||
drop column pings_enabled,
|
||||
drop column latch_timeout,
|
||||
drop column member_limit_override,
|
||||
drop column group_limit_override;
|
||||
|
||||
update info set schema_version = 21;
|
||||
7
crates/migrate/data/migrations/22.sql
Normal file
7
crates/migrate/data/migrations/22.sql
Normal file
|
|
@ -0,0 +1,7 @@
|
|||
-- schema version 22
|
||||
-- automatically set members/groups as private when creating
|
||||
|
||||
alter table system_config add column member_default_private bool not null default false;
|
||||
alter table system_config add column group_default_private bool not null default false;
|
||||
|
||||
update info set schema_version = 22;
|
||||
6
crates/migrate/data/migrations/23.sql
Normal file
6
crates/migrate/data/migrations/23.sql
Normal file
|
|
@ -0,0 +1,6 @@
|
|||
-- schema version 23
|
||||
-- show/hide private information when looked up by linked accounts
|
||||
|
||||
alter table system_config add column show_private_info bool default true;
|
||||
|
||||
update info set schema_version = 23;
|
||||
10
crates/migrate/data/migrations/24.sql
Normal file
10
crates/migrate/data/migrations/24.sql
Normal file
|
|
@ -0,0 +1,10 @@
|
|||
-- schema version 24
|
||||
-- don't drop message rows when system/member are deleted
|
||||
|
||||
alter table messages alter column member drop not null;
|
||||
alter table messages drop constraint messages_member_fkey;
|
||||
alter table messages
|
||||
add constraint messages_member_fkey
|
||||
foreign key (member) references members(id) on delete set null;
|
||||
|
||||
update info set schema_version = 24;
|
||||
7
crates/migrate/data/migrations/25.sql
Normal file
7
crates/migrate/data/migrations/25.sql
Normal file
|
|
@ -0,0 +1,7 @@
|
|||
-- schema version 25
|
||||
-- group name privacy
|
||||
|
||||
alter table groups add column name_privacy integer check (name_privacy in (1, 2)) not null default 1;
|
||||
alter table groups add column metadata_privacy integer check (metadata_privacy in (1, 2)) not null default 1;
|
||||
|
||||
update info set schema_version = 25;
|
||||
12
crates/migrate/data/migrations/26.sql
Normal file
12
crates/migrate/data/migrations/26.sql
Normal file
|
|
@ -0,0 +1,12 @@
|
|||
-- schema version 26
|
||||
-- cache Discord DM channels in the database
|
||||
|
||||
alter table accounts alter column system drop not null;
|
||||
alter table accounts drop constraint accounts_system_fkey;
|
||||
alter table accounts
|
||||
add constraint accounts_system_fkey
|
||||
foreign key (system) references systems(id) on delete set null;
|
||||
|
||||
alter table accounts add column dm_channel bigint;
|
||||
|
||||
update info set schema_version = 26;
|
||||
36
crates/migrate/data/migrations/27.sql
Normal file
36
crates/migrate/data/migrations/27.sql
Normal file
|
|
@ -0,0 +1,36 @@
|
|||
-- schema version 27
|
||||
-- autoproxy locations
|
||||
|
||||
-- mode pseudo-enum: (copied from 3.sql)
|
||||
-- 1 = autoproxy off
|
||||
-- 2 = front mode (first fronter)
|
||||
-- 3 = latch mode (last proxyer)
|
||||
-- 4 = member mode (specific member)
|
||||
|
||||
create table autoproxy (
|
||||
system int references systems(id) on delete cascade,
|
||||
channel_id bigint,
|
||||
guild_id bigint,
|
||||
autoproxy_mode int check (autoproxy_mode in (1, 2, 3, 4)) not null default 1,
|
||||
autoproxy_member int references members(id) on delete set null,
|
||||
last_latch_timestamp timestamp,
|
||||
check (
|
||||
(channel_id = 0 and guild_id = 0)
|
||||
or (channel_id != 0 and guild_id = 0)
|
||||
or (channel_id = 0 and guild_id != 0)
|
||||
),
|
||||
primary key (system, channel_id, guild_id)
|
||||
);
|
||||
|
||||
insert into autoproxy select
|
||||
system,
|
||||
0 as channel_id,
|
||||
guild as guild_id,
|
||||
autoproxy_mode,
|
||||
autoproxy_member
|
||||
from system_guild;
|
||||
|
||||
alter table system_guild drop column autoproxy_mode;
|
||||
alter table system_guild drop column autoproxy_member;
|
||||
|
||||
update info set schema_version = 27;
|
||||
7
crates/migrate/data/migrations/28.sql
Normal file
7
crates/migrate/data/migrations/28.sql
Normal file
|
|
@ -0,0 +1,7 @@
|
|||
-- schema version 28
|
||||
-- system pronouns
|
||||
|
||||
alter table systems add column pronouns text;
|
||||
alter table systems add column pronoun_privacy integer check (pronoun_privacy in (1, 2)) not null default 1;
|
||||
|
||||
update info set schema_version = 28;
|
||||
5
crates/migrate/data/migrations/29.sql
Normal file
5
crates/migrate/data/migrations/29.sql
Normal file
|
|
@ -0,0 +1,5 @@
|
|||
-- schema version 29
|
||||
|
||||
alter table systems add column is_deleting bool default false;
|
||||
|
||||
update info set schema_version = 29;
|
||||
15
crates/migrate/data/migrations/3.sql
Normal file
15
crates/migrate/data/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;
|
||||
5
crates/migrate/data/migrations/30.sql
Normal file
5
crates/migrate/data/migrations/30.sql
Normal file
|
|
@ -0,0 +1,5 @@
|
|||
-- schema version 30
|
||||
|
||||
alter table system_config add column description_templates text[] not null default array[]::text[];
|
||||
|
||||
update info set schema_version = 30;
|
||||
5
crates/migrate/data/migrations/31.sql
Normal file
5
crates/migrate/data/migrations/31.sql
Normal file
|
|
@ -0,0 +1,5 @@
|
|||
-- schema version 31
|
||||
|
||||
alter table system_config add column case_sensitive_proxy_tags boolean not null default true;
|
||||
|
||||
update info set schema_version = 31;
|
||||
6
crates/migrate/data/migrations/32.sql
Normal file
6
crates/migrate/data/migrations/32.sql
Normal file
|
|
@ -0,0 +1,6 @@
|
|||
-- database version 32
|
||||
-- re-add last message timestamp to members
|
||||
|
||||
alter table members add column last_message_timestamp timestamp;
|
||||
|
||||
update info set schema_version = 32;
|
||||
6
crates/migrate/data/migrations/33.sql
Normal file
6
crates/migrate/data/migrations/33.sql
Normal file
|
|
@ -0,0 +1,6 @@
|
|||
-- database version 33
|
||||
-- add webhook_avatar_url to system members
|
||||
|
||||
alter table members add column webhook_avatar_url text;
|
||||
|
||||
update info set schema_version = 33;
|
||||
6
crates/migrate/data/migrations/34.sql
Normal file
6
crates/migrate/data/migrations/34.sql
Normal file
|
|
@ -0,0 +1,6 @@
|
|||
-- database version 34
|
||||
-- add proxy_error_message_enabled to system config
|
||||
|
||||
alter table system_config add column proxy_error_message_enabled bool default true;
|
||||
|
||||
update info set schema_version = 34;
|
||||
7
crates/migrate/data/migrations/35.sql
Normal file
7
crates/migrate/data/migrations/35.sql
Normal file
|
|
@ -0,0 +1,7 @@
|
|||
-- database version 35
|
||||
-- add guild avatar and guild name to system guild settings
|
||||
|
||||
alter table system_guild add column avatar_url text;
|
||||
alter table system_guild add column display_name text;
|
||||
|
||||
update info set schema_version = 35;
|
||||
7
crates/migrate/data/migrations/36.sql
Normal file
7
crates/migrate/data/migrations/36.sql
Normal file
|
|
@ -0,0 +1,7 @@
|
|||
-- database version 36
|
||||
-- add system avatar privacy and system name privacy
|
||||
|
||||
alter table systems add column name_privacy integer not null default 1;
|
||||
alter table systems add column avatar_privacy integer not null default 1;
|
||||
|
||||
update info set schema_version = 36;
|
||||
7
crates/migrate/data/migrations/37.sql
Normal file
7
crates/migrate/data/migrations/37.sql
Normal file
|
|
@ -0,0 +1,7 @@
|
|||
-- database version 37
|
||||
-- add proxy tag privacy
|
||||
|
||||
alter table members add column proxy_privacy integer not null default 1;
|
||||
alter table members add constraint members_proxy_privacy_check check (proxy_privacy = ANY (ARRAY[1,2]));
|
||||
|
||||
update info set schema_version = 37;
|
||||
6
crates/migrate/data/migrations/38.sql
Normal file
6
crates/migrate/data/migrations/38.sql
Normal file
|
|
@ -0,0 +1,6 @@
|
|||
-- database version 38
|
||||
-- add proxy tag privacy
|
||||
|
||||
alter table members add column tts boolean not null default false;
|
||||
|
||||
update info set schema_version = 38;
|
||||
7
crates/migrate/data/migrations/39.sql
Normal file
7
crates/migrate/data/migrations/39.sql
Normal file
|
|
@ -0,0 +1,7 @@
|
|||
-- database version 39
|
||||
-- add missing privacy constraints
|
||||
|
||||
alter table systems add constraint systems_name_privacy_check check (name_privacy = ANY (ARRAY[1,2]));
|
||||
alter table systems add constraint systems_avatar_privacy_check check (avatar_privacy = ANY (ARRAY[1,2]));
|
||||
|
||||
update info set schema_version = 39;
|
||||
3
crates/migrate/data/migrations/4.sql
Normal file
3
crates/migrate/data/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;
|
||||
6
crates/migrate/data/migrations/40.sql
Normal file
6
crates/migrate/data/migrations/40.sql
Normal file
|
|
@ -0,0 +1,6 @@
|
|||
-- database version 40
|
||||
-- add per-server keepproxy toggle
|
||||
|
||||
alter table member_guild add column keep_proxy bool default null;
|
||||
|
||||
update info set schema_version = 40;
|
||||
10
crates/migrate/data/migrations/41.sql
Normal file
10
crates/migrate/data/migrations/41.sql
Normal file
|
|
@ -0,0 +1,10 @@
|
|||
-- database version 41
|
||||
-- fix statistics counts
|
||||
|
||||
alter table info alter column system_count type bigint using system_count::bigint;
|
||||
alter table info alter column member_count type bigint using member_count::bigint;
|
||||
alter table info alter column group_count type bigint using group_count::bigint;
|
||||
alter table info alter column switch_count type bigint using switch_count::bigint;
|
||||
alter table info alter column message_count type bigint using message_count::bigint;
|
||||
|
||||
update info set schema_version = 41;
|
||||
11
crates/migrate/data/migrations/42.sql
Normal file
11
crates/migrate/data/migrations/42.sql
Normal file
|
|
@ -0,0 +1,11 @@
|
|||
-- database version 42
|
||||
-- move to 6 character HIDs, add HID display config setting
|
||||
|
||||
alter table systems alter column hid type char(6) using rpad(hid, 6, ' ');
|
||||
alter table members alter column hid type char(6) using rpad(hid, 6, ' ');
|
||||
alter table groups alter column hid type char(6) using rpad(hid, 6, ' ');
|
||||
|
||||
alter table system_config add column hid_display_split bool default false;
|
||||
alter table system_config add column hid_display_caps bool default false;
|
||||
|
||||
update info set schema_version = 42;
|
||||
6
crates/migrate/data/migrations/43.sql
Normal file
6
crates/migrate/data/migrations/43.sql
Normal file
|
|
@ -0,0 +1,6 @@
|
|||
-- database version 43
|
||||
-- add config setting for padding 5-character IDs in lists
|
||||
|
||||
alter table system_config add column hid_list_padding int not null default 0;
|
||||
|
||||
update info set schema_version = 43;
|
||||
23
crates/migrate/data/migrations/44.sql
Normal file
23
crates/migrate/data/migrations/44.sql
Normal file
|
|
@ -0,0 +1,23 @@
|
|||
-- database version 44
|
||||
-- add abuse handling measures
|
||||
|
||||
create table abuse_logs (
|
||||
id serial primary key,
|
||||
uuid uuid default gen_random_uuid(),
|
||||
description text,
|
||||
deny_bot_usage bool not null default false,
|
||||
created timestamp not null default (current_timestamp at time zone 'utc')
|
||||
);
|
||||
|
||||
alter table accounts add column abuse_log integer default null references abuse_logs (id) on delete set null;
|
||||
create index abuse_logs_uuid_idx on abuse_logs (uuid);
|
||||
|
||||
-- we now need to handle a row in "accounts" table being created with no
|
||||
-- system (rather than just system being set to null after insert)
|
||||
--
|
||||
-- set default null and drop the sequence (from the column being created
|
||||
-- as type SERIAL)
|
||||
alter table accounts alter column system set default null;
|
||||
drop sequence accounts_system_seq;
|
||||
|
||||
update info set schema_version = 44;
|
||||
6
crates/migrate/data/migrations/45.sql
Normal file
6
crates/migrate/data/migrations/45.sql
Normal file
|
|
@ -0,0 +1,6 @@
|
|||
-- database version 45
|
||||
-- add new config setting "proxy_switch"
|
||||
|
||||
alter table system_config add column proxy_switch bool default false;
|
||||
|
||||
update info set schema_version = 45;
|
||||
12
crates/migrate/data/migrations/46.sql
Normal file
12
crates/migrate/data/migrations/46.sql
Normal file
|
|
@ -0,0 +1,12 @@
|
|||
-- database version 46
|
||||
-- adds banner privacy
|
||||
|
||||
alter table members add column banner_privacy int not null default 1 check (banner_privacy = ANY (ARRAY[1,2]));
|
||||
alter table groups add column banner_privacy int not null default 1 check (banner_privacy = ANY (ARRAY[1,2]));
|
||||
alter table systems add column banner_privacy int not null default 1 check (banner_privacy = ANY (ARRAY[1,2]));
|
||||
|
||||
update members set banner_privacy = 2 where description_privacy = 2;
|
||||
update groups set banner_privacy = 2 where description_privacy = 2;
|
||||
update systems set banner_privacy = 2 where description_privacy = 2;
|
||||
|
||||
update info set schema_version = 46;
|
||||
6
crates/migrate/data/migrations/47.sql
Normal file
6
crates/migrate/data/migrations/47.sql
Normal file
|
|
@ -0,0 +1,6 @@
|
|||
-- database version 47
|
||||
-- add config setting for supplying a custom tag format in names
|
||||
|
||||
alter table system_config add column name_format text;
|
||||
|
||||
update info set schema_version = 47;
|
||||
9
crates/migrate/data/migrations/48.sql
Normal file
9
crates/migrate/data/migrations/48.sql
Normal file
|
|
@ -0,0 +1,9 @@
|
|||
-- database version 48
|
||||
--
|
||||
-- add guild settings for disabling "invalid command" responses &
|
||||
-- enforcing the presence of system tags
|
||||
|
||||
alter table servers add column invalid_command_response_enabled bool not null default true;
|
||||
alter table servers add column require_system_tag bool not null default false;
|
||||
|
||||
update info set schema_version = 48;
|
||||
6
crates/migrate/data/migrations/49.sql
Normal file
6
crates/migrate/data/migrations/49.sql
Normal file
|
|
@ -0,0 +1,6 @@
|
|||
-- database version 49
|
||||
-- add guild name format
|
||||
|
||||
alter table system_guild add column name_format text;
|
||||
|
||||
update info set schema_version = 49;
|
||||
3
crates/migrate/data/migrations/5.sql
Normal file
3
crates/migrate/data/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;
|
||||
11
crates/migrate/data/migrations/50.sql
Normal file
11
crates/migrate/data/migrations/50.sql
Normal file
|
|
@ -0,0 +1,11 @@
|
|||
-- database version 50
|
||||
-- change proxy switch config to an enum
|
||||
|
||||
alter table system_config
|
||||
alter column proxy_switch drop default,
|
||||
alter column proxy_switch type int
|
||||
using case when proxy_switch then 1 else 0 end,
|
||||
alter column proxy_switch set default 0,
|
||||
add constraint proxy_switch_check check (proxy_switch = ANY (ARRAY[0,1,2]));
|
||||
|
||||
update info set schema_version = 50;
|
||||
7
crates/migrate/data/migrations/51.sql
Normal file
7
crates/migrate/data/migrations/51.sql
Normal file
|
|
@ -0,0 +1,7 @@
|
|||
-- database version 51
|
||||
--
|
||||
-- add guild setting for SUPPRESS_NOTIFICATIONS message flag on proxied messages
|
||||
|
||||
alter table servers add column suppress_notifications bool not null default false;
|
||||
|
||||
update info set schema_version = 51;
|
||||
21
crates/migrate/data/migrations/52.sql
Normal file
21
crates/migrate/data/migrations/52.sql
Normal file
|
|
@ -0,0 +1,21 @@
|
|||
-- database version 52
|
||||
-- messages db updates
|
||||
|
||||
create index messages_by_original on messages(original_mid);
|
||||
create index messages_by_sender on messages(sender);
|
||||
|
||||
-- remove old table from database version 11
|
||||
alter table command_messages rename to command_messages_old;
|
||||
|
||||
create table command_messages (
|
||||
mid bigint primary key,
|
||||
channel bigint not null,
|
||||
guild bigint not null,
|
||||
sender bigint not null,
|
||||
original_mid bigint not null
|
||||
);
|
||||
|
||||
create index command_messages_by_original on command_messages(original_mid);
|
||||
create index command_messages_by_sender on command_messages(sender);
|
||||
|
||||
update info set schema_version = 52;
|
||||
3
crates/migrate/data/migrations/6.sql
Normal file
3
crates/migrate/data/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;
|
||||
35
crates/migrate/data/migrations/7.sql
Normal file
35
crates/migrate/data/migrations/7.sql
Normal file
|
|
@ -0,0 +1,35 @@
|
|||
-- 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 = counts.count
|
||||
from (select member, count(*) as count from messages group by messages.member) as counts
|
||||
where counts.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;
|
||||
24
crates/migrate/data/migrations/8.sql
Normal file
24
crates/migrate/data/migrations/8.sql
Normal file
|
|
@ -0,0 +1,24 @@
|
|||
-- SCHEMA VERSION 8: 2020-05-13 --
|
||||
-- Create new columns --
|
||||
alter table members add column description_privacy integer check (description_privacy in (1, 2)) not null default 1;
|
||||
alter table members add column name_privacy integer check (name_privacy in (1, 2)) not null default 1;
|
||||
alter table members add column avatar_privacy integer check (avatar_privacy in (1, 2)) not null default 1;
|
||||
alter table members add column birthday_privacy integer check (birthday_privacy in (1, 2)) not null default 1;
|
||||
alter table members add column pronoun_privacy integer check (pronoun_privacy in (1, 2)) not null default 1;
|
||||
alter table members add column metadata_privacy integer check (metadata_privacy in (1, 2)) not null default 1;
|
||||
-- alter table members add column color_privacy integer check (color_privacy in (1, 2)) not null default 1;
|
||||
|
||||
-- Transfer existing settings --
|
||||
update members set description_privacy = member_privacy;
|
||||
update members set name_privacy = member_privacy;
|
||||
update members set avatar_privacy = member_privacy;
|
||||
update members set birthday_privacy = member_privacy;
|
||||
update members set pronoun_privacy = member_privacy;
|
||||
update members set metadata_privacy = member_privacy;
|
||||
-- update members set color_privacy = member_privacy;
|
||||
|
||||
-- Rename member_privacy to member_visibility --
|
||||
alter table members rename column member_privacy to member_visibility;
|
||||
|
||||
-- Update Schema Info --
|
||||
update info set schema_version = 8;
|
||||
32
crates/migrate/data/migrations/9.sql
Normal file
32
crates/migrate/data/migrations/9.sql
Normal file
|
|
@ -0,0 +1,32 @@
|
|||
-- SCHEMA VERSION 9: 2020-08-25 --
|
||||
-- Adds support for member groups.
|
||||
|
||||
create table groups (
|
||||
id int primary key generated always as identity,
|
||||
hid char(5) unique not null,
|
||||
system int not null references systems(id) on delete cascade,
|
||||
|
||||
name text not null,
|
||||
display_name text,
|
||||
description text,
|
||||
icon text,
|
||||
|
||||
-- Description columns follow the same pattern as usual: 1 = public, 2 = private
|
||||
description_privacy integer check (description_privacy in (1, 2)) not null default 1,
|
||||
icon_privacy integer check (icon_privacy in (1, 2)) not null default 1,
|
||||
list_privacy integer check (list_privacy in (1, 2)) not null default 1,
|
||||
visibility integer check (visibility in (1, 2)) not null default 1,
|
||||
|
||||
created timestamp with time zone not null default (current_timestamp at time zone 'utc')
|
||||
);
|
||||
|
||||
create table group_members (
|
||||
group_id int not null references groups(id) on delete cascade,
|
||||
member_id int not null references members(id) on delete cascade,
|
||||
primary key (group_id, member_id)
|
||||
);
|
||||
|
||||
alter table systems add column group_list_privacy integer check (group_list_privacy in (1, 2)) not null default 1;
|
||||
update systems set group_list_privacy = member_list_privacy;
|
||||
|
||||
update info set schema_version = 9;
|
||||
8
crates/migrate/data/seed.sql
Normal file
8
crates/migrate/data/seed.sql
Normal file
|
|
@ -0,0 +1,8 @@
|
|||
-- example data (for integration tests or such)
|
||||
|
||||
insert into systems (hid, token) values (
|
||||
'exmpl',
|
||||
'vlPitT0tEgT++a450w1/afODy5NXdALcHDwryX6dOIZdGUGbZg+5IH3nrUsQihsw'
|
||||
);
|
||||
insert into system_config (system) values (1);
|
||||
insert into system_guild (system, guild) values (1, 466707357099884544);
|
||||
75
crates/migrate/data/views.sql
Normal file
75
crates/migrate/data/views.sql
Normal file
|
|
@ -0,0 +1,75 @@
|
|||
-- Returns one row per system, containing info about latest switch + array of member IDs (for future joins)
|
||||
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 order by switch_members.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 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,
|
||||
|
||||
-- Extract member description as seen by "the public"
|
||||
case
|
||||
-- Privacy '1' = public; just return description as normal
|
||||
when members.description_privacy = 1 then members.description
|
||||
-- Any other privacy (rn just '2'), return null description (missing case = null in SQL)
|
||||
end as public_description,
|
||||
|
||||
-- Extract member name as seen by "the public"
|
||||
case
|
||||
-- Privacy '1' = public; just return name as normal
|
||||
when members.name_privacy = 1 then members.name
|
||||
-- Any other privacy (rn just '2'), return display name
|
||||
else coalesce(members.display_name, members.name)
|
||||
end as public_name
|
||||
from members;
|
||||
|
||||
create view group_list as
|
||||
select groups.*,
|
||||
-- Find public group member count
|
||||
(
|
||||
select count(*) from group_members
|
||||
inner join members on group_members.member_id = members.id
|
||||
where
|
||||
group_members.group_id = groups.id and members.member_visibility = 1
|
||||
) as public_member_count,
|
||||
-- Find private group member count
|
||||
(
|
||||
select count(*) from group_members
|
||||
inner join members on group_members.member_id = members.id
|
||||
where
|
||||
group_members.group_id = groups.id
|
||||
) as total_member_count,
|
||||
|
||||
-- Extract group description as seen by "the public"
|
||||
case
|
||||
-- Privacy '1' = public; just return description as normal
|
||||
when groups.description_privacy = 1 then groups.description
|
||||
-- Any other privacy (rn just '2'), return null description (missing case = null in SQL)
|
||||
end as public_description,
|
||||
|
||||
-- Extract member name as seen by "the public"
|
||||
case
|
||||
-- Privacy '1' = public; just return name as normal
|
||||
when groups.name_privacy = 1 then groups.name
|
||||
-- Any other privacy (rn just '2'), return display name
|
||||
else coalesce(groups.display_name, groups.name)
|
||||
end as public_name
|
||||
from groups;
|
||||
Loading…
Add table
Add a link
Reference in a new issue