Add db-migrations folder.

Add future language metrics to query-exporter.
This commit is contained in:
mathan 2024-02-20 15:45:23 -08:00
parent da86ee3a1c
commit fba373f835
5 changed files with 11 additions and 1 deletions

View file

@ -0,0 +1,46 @@
alter table records rename to records_like;
create table records
(like records_like including defaults)
partition by list (collection);
drop index idx_repo_record_key;
drop index idx_repo_rev;
alter table records_like drop constraint records_pkey;
create unique index records_pkey on records (id, collection);
create table records_default
partition of records default;
create table records_post
partition of records for values in ('app.bsky.feed.post');
create table records_follow
partition of records for values in ('app.bsky.graph.follow');
create table records_block
partition of records for values in ('app.bsky.graph.block');
create table records_repost
partition of records for values in ('app.bsky.feed.repost');
create table records_profile
partition of records for values in ('app.bsky.actor.profile');
with moved_rows as (
delete from records_like r
where collection <> 'app.bsky.feed.like'
returning r.*
)
insert into records select * from moved_rows;
alter table records attach partition records_like for values in ('app.bsky.feed.like');
create index idx_like_subject
on records_like
(split_part(jsonb_extract_path_text(content, 'subject', 'uri'), '/', 3));
create index idx_follow_subject
on records_follow
(jsonb_extract_path_text(content, 'subject'));
create index idx_reply_subject
on records_post
(split_part(jsonb_extract_path_text(content, 'reply', 'parent', 'uri'), '/', 3));

View file

@ -0,0 +1,28 @@
create index post_langs on records_post using gin (jsonb_extract_path(content, 'langs') jsonb_ops);
-- There are invalid/non-conforming values that need to be handled somehow.
create function parse_timestamp(text)
returns timestamp
returns null on null input
immutable
as
$$
begin
begin
return $1::timestamp;
exception
when others then
return null;
end;
end;
$$
language plpgsql;
create index post_created_at on records_post (parse_timestamp(jsonb_extract_path_text(content, 'createdAt')));
create view posts as
select *, jsonb_extract_path(content, 'langs') as langs,
parse_timestamp(jsonb_extract_path_text(content, 'createdAt')) as created_at
from records_post;
explain select count(*) from posts where langs ? 'uk' and content_created_at > now() - interval '1 day';

22
db-migration/init.sql Normal file
View file

@ -0,0 +1,22 @@
insert into pds (host) values ('https://agaric.us-west.host.bsky.network'),
('https://amanita.us-east.host.bsky.network'),
('https://blewit.us-west.host.bsky.network'),
('https://boletus.us-west.host.bsky.network'),
('https://bsky.social'),
('https://chaga.us-west.host.bsky.network'),
('https://conocybe.us-west.host.bsky.network'),
('https://enoki.us-east.host.bsky.network'),
('https://hydnum.us-west.host.bsky.network'),
('https://inkcap.us-east.host.bsky.network'),
('https://lepista.us-west.host.bsky.network'),
('https://lionsmane.us-east.host.bsky.network'),
('https://maitake.us-west.host.bsky.network'),
('https://morel.us-east.host.bsky.network'),
('https://oyster.us-east.host.bsky.network'),
('https://porcini.us-east.host.bsky.network'),
('https://puffball.us-east.host.bsky.network'),
('https://russula.us-west.host.bsky.network'),
('https://shiitake.us-east.host.bsky.network'),
('https://shimeji.us-east.host.bsky.network'),
('https://verpa.us-west.host.bsky.network')
on conflict do nothing;