2020-06-13 19:49:31 +00:00
|
|
|
|
-- Returns one row per system, containing info about latest switch + array of member IDs (for future joins)
|
|
|
|
|
create view system_last_switch as
|
2022-03-30 08:36:22 +00:00
|
|
|
|
select systems.id as system,
|
2020-06-12 18:29:50 +00:00
|
|
|
|
last_switch.id as switch,
|
|
|
|
|
last_switch.timestamp as timestamp,
|
2021-06-09 10:23:23 +00:00
|
|
|
|
array(select member from switch_members where switch_members.switch = last_switch.id order by switch_members.id) as members
|
2020-06-12 18:29:50 +00:00
|
|
|
|
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,
|
2022-03-30 08:36:22 +00:00
|
|
|
|
|
2020-06-12 18:29:50 +00:00
|
|
|
|
-- Extract month/day from birthday and "force" the year identical (just using 4) -> month/day only sorting!
|
2022-03-30 08:36:22 +00:00
|
|
|
|
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,
|
2020-06-18 15:33:37 +00:00
|
|
|
|
|
|
|
|
|
-- Extract member description as seen by "the public"
|
2022-03-30 08:36:22 +00:00
|
|
|
|
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)
|
2020-06-18 15:33:37 +00:00
|
|
|
|
end as public_description
|
2020-08-21 15:08:49 +00:00
|
|
|
|
from members;
|
|
|
|
|
|
|
|
|
|
create view group_list as
|
|
|
|
|
select groups.*,
|
2020-08-25 23:50:24 +00:00
|
|
|
|
-- Find public group member count
|
|
|
|
|
(
|
2022-03-30 08:36:22 +00:00
|
|
|
|
select count(*) from group_members
|
|
|
|
|
inner join members on group_members.member_id = members.id
|
|
|
|
|
where
|
2020-08-25 23:50:24 +00:00
|
|
|
|
group_members.group_id = groups.id and members.member_visibility = 1
|
2022-01-15 03:30:02 +00:00
|
|
|
|
) as public_member_count,
|
|
|
|
|
-- Find private group member count
|
|
|
|
|
(
|
2022-03-30 08:36:22 +00:00
|
|
|
|
select count(*) from group_members
|
|
|
|
|
inner join members on group_members.member_id = members.id
|
|
|
|
|
where
|
2022-01-15 03:30:02 +00:00
|
|
|
|
group_members.group_id = groups.id
|
|
|
|
|
) as total_member_count
|
2020-08-21 15:08:49 +00:00
|
|
|
|
from groups;
|