Refactor sort/filter code once again
Now we handle sorting on the bot side, but still filter in the database
This commit is contained in:
34
PluralKit.Core/Database/Views/DatabaseViewsExt.cs
Normal file
34
PluralKit.Core/Database/Views/DatabaseViewsExt.cs
Normal file
@@ -0,0 +1,34 @@
|
||||
#nullable enable
|
||||
using System.Collections.Generic;
|
||||
using System.Text;
|
||||
using System.Threading.Tasks;
|
||||
|
||||
using Dapper;
|
||||
|
||||
namespace PluralKit.Core
|
||||
{
|
||||
public static class DatabaseViewsExt
|
||||
{
|
||||
public static Task<IEnumerable<SystemFronter>> QueryCurrentFronters(this IPKConnection conn, int system) =>
|
||||
conn.QueryAsync<SystemFronter>("select * from system_fronters where system = @system", new {system});
|
||||
|
||||
public static Task<IEnumerable<ListedMember>> QueryMemberList(this IPKConnection conn, int system, PrivacyLevel? privacyFilter = null, string? filter = null, bool includeDescriptionInNameFilter = false)
|
||||
{
|
||||
StringBuilder query = new StringBuilder("select * from member_list where system = @system");
|
||||
|
||||
if (privacyFilter != null)
|
||||
query.Append($" and member_privacy = {(int) privacyFilter}");
|
||||
|
||||
if (filter != null)
|
||||
{
|
||||
static string Filter(string column) => $"position(lower(@filter) in lower(coalesce({column}, ''))) > 0";
|
||||
|
||||
query.Append($" and ({Filter("name")} or {Filter("display_name")}");
|
||||
if (includeDescriptionInNameFilter) query.Append($" or {Filter("description")}");
|
||||
query.Append(")");
|
||||
}
|
||||
|
||||
return conn.QueryAsync<ListedMember>(query.ToString(), new {system, filter});
|
||||
}
|
||||
}
|
||||
}
|
17
PluralKit.Core/Database/Views/ListedMember.cs
Normal file
17
PluralKit.Core/Database/Views/ListedMember.cs
Normal file
@@ -0,0 +1,17 @@
|
||||
#nullable enable
|
||||
using NodaTime;
|
||||
|
||||
namespace PluralKit.Core
|
||||
{
|
||||
// TODO: is inheritance here correct?
|
||||
public class ListedMember: PKMember
|
||||
{
|
||||
public ulong? LastMessage { get; }
|
||||
public Instant? LastSwitchTime { get; }
|
||||
|
||||
public AnnualDate? AnnualBirthday =>
|
||||
Birthday != null
|
||||
? new AnnualDate(Birthday.Value.Month, Birthday.Value.Day)
|
||||
: (AnnualDate?) null;
|
||||
}
|
||||
}
|
14
PluralKit.Core/Database/Views/SystemFronter.cs
Normal file
14
PluralKit.Core/Database/Views/SystemFronter.cs
Normal file
@@ -0,0 +1,14 @@
|
||||
using NodaTime;
|
||||
|
||||
namespace PluralKit.Core
|
||||
{
|
||||
public class SystemFronter
|
||||
{
|
||||
public int SystemId { get; }
|
||||
public int SwitchId { get; }
|
||||
public Instant SwitchTimestamp { get; }
|
||||
public int MemberId { get; }
|
||||
public string MemberHid { get; }
|
||||
public string MemberName { get; }
|
||||
}
|
||||
}
|
50
PluralKit.Core/Database/Views/views.sql
Normal file
50
PluralKit.Core/Database/Views/views.sql
Normal file
@@ -0,0 +1,50 @@
|
||||
-- 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) 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;
|
||||
|
||||
-- Returns one row for every current fronter in a system, w/ some member info
|
||||
create view system_fronters as
|
||||
select
|
||||
systems.id as system_id,
|
||||
last_switch.id as switch_id,
|
||||
last_switch.timestamp as switch_timestamp,
|
||||
members.id as member_id,
|
||||
members.hid as member_hid,
|
||||
members.name as member_name
|
||||
from systems
|
||||
-- TODO: is there a more efficient way of doing this search? might need to index on timestamp if we haven't in prod
|
||||
inner join lateral (select * from switches where switches.system = systems.id order by timestamp desc limit 1) as last_switch on true
|
||||
|
||||
-- change to left join to handle memberless switches?
|
||||
inner join switch_members on switch_members.switch = last_switch.system
|
||||
inner join members on members.id = switch_members.member
|
||||
-- return them in order of the switch itself
|
||||
order by switch_members.id;
|
||||
|
||||
create view member_list as
|
||||
select members.*,
|
||||
-- Find last message ID
|
||||
-- max(mid) does full table scan, order by/limit uses index (dunno why, but it works!)
|
||||
(select mid from messages where messages.member = members.id order by mid desc nulls last limit 1) 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