wip: try partitioning by date
This commit is contained in:
parent
19a21ad3a9
commit
a41f6aa75c
8 changed files with 149 additions and 41 deletions
62
db-migration/migrations/obsolete/20240217_partition.sql
Normal file
62
db-migration/migrations/obsolete/20240217_partition.sql
Normal file
|
@ -0,0 +1,62 @@
|
|||
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');
|
||||
|
||||
ALTER TABLE records_like
|
||||
ADD CHECK (collection in ('app.bsky.feed.like'));
|
||||
|
||||
ALTER TABLE records_post
|
||||
ADD CHECK (collection in ('app.bsky.feed.post'));
|
||||
|
||||
ALTER TABLE records_follow
|
||||
ADD CHECK (collection in ('app.bsky.graph.follow'));
|
||||
|
||||
ALTER TABLE records_repost
|
||||
ADD CHECK (collection in ('app.bsky.feed.repost'));
|
||||
|
||||
ALTER TABLE records_profile
|
||||
ADD CHECK (collection in ('app.bsky.actor.profile'));
|
||||
|
||||
-- SLOW, can run overnight
|
||||
with moved_rows as (
|
||||
delete from records_like r
|
||||
where collection <> 'app.bsky.feed.like'
|
||||
returning r.*
|
||||
)
|
||||
insert into records select * from moved_rows;
|
||||
|
||||
-- ULTRA SLOW, DO NOT RUN on large DB
|
||||
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));
|
|
@ -0,0 +1,54 @@
|
|||
alter table records detach partition records_default;
|
||||
|
||||
create table records_list
|
||||
partition of records for values in ('app.bsky.graph.list');
|
||||
create table records_listblock
|
||||
partition of records for values in ('app.bsky.graph.listblock');
|
||||
create table records_listitem
|
||||
partition of records for values in ('app.bsky.graph.listitem');
|
||||
|
||||
ALTER TABLE records_list
|
||||
ADD CHECK (collection in ('app.bsky.graph.list'));
|
||||
|
||||
ALTER TABLE records_listblock
|
||||
ADD CHECK (collection in ('app.bsky.graph.listblock'));
|
||||
|
||||
ALTER TABLE records_listitem
|
||||
ADD CHECK (collection in ('app.bsky.graph.listitem'));
|
||||
|
||||
with moved_rows as (
|
||||
delete from records_default r
|
||||
where collection in ('app.bsky.graph.list', 'app.bsky.graph.listblock', 'app.bsky.graph.listitem')
|
||||
returning r.*
|
||||
)
|
||||
insert into records select * from moved_rows;
|
||||
|
||||
alter table records attach partition records_default default;
|
||||
|
||||
create index listitem_uri_subject
|
||||
on records_listitem
|
||||
(
|
||||
jsonb_extract_path_text(content, 'list'),
|
||||
jsonb_extract_path_text(content, 'subject'))
|
||||
include (deleted);
|
||||
|
||||
create index listitem_subject_uri
|
||||
on records_listitem
|
||||
(
|
||||
jsonb_extract_path_text(content, 'subject'),
|
||||
jsonb_extract_path_text(content, 'list'))
|
||||
include (deleted);
|
||||
|
||||
create view listitems as
|
||||
select *, jsonb_extract_path_text(content, 'list') as list,
|
||||
jsonb_extract_path_text(content, 'subject') as subject
|
||||
from records_listitem;
|
||||
|
||||
|
||||
create view lists as
|
||||
select records_list.*,
|
||||
jsonb_extract_path_text(content, 'name') as name,
|
||||
jsonb_extract_path_text(content, 'description') as description,
|
||||
jsonb_extract_path_text(content, 'purpose') as purpose,
|
||||
'at://' || repos.did || '/app.bsky.graph.list/' || rkey as uri
|
||||
from records_list join repos on records_list.repo = repos.id;
|
|
@ -0,0 +1,23 @@
|
|||
DROP VIEW posts;
|
||||
DROP VIEW lists;
|
||||
DROP VIEW listitems;
|
||||
|
||||
ALTER TABLE "records" ALTER COLUMN "deleted" TYPE boolean USING "deleted"::boolean;
|
||||
|
||||
create view posts as
|
||||
select *, jsonb_extract_path(content, 'langs') as langs,
|
||||
parse_timestamp(jsonb_extract_path_text(content, 'createdAt')) as content_created_at
|
||||
from records_post;
|
||||
|
||||
create view lists as
|
||||
select records_list.*,
|
||||
jsonb_extract_path_text(content, 'name') as name,
|
||||
jsonb_extract_path_text(content, 'description') as description,
|
||||
jsonb_extract_path_text(content, 'purpose') as purpose,
|
||||
'at://' || repos.did || '/app.bsky.graph.list/' || rkey as uri
|
||||
from records_list join repos on records_list.repo = repos.id;
|
||||
|
||||
create view listitems as
|
||||
select *, jsonb_extract_path_text(content, 'list') as list,
|
||||
jsonb_extract_path_text(content, 'subject') as subject
|
||||
from records_listitem;
|
Loading…
Add table
Add a link
Reference in a new issue