]> Untitled Git - lemmy.git/commitdiff
Merge branch 'main' into split_user_table
authorDessalines <tyhou13@gmx.com>
Thu, 25 Feb 2021 17:34:00 +0000 (12:34 -0500)
committerDessalines <tyhou13@gmx.com>
Thu, 25 Feb 2021 17:34:00 +0000 (12:34 -0500)
crates/db_schema/src/source/user.rs
migrations/2021-02-14-041356_split_user_table/down.sql [new file with mode: 0644]
migrations/2021-02-14-041356_split_user_table/up.sql [new file with mode: 0644]

index d72929fa8ec2be08ebf8ad68c32192787b040c52..17e8734ccd81a68d66b3ab96a3c4b11ed156caf5 100644 (file)
@@ -7,34 +7,34 @@ use serde::Serialize;
 #[derive(Clone, Queryable, Identifiable, PartialEq, Debug, Serialize)]
 #[table_name = "user_"]
 pub struct User_ {
-  pub id: i32,
-  pub name: String,
-  pub preferred_username: Option<String>,
-  pub password_encrypted: String,
-  pub email: Option<String>,
-  pub avatar: Option<String>,
-  pub admin: bool,
-  pub banned: bool,
-  pub published: chrono::NaiveDateTime,
-  pub updated: Option<chrono::NaiveDateTime>,
-  pub show_nsfw: bool,
-  pub theme: String,
-  pub default_sort_type: i16,
-  pub default_listing_type: i16,
-  pub lang: String,
-  pub show_avatars: bool,
-  pub send_notifications_to_email: bool,
-  pub matrix_user_id: Option<String>,
-  pub actor_id: Url,
-  pub bio: Option<String>,
-  pub local: bool,
-  pub private_key: Option<String>,
-  pub public_key: Option<String>,
-  pub last_refreshed_at: chrono::NaiveDateTime,
-  pub banner: Option<String>,
-  pub deleted: bool,
-  pub inbox_url: Url,
-  pub shared_inbox_url: Option<Url>,
+  pub id: i32,                                  // person
+  pub name: String,                             // person
+  pub preferred_username: Option<String>,       // person
+  pub password_encrypted: String,               // local_user
+  pub email: Option<String>,                    // local_user
+  pub avatar: Option<String>,                   // person
+  pub admin: bool,                              // local_user
+  pub banned: bool,                             // person?
+  pub published: chrono::NaiveDateTime,         // person
+  pub updated: Option<chrono::NaiveDateTime>,   // person
+  pub show_nsfw: bool,                          // local_user
+  pub theme: String,                            // local_user
+  pub default_sort_type: i16,                   // local_user
+  pub default_listing_type: i16,                // local_user
+  pub lang: String,                             // local_user
+  pub show_avatars: bool,                       // local_user
+  pub send_notifications_to_email: bool,        // local_user
+  pub matrix_user_id: Option<String>,           // local_user
+  pub actor_id: Url,                            // person
+  pub bio: Option<String>,                      // person
+  pub local: bool,                              // person
+  pub private_key: Option<String>,              // person
+  pub public_key: Option<String>,               // person
+  pub last_refreshed_at: chrono::NaiveDateTime, // person
+  pub banner: Option<String>,                   // person
+  pub deleted: bool,                            // person
+  pub inbox_url: Url,                           // person
+  pub shared_inbox_url: Option<Url>,            // person
 }
 
 /// A safe representation of user, without the sensitive info
