2023-08-10 18:03:37 +12:00
|
|
|
|
create function message_context(account_id bigint, guild_id bigint, channel_id bigint, thread_id bigint)
|
2020-06-12 23:13:21 +02:00
|
|
|
|
returns table (
|
2024-11-07 09:26:49 +09:00
|
|
|
|
allow_autoproxy bool,
|
|
|
|
|
|
|
2020-06-12 23:13:21 +02:00
|
|
|
|
system_id int,
|
2020-06-12 23:30:10 +02:00
|
|
|
|
system_tag text,
|
2020-11-20 18:34:08 -05:00
|
|
|
|
system_avatar text,
|
2024-11-07 09:26:49 +09:00
|
|
|
|
|
2022-11-23 09:48:24 +01:00
|
|
|
|
latch_timeout integer,
|
2023-03-25 23:42:47 +01:00
|
|
|
|
case_sensitive_proxy_tags bool,
|
2024-10-23 10:08:25 +13:00
|
|
|
|
proxy_error_message_enabled bool,
|
2024-11-08 14:46:07 -07:00
|
|
|
|
proxy_switch bool,
|
2024-11-07 09:26:49 +09:00
|
|
|
|
|
|
|
|
|
|
tag_enabled bool,
|
|
|
|
|
|
proxy_enabled bool,
|
|
|
|
|
|
system_guild_tag text,
|
|
|
|
|
|
system_guild_avatar 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,
|
|
|
|
|
|
|
2024-10-23 10:08:25 +13:00
|
|
|
|
deny_bot_usage bool
|
2020-06-12 23:13:21 +02:00
|
|
|
|
)
|
|
|
|
|
|
as $$
|
|
|
|
|
|
select
|
2024-11-07 04:54:37 +09:00
|
|
|
|
-- 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,
|
2024-11-07 09:20:15 +09:00
|
|
|
|
system_config.proxy_error_message_enabled as proxy_error_message_enabled,
|
2024-11-08 14:46:07 -07:00
|
|
|
|
system_config.proxy_switch as proxy_switch,
|
2024-11-07 04:54:37 +09:00
|
|
|
|
|
|
|
|
|
|
-- 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_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,
|
|
|
|
|
|
|
|
|
|
|
|
-- abuse_logs table
|
|
|
|
|
|
coalesce(abuse_logs.deny_bot_usage, false) as deny_bot_usage
|
|
|
|
|
|
|
2020-06-15 12:54:00 +02:00
|
|
|
|
-- 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
|
2024-11-06 19:38:09 +13:00
|
|
|
|
left join accounts on accounts.uid = account_id
|
2024-11-07 04:54:37 +09:00
|
|
|
|
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
|
2024-10-23 10:08:25 +13:00
|
|
|
|
left join abuse_logs on abuse_logs.id = accounts.abuse_log
|
2020-06-12 23:13:21 +02:00
|
|
|
|
$$ 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,
|
2023-08-10 18:03:37 +12:00
|
|
|
|
tts bool,
|
2023-08-10 18:15:25 +12:00
|
|
|
|
server_keep_proxy bool,
|
2022-03-30 04:36:22 -04:00
|
|
|
|
|
2020-06-12 23:24:36 +02:00
|
|
|
|
server_name text,
|
|
|
|
|
|
display_name text,
|
|
|
|
|
|
name text,
|
2021-05-01 19:20:00 +01:00
|
|
|
|
|
2020-06-12 23:24:36 +02:00
|
|
|
|
server_avatar text,
|
2023-03-02 06:11:35 +13:00
|
|
|
|
webhook_avatar text,
|
2020-11-20 16:40:36 -05:00
|
|
|
|
avatar text,
|
|
|
|
|
|
|
2021-05-01 19:20:00 +01:00
|
|
|
|
color char(6),
|
|
|
|
|
|
|
2020-11-20 16:40:36 -05:00
|
|
|
|
allow_autoproxy bool
|
2020-06-12 23:13:21 +02:00
|
|
|
|
)
|
|
|
|
|
|
as $$
|
|
|
|
|
|
select
|
|
|
|
|
|
-- Basic data
|
2023-03-02 06:11:35 +13:00
|
|
|
|
members.id as id,
|
|
|
|
|
|
members.proxy_tags as proxy_tags,
|
|
|
|
|
|
members.keep_proxy as keep_proxy,
|
2023-08-10 18:03:37 +12:00
|
|
|
|
members.tts as tts,
|
2023-08-10 18:15:25 +12:00
|
|
|
|
member_guild.keep_proxy as server_keep_proxy,
|
2022-03-30 04:36:22 -04:00
|
|
|
|
|
2020-06-12 23:24:36 +02:00
|
|
|
|
-- Name info
|
2023-03-02 06:11:35 +13:00
|
|
|
|
member_guild.display_name as server_name,
|
|
|
|
|
|
members.display_name as display_name,
|
|
|
|
|
|
members.name as name,
|
2022-03-30 04:36:22 -04:00
|
|
|
|
|
2020-06-12 23:24:36 +02:00
|
|
|
|
-- Avatar info
|
2023-03-02 06:11:35 +13:00
|
|
|
|
member_guild.avatar_url as server_avatar,
|
|
|
|
|
|
members.webhook_avatar_url as webhook_avatar,
|
|
|
|
|
|
members.avatar_url as avatar,
|
2020-11-20 16:40:36 -05:00
|
|
|
|
|
2023-03-02 06:11:35 +13:00
|
|
|
|
members.color as color,
|
2021-05-01 19:20:00 +01:00
|
|
|
|
|
2023-03-02 06:11:35 +13:00
|
|
|
|
members.allow_autoproxy as allow_autoproxy
|
2020-06-12 23:13:21 +02:00
|
|
|
|
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
|
2020-06-13 00:43:48 +02:00
|
|
|
|
$$ language sql stable rows 10;
|
|
|
|
|
|
|
2020-10-19 03:50:51 -05:00
|
|
|
|
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;
|
2020-06-13 00:43:48 +02:00
|
|
|
|
|
2024-04-28 15:46:06 +12:00
|
|
|
|
create function generate_hid() returns char(6) as $$
|
|
|
|
|
|
select string_agg(substr('abcefghjknoprstuvwxyz', ceil(random() * 21)::integer, 1), '') from generate_series(1, 6)
|
2020-06-13 00:43:48 +02:00
|
|
|
|
$$ language sql volatile;
|
|
|
|
|
|
|
|
|
|
|
|
|
2024-04-28 15:46:06 +12:00
|
|
|
|
create function find_free_system_hid() returns char(6) as $$
|
|
|
|
|
|
declare new_hid char(6);
|
2020-06-13 00:43:48 +02:00
|
|
|
|
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;
|
|
|
|
|
|
|
|
|
|
|
|
|
2024-04-28 15:46:06 +12:00
|
|
|
|
create function find_free_member_hid() returns char(6) as $$
|
|
|
|
|
|
declare new_hid char(6);
|
2020-06-13 00:43:48 +02:00
|
|
|
|
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
|
2020-06-29 23:51:12 +02:00
|
|
|
|
$$ language plpgsql volatile;
|
|
|
|
|
|
|
2024-04-28 15:46:06 +12:00
|
|
|
|
|
|
|
|
|
|
create function find_free_group_hid() returns char(6) as $$
|
|
|
|
|
|
declare new_hid char(6);
|
2020-06-29 23:51:12 +02:00
|
|
|
|
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
|
2023-08-10 18:15:25 +12:00
|
|
|
|
$$ language plpgsql volatile;
|