Migrate tables

pull/4459/merge^2
Dull Bananas 2 months ago
parent f71e8b4f8c
commit 7cf8684eac

@ -103,9 +103,9 @@ diesel::table! {
person_id -> Int4,
comment_id -> Int4,
post_id -> Int4,
saved -> Nullable<Timestamptz>,
liked -> Nullable<Timestamptz>,
like_score -> Nullable<Int2>,
liked -> Nullable<Timestamptz>,
saved -> Nullable<Timestamptz>,
}
}
@ -189,11 +189,11 @@ diesel::table! {
diesel::table! {
community_actions (person_id, community_id) {
person_id -> Int4,
community_id -> Int4,
blocked -> Nullable<Timestamptz>,
person_id -> Int4,
followed -> Nullable<Timestamptz>,
follow_pending -> Nullable<Bool>,
blocked -> Nullable<Timestamptz>,
became_moderator -> Nullable<Timestamptz>,
received_ban -> Nullable<Timestamptz>,
ban_expires -> Nullable<Timestamptz>,
@ -618,11 +618,11 @@ diesel::table! {
diesel::table! {
person_actions (person_id, target_id) {
person_id -> Int4,
target_id -> Int4,
blocked -> Nullable<Timestamptz>,
person_id -> Int4,
followed -> Nullable<Timestamptz>,
follow_pending -> Nullable<Bool>,
blocked -> Nullable<Timestamptz>,
}
}
@ -685,12 +685,12 @@ diesel::table! {
}
diesel::table! {
post_actions (person_id, post_id) {
person_id -> Int4,
post_actions (person_id, post_id) {
post_id -> Int4,
person_id -> Int4,
read -> Nullable<Timestamptz>,
read_comments -> Nullable<Timestamptz>,
read_comments_amount -> Int8,
read -> Nullable<Timestamptz>,
saved -> Nullable<Timestamptz>,
liked -> Nullable<Timestamptz>,
like_score -> Nullable<Int2>,

@ -1,10 +1,5 @@
use crate::structs::VoteView;
use diesel::{
result::Error,
ExpressionMethods,
NullableExpressionMethods,
QueryDsl,
};
use diesel::{result::Error, ExpressionMethods, NullableExpressionMethods, QueryDsl};
use diesel_async::RunQueryDsl;
use lemmy_db_schema::{
aliases::creator_community_actions,

@ -0,0 +1,258 @@
-- For each new actions table:
-- * Create tables that are dropped in up.sql, and insert into them
-- * Do the opposite of the `ALTER TABLE` commands in up.sql, with `DELETE` being used to
-- only keep rows where the preserved action is not null
--
-- Create comment_like from comment_actions
CREATE TABLE comment_saved (
person_id int REFERENCES person ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
comment_id int REFERENCES COMMENT ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
published timestamptz DEFAULT now() NOT NULL,
PRIMARY KEY (person_id, comment_id)
);
INSERT INTO comment_saved (person_id, comment_id, published)
SELECT
person_id,
comment_id,
saved
FROM
comment_actions
WHERE
saved IS NOT NULL;
DELETE FROM comment_actions
WHERE liked IS NULL;
ALTER TABLE comment_actions RENAME TO comment_like;
ALTER TABLE comment_like RENAME COLUMN liked TO published;
ALTER TABLE comment_like RENAME COLUMN like_score TO score;
ALTER TABLE comment_like
DROP CONSTRAINT comment_actions_check_liked,
ALTER COLUMN published SET NOT NULL,
ALTER COLUMN published SET DEFAULT now(),
ALTER COLUMN score SET NOT NULL,
DROP COLUMN saved;
-- Create community_follower from community_actions
CREATE TABLE community_block (
person_id int REFERENCES person ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
community_id int REFERENCES community ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
published timestamptz DEFAULT now() NOT NULL,
PRIMARY KEY (person_id, community_id)
);
INSERT INTO community_block (person_id, community_id, published)
SELECT
person_id,
community_id,
blocked
FROM
community_actions
WHERE
blocked IS NOT NULL;
CREATE TABLE community_moderator (
community_id int REFERENCES community ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
person_id int REFERENCES person ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
published timestamptz DEFAULT now() NOT NULL,
PRIMARY KEY (person_id, community_id)
);
INSERT INTO community_moderator (community_id, person_id, published)
SELECT
community_id,
person_id,
became_moderator
FROM
community_actions
WHERE
became_moderator IS NOT NULL;
CREATE TABLE community_person_ban (
community_id int REFERENCES community ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
person_id int REFERENCES person ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
published timestamptz DEFAULT now() NOT NULL,
expires timestamptz,
PRIMARY KEY (person_id, community_id)
);
INSERT INTO community_person_ban (community_id, person_id, published, expires)
SELECT
community_id,
person_id,
received_ban,
ban_expires
FROM
community_actions
WHERE
received_ban IS NOT NULL;
DELETE FROM community_actions
WHERE followed IS NULL;
ALTER TABLE community_actions RENAME TO community_follower;
ALTER TABLE community_follower RENAME COLUMN followed TO published;
ALTER TABLE community_follower RENAME follow_pending TO pending;
ALTER TABLE community_follower
DROP CONSTRAINT community_actions_check_followed,
DROP CONSTRAINT community_actions_check_received_ban,
ALTER COLUMN published SET NOT NULL,
ALTER COLUMN published SET DEFAULT now(),
ALTER COLUMN pending SET NOT NULL,
-- This `SET DEFAULT` is done for community follow, but not person follow. It's not a mistake
-- in this migration. Believe it or not, `pending` only had a default value in community follow.
ALTER COLUMN pending SET DEFAULT FALSE,
DROP COLUMN blocked,
DROP COLUMN became_moderator,
DROP COLUMN received_ban,
DROP COLUMN ban_expires;
-- Create instance_block from instance_actions
DELETE FROM instance_actions
WHERE blocked IS NULL;
ALTER TABLE instance_actions RENAME TO instance_block;
ALTER TABLE instance_block RENAME COLUMN blocked TO published;
ALTER TABLE instance_block
ALTER COLUMN published SET NOT NULL,
ALTER COLUMN published SET DEFAULT now();
-- Create person_follower from person_actions
CREATE TABLE person_block (
person_id int REFERENCES person ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
target_id int REFERENCES person ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
published timestamptz DEFAULT now() NOT NULL,
PRIMARY KEY (person_id, target_id)
);
INSERT INTO person_block (person_id, target_id, published)
SELECT
person_id,
target_id,
blocked
FROM
person_actions
WHERE
blocked IS NOT NULL;
DELETE FROM person_actions
WHERE followed IS NULL;
ALTER TABLE person_actions RENAME TO person_follower;
ALTER TABLE person_follower RENAME COLUMN person_id TO follower_id;
ALTER TABLE person_follower RENAME COLUMN target_id TO person_id;
ALTER TABLE person_follower RENAME COLUMN followed TO published;
ALTER TABLE person_follower RENAME COLUMN follow_pending TO pending;
ALTER TABLE person_follower
DROP CONSTRAINT person_actions_check_followed,
ALTER COLUMN published SET NOT NULL,
ALTER COLUMN published SET DEFAULT now(),
ALTER COLUMN pending SET NOT NULL,
DROP COLUMN blocked;
-- Create post_read from post_actions
CREATE TABLE person_post_aggregates (
person_id int REFERENCES person ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
post_id int REFERENCES post ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
read_comments bigint DEFAULT 0 NOT NULL,
published timestamptz NOT NULL,
PRIMARY KEY (person_id, post_id)
);
INSERT INTO person_post_aggregates (person_id, post_id, read_comments, published)
SELECT
person_id,
post_id,
read_comments_amount,
read_comments
FROM
post_actions
WHERE
read_comments IS NOT NULL;
CREATE TABLE post_hide (
post_id int REFERENCES post ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
person_id int REFERENCES person ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
published timestamptz DEFAULT now() NOT NULL,
PRIMARY KEY (person_id, post_id)
);
INSERT INTO post_hide (post_id, person_id, published)
SELECT
post_id,
person_id,
hidden
FROM
post_actions
WHERE
hidden IS NOT NULL;
CREATE TABLE post_like (
post_id int REFERENCES post ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
person_id int REFERENCES person ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
score smallint NOT NULL,
published timestamptz DEFAULT now() NOT NULL,
PRIMARY KEY (person_id, post_id)
);
INSERT INTO post_like (post_id, person_id, score, published)
SELECT
post_id,
person_id,
like_score,
liked
FROM
post_actions
WHERE
liked IS NOT NULL;
CREATE TABLE post_saved (
post_id int REFERENCES post ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
person_id int REFERENCES person ON UPDATE CASCADE ON DELETE CASCADE NOT NULL,
published timestamptz DEFAULT now() NOT NULL,
PRIMARY KEY (person_id, post_id)
);
INSERT INTO post_saved (post_id, person_id, published)
SELECT
post_id,
person_id,
saved
FROM
post_actions
WHERE
saved IS NOT NULL;
DELETE FROM post_actions
WHERE read IS NULL;
ALTER TABLE post_actions RENAME TO post_read;
ALTER TABLE post_read RENAME COLUMN read TO published;
ALTER TABLE post_read
DROP CONSTRAINT post_actions_check_read_comments,
DROP CONSTRAINT post_actions_check_liked,
ALTER COLUMN published SET NOT NULL,
ALTER COLUMN published SET DEFAULT now(),
DROP COLUMN read_comments,
DROP COLUMN read_comments_amount,
DROP COLUMN saved,
DROP COLUMN liked,
DROP COLUMN like_score,
DROP COLUMN hidden;

@ -0,0 +1,248 @@
-- For each new actions table:
-- * Transform the table previously used for the most common action type into the new actions table,
-- which should only change the table's metadata instead of rewriting the rows
-- * Add actions from other old tables to the new table
--
-- Create comment_actions from comment_like
ALTER TABLE comment_like RENAME TO comment_actions;
ALTER TABLE comment_actions RENAME COLUMN published TO liked;
ALTER TABLE comment_actions RENAME COLUMN score TO like_score;
ALTER TABLE comment_actions
ALTER COLUMN liked DROP NOT NULL,
ALTER COLUMN liked DROP DEFAULT,
ALTER COLUMN like_score DROP NOT NULL,
ADD COLUMN saved timestamptz,
ADD CONSTRAINT comment_actions_check_liked CHECK ((liked IS NULL) = (like_score IS NULL));
WITH old_comment_saved AS (
DELETE FROM comment_saved
RETURNING
*)
INSERT INTO comment_actions (person_id, comment_id, saved, post_id)
SELECT
old_comment_saved.person_id,
old_comment_saved.comment_id,
old_comment_saved.published,
comment.post_id
FROM
old_comment_saved
INNER JOIN COMMENT ON comment.id = old_comment_saved.comment_id
ON CONFLICT (person_id,
comment_id)
DO UPDATE SET
saved = excluded.saved;
-- Create community_actions from community_follower
ALTER TABLE community_follower RENAME TO community_actions;
ALTER TABLE community_actions RENAME COLUMN published TO followed;
ALTER TABLE community_actions RENAME pending TO follow_pending;
ALTER TABLE community_actions
ALTER COLUMN followed DROP NOT NULL,
ALTER COLUMN followed DROP DEFAULT,
ALTER COLUMN follow_pending DROP NOT NULL,
-- This `DROP DEFAULT` is done for community follow, but not person follow. It's not a mistake
-- in this migration. Believe it or not, `pending` only had a default value in community follow.
ALTER COLUMN follow_pending DROP DEFAULT,
ADD COLUMN blocked timestamptz,
ADD COLUMN became_moderator timestamptz,
ADD COLUMN received_ban timestamptz,
ADD COLUMN ban_expires timestamptz,
ADD CONSTRAINT community_actions_check_followed CHECK ((followed IS NULL) = (follow_pending IS NULL)),
ADD CONSTRAINT community_actions_check_received_ban CHECK ((received_ban IS NULL, ban_expires IS NULL) != (FALSE, TRUE));
WITH old_community_block AS (
DELETE FROM community_block
RETURNING
*)
INSERT INTO community_actions (person_id, community_id, blocked)
SELECT
person_id,
community_id,
published
FROM
old_community_block
ON CONFLICT (person_id,
community_id)
DO UPDATE SET
person_id = excluded.person_id,
community_id = excluded.community_id,
blocked = excluded.blocked;
WITH old_community_moderator AS (
DELETE FROM community_moderator
RETURNING
*)
INSERT INTO community_actions (person_id, community_id, became_moderator)
SELECT
person_id,
community_id,
published
FROM
old_community_moderator
ON CONFLICT (person_id,
community_id)
DO UPDATE SET
person_id = excluded.person_id,
community_id = excluded.community_id,
became_moderator = excluded.became_moderator;
WITH old_community_person_ban AS (
DELETE FROM community_person_ban
RETURNING
*)
INSERT INTO community_actions (person_id, community_id, received_ban, ban_expires)
SELECT
person_id,
community_id,
published,
expires
FROM
old_community_person_ban
ON CONFLICT (person_id,
community_id)
DO UPDATE SET
person_id = excluded.person_id,
community_id = excluded.community_id,
received_ban = excluded.received_ban,
ban_expires = excluded.ban_expires;
-- Create instance_actions from instance_block
ALTER TABLE instance_block RENAME TO instance_actions;
ALTER TABLE instance_actions RENAME COLUMN published TO blocked;
ALTER TABLE instance_actions
ALTER COLUMN blocked DROP NOT NULL,
ALTER COLUMN blocked DROP DEFAULT;
-- Create person_actions from person_follower
ALTER TABLE person_follower RENAME TO person_actions;
ALTER TABLE person_actions RENAME COLUMN person_id TO target_id;
ALTER TABLE person_actions RENAME COLUMN follower_id TO person_id;
ALTER TABLE person_actions RENAME COLUMN published TO followed;
ALTER TABLE person_actions RENAME COLUMN pending TO follow_pending;
ALTER TABLE person_actions
ALTER COLUMN followed DROP NOT NULL,
ALTER COLUMN followed DROP DEFAULT,
ALTER COLUMN follow_pending DROP NOT NULL,
ADD COLUMN blocked timestamptz,
ADD CONSTRAINT person_actions_check_followed CHECK ((followed IS NULL) = (follow_pending IS NULL));
WITH old_person_block AS (
DELETE FROM person_block
RETURNING
*)
INSERT INTO person_actions (person_id, target_id, blocked)
SELECT
person_id,
target_id,
published
FROM
old_person_block
ON CONFLICT (person_id,
target_id)
DO UPDATE SET
person_id = excluded.person_id,
target_id = excluded.target_id,
blocked = excluded.blocked;
-- Create post_actions from post_read
ALTER TABLE post_read RENAME TO post_actions;
ALTER TABLE post_actions RENAME COLUMN published TO read;
ALTER TABLE post_actions
ALTER COLUMN read DROP NOT NULL,
ALTER COLUMN read DROP DEFAULT,
ADD COLUMN read_comments timestamptz,
-- TODO make nullable
ADD COLUMN read_comments_amount bigint NOT NULL,
ADD COLUMN saved timestamptz,
ADD COLUMN liked timestamptz,
ADD COLUMN like_score smallint,
ADD COLUMN hidden timestamptz,
ADD CONSTRAINT post_actions_check_read_comments CHECK ((read_comments IS NULL) = (read_comments_amount IS NULL)),
ADD CONSTRAINT post_actions_check_liked CHECK ((liked IS NULL) = (like_score IS NULL));
WITH old_person_post_aggregates AS (
DELETE FROM person_post_aggregates
RETURNING
*)
INSERT INTO post_actions (person_id, post_id, read_comments, read_comments_amount)
SELECT
person_id,
post_id,
published,
read_comments
FROM
old_person_post_aggregates
ON CONFLICT (person_id,
post_id)
DO UPDATE SET
read_comments = excluded.read_comments,
read_comments_amount = excluded.read_comments_amount;
WITH old_post_hide AS (
DELETE FROM post_hide
RETURNING
*)
INSERT INTO post_actions (person_id, post_id, hidden)
SELECT
person_id,
post_id,
published
FROM
old_post_hide
ON CONFLICT (person_id,
post_id)
DO UPDATE SET
hidden = excluded.hidden;
WITH old_post_like AS (
DELETE FROM post_like
RETURNING
*)
INSERT INTO post_actions (person_id, post_id, liked, like_score)
SELECT
person_id,
post_id,
published,
score
FROM
old_post_like
ON CONFLICT (person_id,
post_id)
DO UPDATE SET
liked = excluded.liked,
like_score = excluded.like_score;
WITH old_post_saved AS (
DELETE FROM post_saved
RETURNING
*)
INSERT INTO post_actions (person_id, post_id, saved)
SELECT
person_id,
post_id,
published
FROM
old_post_saved
ON CONFLICT (person_id,
post_id)
DO UPDATE SET
saved = excluded.saved;
-- Drop old tables
DROP TABLE comment_saved, community_block, community_moderator, community_person_ban, person_block, person_post_aggregates, post_hide, post_like, post_saved;
Loading…
Cancel
Save