diff --git a/migrations/2021-02-14-041356_split_user_table/down.sql b/migrations/2021-02-14-041356_split_user_table/down.sql
new file mode 100644 (file)
index 0000000..c39a8ac
--- /dev/null
@@ -0,0 +1,242 @@
+-- user_ban
+alter table person_ban rename to user_ban;
+alter sequence person_ban_id_seq rename to user_ban_id_seq;
+alter index person_ban_pkey rename to user_ban_pkey;
+alter index person_ban_person_id_key rename to user_ban_user_id_key;
+alter table user_ban rename constraint person_ban_person_id_fkey to user_ban_user_id_fkey;
+
+-- user_mention
+alter table person_mention rename to user_mention;
+alter sequence person_mention_id_seq rename to user_mention_id_seq;
+alter index person_mention_pkey rename to user_mention_pkey;
+alter index person_mention_recipient_id_comment_id_key rename to user_mention_recipient_id_comment_id_key;
+alter table user_mention rename constraint person_mention_comment_id_fkey to user_mention_comment_id_fkey;
+alter table user_mention rename constraint person_mention_recipient_id_fkey to user_mention_recipient_id_fkey;
+
+-- User aggregates table
+alter table person_aggregates rename to user_aggregates;
+alter sequence person_aggregates_id_seq rename to user_aggregates_id_seq;
+alter table user_aggregates rename column person_id to user_id;
+
+-- Indexes
+alter index person_aggregates_pkey rename to user_aggregates_pkey;
+alter index idx_person_aggregates_comment_score rename to idx_user_aggregates_comment_score;
+alter index person_aggregates_person_id_key rename to user_aggregates_user_id_key;
+alter table user_aggregates rename constraint person_aggregates_person_id_fkey to user_aggregates_user_id_fkey;
+
+-- Redo the user_aggregates table
+drop trigger person_aggregates_person on person;
+drop trigger person_aggregates_post_count on post;
+drop trigger person_aggregates_post_score on post_like;
+drop trigger person_aggregates_comment_count on comment;
+drop trigger person_aggregates_comment_score on comment_like;
+drop function 
+  person_aggregates_person, 
+  person_aggregates_post_count,
+  person_aggregates_post_score,
+  person_aggregates_comment_count,
+  person_aggregates_comment_score;
+
+-- user_ table
+-- Drop views
+drop view person_alias_1, person_alias_2;
+
+-- Rename indexes
+alter index person__pkey rename to user__pkey;
+alter index idx_person_actor_id rename to idx_user_actor_id;
+alter index idx_person_inbox_url rename to idx_user_inbox_url;
+alter index idx_person_lower_actor_id rename to idx_user_lower_actor_id;
+alter index idx_person_published rename to idx_user_published;
+
+-- Rename triggers
+alter trigger site_aggregates_person_delete on person rename to site_aggregates_user_delete;
+alter trigger site_aggregates_person_insert on person rename to site_aggregates_user_insert;
+
+-- Rename the trigger functions
+alter function site_aggregates_person_delete() rename to site_aggregates_user_delete;
+alter function site_aggregates_person_insert() rename to site_aggregates_user_insert;
+
+-- Rename the table back to user_
+alter table person rename to user_;
+alter sequence person_id_seq rename to user__id_seq;
+
+-- Add the columns back in
+alter table user_
+  add column password_encrypted text not null default 'changeme',
+  add column email text,
+  add column admin boolean default false not null,
+  add column show_nsfw boolean default false not null,
+  add column theme character varying(20) default 'darkly'::character varying not null,
+  add column default_sort_type smallint default 0 not null,
+  add column default_listing_type smallint default 1 not null,
+  add column lang character varying(20) default 'browser'::character varying not null,
+  add column show_avatars boolean default true not null,
+  add column send_notifications_to_email boolean default false not null,
+  add column matrix_user_id text;
+
+-- Update the user_ table with the local_user data
+update user_ u set
+  password_encrypted = lu.password_encrypted,
+  email = lu.email,
+  admin = lu.admin,
+  show_nsfw = lu.show_nsfw,
+  theme = lu.theme,
+  default_sort_type = lu.default_sort_type,
+  default_listing_type = lu.default_listing_type,
+  lang = lu.lang,
+  show_avatars = lu.show_avatars,
+  send_notifications_to_email = lu.send_notifications_to_email,
+  matrix_user_id = lu.matrix_user_id
+from local_user lu
+where lu.user_id = u.id;
+
+create view user_alias_1 as select * from user_;
+create view user_alias_2 as select * from user_;
+
+drop table local_user;
+
+-- Add the user_aggregates table triggers
+
+-- initial user add
+create function user_aggregates_user()
+returns trigger language plpgsql
+as $$
+begin
+  IF (TG_OP = 'INSERT') THEN
+    insert into user_aggregates (user_id) values (NEW.id);
+  ELSIF (TG_OP = 'DELETE') THEN
+    delete from user_aggregates where user_id = OLD.id;
+  END IF;
+  return null;
+end $$;
+
+create trigger user_aggregates_user
+after insert or delete on user_
+for each row
+execute procedure user_aggregates_user();
+
+-- post count
+create function user_aggregates_post_count()
+returns trigger language plpgsql
+as $$
+begin
+  IF (TG_OP = 'INSERT') THEN
+    update user_aggregates 
+    set post_count = post_count + 1 where user_id = NEW.creator_id;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    update user_aggregates 
+    set post_count = post_count - 1 where user_id = OLD.creator_id;
+
+    -- If the post gets deleted, the score calculation trigger won't fire, 
+    -- so you need to re-calculate
+    update user_aggregates ua
+    set post_score = pd.score
+    from (
+      select u.id,
+      coalesce(0, sum(pl.score)) as score
+      -- User join because posts could be empty
+      from user_ u 
+      left join post p on u.id = p.creator_id
+      left join post_like pl on p.id = pl.post_id
+      group by u.id
+    ) pd 
+    where ua.user_id = OLD.creator_id;
+
+  END IF;
+  return null;
+end $$;
+
+create trigger user_aggregates_post_count
+after insert or delete on post
+for each row
+execute procedure user_aggregates_post_count();
+
+-- post score
+create function user_aggregates_post_score()
+returns trigger language plpgsql
+as $$
+begin
+  IF (TG_OP = 'INSERT') THEN
+    -- Need to get the post creator, not the voter
+    update user_aggregates ua
+    set post_score = post_score + NEW.score
+    from post p
+    where ua.user_id = p.creator_id and p.id = NEW.post_id;
+    
+  ELSIF (TG_OP = 'DELETE') THEN
+    update user_aggregates ua
+    set post_score = post_score - OLD.score
+    from post p
+    where ua.user_id = p.creator_id and p.id = OLD.post_id;
+  END IF;
+  return null;
+end $$;
+
+create trigger user_aggregates_post_score
+after insert or delete on post_like
+for each row
+execute procedure user_aggregates_post_score();
+
+-- comment count
+create function user_aggregates_comment_count()
+returns trigger language plpgsql
+as $$
+begin
+  IF (TG_OP = 'INSERT') THEN
+    update user_aggregates 
+    set comment_count = comment_count + 1 where user_id = NEW.creator_id;
+  ELSIF (TG_OP = 'DELETE') THEN
+    update user_aggregates 
+    set comment_count = comment_count - 1 where user_id = OLD.creator_id;
+
+    -- If the comment gets deleted, the score calculation trigger won't fire, 
+    -- so you need to re-calculate
+    update user_aggregates ua
+    set comment_score = cd.score
+    from (
+      select u.id,
+      coalesce(0, sum(cl.score)) as score
+      -- User join because comments could be empty
+      from user_ u 
+      left join comment c on u.id = c.creator_id
+      left join comment_like cl on c.id = cl.comment_id
+      group by u.id
+    ) cd 
+    where ua.user_id = OLD.creator_id;
+  END IF;
+  return null;
+end $$;
+
+create trigger user_aggregates_comment_count
+after insert or delete on comment
+for each row
+execute procedure user_aggregates_comment_count();
+
+-- comment score
+create function user_aggregates_comment_score()
+returns trigger language plpgsql
+as $$
+begin
+  IF (TG_OP = 'INSERT') THEN
+    -- Need to get the post creator, not the voter
+    update user_aggregates ua
+    set comment_score = comment_score + NEW.score
+    from comment c
+    where ua.user_id = c.creator_id and c.id = NEW.comment_id;
+  ELSIF (TG_OP = 'DELETE') THEN
+    update user_aggregates ua
+    set comment_score = comment_score - OLD.score
+    from comment c
+    where ua.user_id = c.creator_id and c.id = OLD.comment_id;
+  END IF;
+  return null;
+end $$;
+
+create trigger user_aggregates_comment_score
+after insert or delete on comment_like
+for each row
+execute procedure user_aggregates_comment_score();
+
+
+
diff --git a/migrations/2021-02-14-041356_split_user_table/up.sql b/migrations/2021-02-14-041356_split_user_table/up.sql
new file mode 100644 (file)
index 0000000..107ee4f
--- /dev/null
@@ -0,0 +1,273 @@
+-- Person
+-- Drop the 2 views user_alias_1, user_alias_2
+drop view user_alias_1, user_alias_2;
+
+-- rename the user_ table to person
+alter table user_ rename to person;
+alter sequence user__id_seq rename to person_id_seq;
+
+-- create a new table local_user
+create table local_user (
+  id serial primary key,
+  user_id int references person on update cascade on delete cascade not null,
+  password_encrypted text not null,
+  email text,
+  admin boolean default false not null,
+  show_nsfw boolean default false not null,
+  theme character varying(20) default 'darkly'::character varying not null,
+  default_sort_type smallint default 0 not null,
+  default_listing_type smallint default 1 not null,
+  lang character varying(20) default 'browser'::character varying not null,
+  show_avatars boolean default true not null,
+  send_notifications_to_email boolean default false not null,
+  matrix_user_id text,
+  unique (user_id)
+);
+
+-- Copy the local users over to the new table
+insert into local_user 
+(
+  user_id,
+  password_encrypted,
+  email,
+  admin,
+  show_nsfw,
+  theme,
+  default_sort_type,
+  default_listing_type,
+  lang,
+  show_avatars,
+  send_notifications_to_email,
+  matrix_user_id
+)
+select
+  id,
+  password_encrypted,
+  email,
+  admin,
+  show_nsfw,
+  theme,
+  default_sort_type,
+  default_listing_type,
+  lang,
+  show_avatars,
+  send_notifications_to_email,
+  matrix_user_id
+from person
+where local = true;
+
+-- Drop those columns from person
+alter table person 
+  drop column password_encrypted,
+  drop column email,
+  drop column admin,
+  drop column show_nsfw,
+  drop column theme,
+  drop column default_sort_type,
+  drop column default_listing_type,
+  drop column lang,
+  drop column show_avatars,
+  drop column send_notifications_to_email,
+  drop column matrix_user_id;
+
+-- Rename indexes
+alter index user__pkey rename to person__pkey;
+alter index idx_user_actor_id rename to idx_person_actor_id;
+alter index idx_user_inbox_url rename to idx_person_inbox_url;
+alter index idx_user_lower_actor_id rename to idx_person_lower_actor_id;
+alter index idx_user_published rename to idx_person_published;
+
+-- Rename triggers
+alter trigger site_aggregates_user_delete on person rename to site_aggregates_person_delete;
+alter trigger site_aggregates_user_insert on person rename to site_aggregates_person_insert;
+
+-- Rename the trigger functions
+alter function site_aggregates_user_delete() rename to site_aggregates_person_delete;
+alter function site_aggregates_user_insert() rename to site_aggregates_person_insert;
+
+-- Create views
+create view person_alias_1 as select * from person;
+create view person_alias_2 as select * from person;
+
+-- Redo user aggregates into person_aggregates
+alter table user_aggregates rename to person_aggregates;
+alter sequence user_aggregates_id_seq rename to person_aggregates_id_seq;
+alter table person_aggregates rename column user_id to person_id;
+
+-- index
+alter index user_aggregates_pkey rename to person_aggregates_pkey;
+alter index idx_user_aggregates_comment_score rename to idx_person_aggregates_comment_score;
+alter index user_aggregates_user_id_key rename to person_aggregates_person_id_key;
+alter table person_aggregates rename constraint user_aggregates_user_id_fkey to person_aggregates_person_id_fkey;
+
+
+-- Drop all the old triggers and functions
+drop trigger user_aggregates_user on person;
+drop trigger user_aggregates_post_count on post;
+drop trigger user_aggregates_post_score on post_like;
+drop trigger user_aggregates_comment_count on comment;
+drop trigger user_aggregates_comment_score on comment_like;
+drop function 
+  user_aggregates_user, 
+  user_aggregates_post_count,
+  user_aggregates_post_score,
+  user_aggregates_comment_count,
+  user_aggregates_comment_score;
+
+-- initial user add
+create function person_aggregates_person()
+returns trigger language plpgsql
+as $$
+begin
+  IF (TG_OP = 'INSERT') THEN
+    insert into person_aggregates (person_id) values (NEW.id);
+  ELSIF (TG_OP = 'DELETE') THEN
+    delete from person_aggregates where person_id = OLD.id;
+  END IF;
+  return null;
+end $$;
+
+create trigger person_aggregates_person
+after insert or delete on person
+for each row
+execute procedure person_aggregates_person();
+
+-- post count
+create function person_aggregates_post_count()
+returns trigger language plpgsql
+as $$
+begin
+  IF (TG_OP = 'INSERT') THEN
+    update person_aggregates 
+    set post_count = post_count + 1 where person_id = NEW.creator_id;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    update person_aggregates 
+    set post_count = post_count - 1 where person_id = OLD.creator_id;
+
+    -- If the post gets deleted, the score calculation trigger won't fire, 
+    -- so you need to re-calculate
+    update person_aggregates ua
+    set post_score = pd.score
+    from (
+      select u.id,
+      coalesce(0, sum(pl.score)) as score
+      -- User join because posts could be empty
+      from person u 
+      left join post p on u.id = p.creator_id
+      left join post_like pl on p.id = pl.post_id
+      group by u.id
+    ) pd 
+    where ua.person_id = OLD.creator_id;
+
+  END IF;
+  return null;
+end $$;
+
+create trigger person_aggregates_post_count
+after insert or delete on post
+for each row
+execute procedure person_aggregates_post_count();
+
+-- post score
+create function person_aggregates_post_score()
+returns trigger language plpgsql
+as $$
+begin
+  IF (TG_OP = 'INSERT') THEN
+    -- Need to get the post creator, not the voter
+    update person_aggregates ua
+    set post_score = post_score + NEW.score
+    from post p
+    where ua.person_id = p.creator_id and p.id = NEW.post_id;
+    
+  ELSIF (TG_OP = 'DELETE') THEN
+    update person_aggregates ua
+    set post_score = post_score - OLD.score
+    from post p
+    where ua.person_id = p.creator_id and p.id = OLD.post_id;
+  END IF;
+  return null;
+end $$;
+
+create trigger person_aggregates_post_score
+after insert or delete on post_like
+for each row
+execute procedure person_aggregates_post_score();
+
+-- comment count
+create function person_aggregates_comment_count()
+returns trigger language plpgsql
+as $$
+begin
+  IF (TG_OP = 'INSERT') THEN
+    update person_aggregates 
+    set comment_count = comment_count + 1 where person_id = NEW.creator_id;
+  ELSIF (TG_OP = 'DELETE') THEN
+    update person_aggregates 
+    set comment_count = comment_count - 1 where person_id = OLD.creator_id;
+
+    -- If the comment gets deleted, the score calculation trigger won't fire, 
+    -- so you need to re-calculate
+    update person_aggregates ua
+    set comment_score = cd.score
+    from (
+      select u.id,
+      coalesce(0, sum(cl.score)) as score
+      -- User join because comments could be empty
+      from person u 
+      left join comment c on u.id = c.creator_id
+      left join comment_like cl on c.id = cl.comment_id
+      group by u.id
+    ) cd 
+    where ua.person_id = OLD.creator_id;
+  END IF;
+  return null;
+end $$;
+
+create trigger person_aggregates_comment_count
+after insert or delete on comment
+for each row
+execute procedure person_aggregates_comment_count();
+
+-- comment score
+create function person_aggregates_comment_score()
+returns trigger language plpgsql
+as $$
+begin
+  IF (TG_OP = 'INSERT') THEN
+    -- Need to get the post creator, not the voter
+    update person_aggregates ua
+    set comment_score = comment_score + NEW.score
+    from comment c
+    where ua.person_id = c.creator_id and c.id = NEW.comment_id;
+  ELSIF (TG_OP = 'DELETE') THEN
+    update person_aggregates ua
+    set comment_score = comment_score - OLD.score
+    from comment c
+    where ua.person_id = c.creator_id and c.id = OLD.comment_id;
+  END IF;
+  return null;
+end $$;
+
+create trigger person_aggregates_comment_score
+after insert or delete on comment_like
+for each row
+execute procedure person_aggregates_comment_score();
+
+-- person_mention
+alter table user_mention rename to person_mention;
+alter sequence user_mention_id_seq rename to person_mention_id_seq;
+alter index user_mention_pkey rename to person_mention_pkey;
+alter index user_mention_recipient_id_comment_id_key rename to person_mention_recipient_id_comment_id_key;
+alter table person_mention rename constraint user_mention_comment_id_fkey to person_mention_comment_id_fkey;
+alter table person_mention rename constraint user_mention_recipient_id_fkey to person_mention_recipient_id_fkey;
+
+-- user_ban
+alter table user_ban rename to person_ban;
+alter sequence user_ban_id_seq rename to person_ban_id_seq;
+alter index user_ban_pkey rename to person_ban_pkey;
+alter index user_ban_user_id_key rename to person_ban_person_id_key;
+alter table person_ban rename constraint user_ban_user_id_fkey to person_ban_person_id_fkey;
+
+