Migration

This commit is contained in:
Liam 2024-07-07 15:54:47 -04:00
parent 5636077a84
commit 6ac5230b2e
2 changed files with 500 additions and 0 deletions

View file

@ -0,0 +1,109 @@
defmodule Philomena.Repo.Migrations.NewNotifications do
use Ecto.Migration
@categories [
channel_live: [channels: :channel_id],
forum_post: [topics: :topic_id, posts: :post_id],
forum_topic: [topics: :topic_id],
gallery_image: [galleries: :gallery_id],
image_comment: [images: :image_id, comments: :comment_id],
image_merge: [images: :target_id, images: :source_id]
]
def up do
for {category, refs} <- @categories do
create table("#{category}_notifications", primary_key: false) do
for {target_table_name, reference_name} <- refs do
add reference_name, references(target_table_name, on_delete: :delete_all), null: false
end
add :user_id, references(:users, on_delete: :delete_all), null: false
timestamps(inserted_at: :created_at, type: :utc_datetime)
add :read, :boolean, default: false, null: false
end
{_primary_table_name, primary_ref_name} = hd(refs)
create index("#{category}_notifications", [:user_id, primary_ref_name], unique: true)
create index("#{category}_notifications", [:user_id, "updated_at desc"])
create index("#{category}_notifications", [:user_id, :read])
for {_target_table_name, reference_name} <- refs do
create index("#{category}_notifications", [reference_name])
end
end
insert_statements =
"""
insert into channel_live_notifications (channel_id, user_id, created_at, updated_at)
select n.actor_id, un.user_id, n.created_at, n.updated_at
from unread_notifications un
join notifications n on un.notification_id = n.id
where n.actor_type = 'Channel'
and exists(select 1 from channels c where c.id = n.actor_id)
and exists(select 1 from users u where u.id = un.user_id);
insert into forum_post_notifications (topic_id, post_id, user_id, created_at, updated_at)
select n.actor_id, n.actor_child_id, un.user_id, n.created_at, n.updated_at
from unread_notifications un
join notifications n on un.notification_id = n.id
where n.actor_type = 'Topic'
and n.actor_child_type = 'Post'
and n.action = 'posted a new reply in'
and exists(select 1 from topics t where t.id = n.actor_id)
and exists(select 1 from posts p where p.id = n.actor_child_id)
and exists(select 1 from users u where u.id = un.user_id);
insert into forum_topic_notifications (topic_id, user_id, created_at, updated_at)
select n.actor_id, un.user_id, n.created_at, n.updated_at
from unread_notifications un
join notifications n on un.notification_id = n.id
where n.actor_type = 'Topic'
and n.actor_child_type = 'Post'
and n.action <> 'posted a new reply in'
and exists(select 1 from topics t where t.id = n.actor_id)
and exists(select 1 from users u where u.id = un.user_id);
insert into gallery_image_notifications (gallery_id, user_id, created_at, updated_at)
select n.actor_id, un.user_id, n.created_at, n.updated_at
from unread_notifications un
join notifications n on un.notification_id = n.id
where n.actor_type = 'Gallery'
and exists(select 1 from galleries g where g.id = n.actor_id)
and exists(select 1 from users u where u.id = un.user_id);
insert into image_comment_notifications (image_id, comment_id, user_id, created_at, updated_at)
select n.actor_id, n.actor_child_id, un.user_id, n.created_at, n.updated_at
from unread_notifications un
join notifications n on un.notification_id = n.id
where n.actor_type = 'Image'
and n.actor_child_type = 'Comment'
and exists(select 1 from images i where i.id = n.actor_id)
and exists(select 1 from comments c where c.id = n.actor_child_id)
and exists(select 1 from users u where u.id = un.user_id);
insert into image_merge_notifications (target_id, source_id, user_id, created_at, updated_at)
select n.actor_id, regexp_replace(n.action, '[a-z#]+', '', 'g')::bigint, un.user_id, n.created_at, n.updated_at
from unread_notifications un
join notifications n on un.notification_id = n.id
where n.actor_type = 'Image'
and n.actor_child_type is null
and exists(select 1 from images i where i.id = n.actor_id)
and exists(select 1 from images i where i.id = regexp_replace(n.action, '[a-z#]+', '', 'g')::integer)
and exists(select 1 from users u where u.id = un.user_id);
"""
# These statements should not be run by the migration in production.
# Run them manually in psql instead.
if System.get_env("MIX_ENV") != "prod" do
for stmt <- String.split(insert_statements, "\n\n") do
execute(stmt)
end
end
end
def down do
for {category, _refs} <- @categories do
drop table("#{category}_notifications")
end
end
end

View file

@ -198,6 +198,19 @@ CREATE SEQUENCE public.badges_id_seq
ALTER SEQUENCE public.badges_id_seq OWNED BY public.badges.id; ALTER SEQUENCE public.badges_id_seq OWNED BY public.badges.id;
--
-- Name: channel_live_notifications; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.channel_live_notifications (
channel_id bigint NOT NULL,
user_id bigint NOT NULL,
created_at timestamp(0) without time zone NOT NULL,
updated_at timestamp(0) without time zone NOT NULL,
read boolean DEFAULT false NOT NULL
);
-- --
-- Name: channel_subscriptions; Type: TABLE; Schema: public; Owner: - -- Name: channel_subscriptions; Type: TABLE; Schema: public; Owner: -
-- --
@ -620,6 +633,20 @@ CREATE SEQUENCE public.fingerprint_bans_id_seq
ALTER SEQUENCE public.fingerprint_bans_id_seq OWNED BY public.fingerprint_bans.id; ALTER SEQUENCE public.fingerprint_bans_id_seq OWNED BY public.fingerprint_bans.id;
--
-- Name: forum_post_notifications; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.forum_post_notifications (
topic_id bigint NOT NULL,
post_id bigint NOT NULL,
user_id bigint NOT NULL,
created_at timestamp(0) without time zone NOT NULL,
updated_at timestamp(0) without time zone NOT NULL,
read boolean DEFAULT false NOT NULL
);
-- --
-- Name: forum_subscriptions; Type: TABLE; Schema: public; Owner: - -- Name: forum_subscriptions; Type: TABLE; Schema: public; Owner: -
-- --
@ -630,6 +657,19 @@ CREATE TABLE public.forum_subscriptions (
); );
--
-- Name: forum_topic_notifications; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.forum_topic_notifications (
topic_id bigint NOT NULL,
user_id bigint NOT NULL,
created_at timestamp(0) without time zone NOT NULL,
updated_at timestamp(0) without time zone NOT NULL,
read boolean DEFAULT false NOT NULL
);
-- --
-- Name: forums; Type: TABLE; Schema: public; Owner: - -- Name: forums; Type: TABLE; Schema: public; Owner: -
-- --
@ -709,6 +749,19 @@ CREATE SEQUENCE public.galleries_id_seq
ALTER SEQUENCE public.galleries_id_seq OWNED BY public.galleries.id; ALTER SEQUENCE public.galleries_id_seq OWNED BY public.galleries.id;
--
-- Name: gallery_image_notifications; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.gallery_image_notifications (
gallery_id bigint NOT NULL,
user_id bigint NOT NULL,
created_at timestamp(0) without time zone NOT NULL,
updated_at timestamp(0) without time zone NOT NULL,
read boolean DEFAULT false NOT NULL
);
-- --
-- Name: gallery_interactions; Type: TABLE; Schema: public; Owner: - -- Name: gallery_interactions; Type: TABLE; Schema: public; Owner: -
-- --
@ -750,6 +803,20 @@ CREATE TABLE public.gallery_subscriptions (
); );
--
-- Name: image_comment_notifications; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.image_comment_notifications (
image_id bigint NOT NULL,
comment_id bigint NOT NULL,
user_id bigint NOT NULL,
created_at timestamp(0) without time zone NOT NULL,
updated_at timestamp(0) without time zone NOT NULL,
read boolean DEFAULT false NOT NULL
);
-- --
-- Name: image_faves; Type: TABLE; Schema: public; Owner: - -- Name: image_faves; Type: TABLE; Schema: public; Owner: -
-- --
@ -837,6 +904,20 @@ CREATE SEQUENCE public.image_intensities_id_seq
ALTER SEQUENCE public.image_intensities_id_seq OWNED BY public.image_intensities.id; ALTER SEQUENCE public.image_intensities_id_seq OWNED BY public.image_intensities.id;
--
-- Name: image_merge_notifications; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.image_merge_notifications (
target_id bigint NOT NULL,
source_id bigint NOT NULL,
user_id bigint NOT NULL,
created_at timestamp(0) without time zone NOT NULL,
updated_at timestamp(0) without time zone NOT NULL,
read boolean DEFAULT false NOT NULL
);
-- --
-- Name: image_sources; Type: TABLE; Schema: public; Owner: - -- Name: image_sources; Type: TABLE; Schema: public; Owner: -
-- --
@ -2894,6 +2975,160 @@ ALTER TABLE ONLY public.versions
ADD CONSTRAINT versions_pkey PRIMARY KEY (id); ADD CONSTRAINT versions_pkey PRIMARY KEY (id);
--
-- Name: channel_live_notifications_channel_id_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX channel_live_notifications_channel_id_index ON public.channel_live_notifications USING btree (channel_id);
--
-- Name: channel_live_notifications_user_id_channel_id_index; Type: INDEX; Schema: public; Owner: -
--
CREATE UNIQUE INDEX channel_live_notifications_user_id_channel_id_index ON public.channel_live_notifications USING btree (user_id, channel_id);
--
-- Name: channel_live_notifications_user_id_read_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX channel_live_notifications_user_id_read_index ON public.channel_live_notifications USING btree (user_id, read);
--
-- Name: channel_live_notifications_user_id_updated_at_desc_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX channel_live_notifications_user_id_updated_at_desc_index ON public.channel_live_notifications USING btree (user_id, updated_at DESC);
--
-- Name: forum_post_notifications_post_id_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX forum_post_notifications_post_id_index ON public.forum_post_notifications USING btree (post_id);
--
-- Name: forum_post_notifications_topic_id_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX forum_post_notifications_topic_id_index ON public.forum_post_notifications USING btree (topic_id);
--
-- Name: forum_post_notifications_user_id_read_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX forum_post_notifications_user_id_read_index ON public.forum_post_notifications USING btree (user_id, read);
--
-- Name: forum_post_notifications_user_id_topic_id_index; Type: INDEX; Schema: public; Owner: -
--
CREATE UNIQUE INDEX forum_post_notifications_user_id_topic_id_index ON public.forum_post_notifications USING btree (user_id, topic_id);
--
-- Name: forum_post_notifications_user_id_updated_at_desc_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX forum_post_notifications_user_id_updated_at_desc_index ON public.forum_post_notifications USING btree (user_id, updated_at DESC);
--
-- Name: forum_topic_notifications_topic_id_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX forum_topic_notifications_topic_id_index ON public.forum_topic_notifications USING btree (topic_id);
--
-- Name: forum_topic_notifications_user_id_read_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX forum_topic_notifications_user_id_read_index ON public.forum_topic_notifications USING btree (user_id, read);
--
-- Name: forum_topic_notifications_user_id_topic_id_index; Type: INDEX; Schema: public; Owner: -
--
CREATE UNIQUE INDEX forum_topic_notifications_user_id_topic_id_index ON public.forum_topic_notifications USING btree (user_id, topic_id);
--
-- Name: forum_topic_notifications_user_id_updated_at_desc_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX forum_topic_notifications_user_id_updated_at_desc_index ON public.forum_topic_notifications USING btree (user_id, updated_at DESC);
--
-- Name: gallery_image_notifications_gallery_id_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX gallery_image_notifications_gallery_id_index ON public.gallery_image_notifications USING btree (gallery_id);
--
-- Name: gallery_image_notifications_user_id_gallery_id_index; Type: INDEX; Schema: public; Owner: -
--
CREATE UNIQUE INDEX gallery_image_notifications_user_id_gallery_id_index ON public.gallery_image_notifications USING btree (user_id, gallery_id);
--
-- Name: gallery_image_notifications_user_id_read_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX gallery_image_notifications_user_id_read_index ON public.gallery_image_notifications USING btree (user_id, read);
--
-- Name: gallery_image_notifications_user_id_updated_at_desc_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX gallery_image_notifications_user_id_updated_at_desc_index ON public.gallery_image_notifications USING btree (user_id, updated_at DESC);
--
-- Name: image_comment_notifications_comment_id_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX image_comment_notifications_comment_id_index ON public.image_comment_notifications USING btree (comment_id);
--
-- Name: image_comment_notifications_image_id_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX image_comment_notifications_image_id_index ON public.image_comment_notifications USING btree (image_id);
--
-- Name: image_comment_notifications_user_id_image_id_index; Type: INDEX; Schema: public; Owner: -
--
CREATE UNIQUE INDEX image_comment_notifications_user_id_image_id_index ON public.image_comment_notifications USING btree (user_id, image_id);
--
-- Name: image_comment_notifications_user_id_read_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX image_comment_notifications_user_id_read_index ON public.image_comment_notifications USING btree (user_id, read);
--
-- Name: image_comment_notifications_user_id_updated_at_desc_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX image_comment_notifications_user_id_updated_at_desc_index ON public.image_comment_notifications USING btree (user_id, updated_at DESC);
-- --
-- Name: image_intensities_index; Type: INDEX; Schema: public; Owner: - -- Name: image_intensities_index; Type: INDEX; Schema: public; Owner: -
-- --
@ -2901,6 +3136,41 @@ ALTER TABLE ONLY public.versions
CREATE INDEX image_intensities_index ON public.image_intensities USING btree (nw, ne, sw, se); CREATE INDEX image_intensities_index ON public.image_intensities USING btree (nw, ne, sw, se);
--
-- Name: image_merge_notifications_source_id_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX image_merge_notifications_source_id_index ON public.image_merge_notifications USING btree (source_id);
--
-- Name: image_merge_notifications_target_id_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX image_merge_notifications_target_id_index ON public.image_merge_notifications USING btree (target_id);
--
-- Name: image_merge_notifications_user_id_read_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX image_merge_notifications_user_id_read_index ON public.image_merge_notifications USING btree (user_id, read);
--
-- Name: image_merge_notifications_user_id_target_id_index; Type: INDEX; Schema: public; Owner: -
--
CREATE UNIQUE INDEX image_merge_notifications_user_id_target_id_index ON public.image_merge_notifications USING btree (user_id, target_id);
--
-- Name: image_merge_notifications_user_id_updated_at_desc_index; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX image_merge_notifications_user_id_updated_at_desc_index ON public.image_merge_notifications USING btree (user_id, updated_at DESC);
-- --
-- Name: image_sources_image_id_source_index; Type: INDEX; Schema: public; Owner: - -- Name: image_sources_image_id_source_index; Type: INDEX; Schema: public; Owner: -
-- --
@ -4175,6 +4445,22 @@ CREATE UNIQUE INDEX user_tokens_context_token_index ON public.user_tokens USING
CREATE INDEX user_tokens_user_id_index ON public.user_tokens USING btree (user_id); CREATE INDEX user_tokens_user_id_index ON public.user_tokens USING btree (user_id);
--
-- Name: channel_live_notifications channel_live_notifications_channel_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY public.channel_live_notifications
ADD CONSTRAINT channel_live_notifications_channel_id_fkey FOREIGN KEY (channel_id) REFERENCES public.channels(id) ON DELETE CASCADE;
--
-- Name: channel_live_notifications channel_live_notifications_user_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY public.channel_live_notifications
ADD CONSTRAINT channel_live_notifications_user_id_fkey FOREIGN KEY (user_id) REFERENCES public.users(id) ON DELETE CASCADE;
-- --
-- Name: channels fk_rails_021c624081; Type: FK CONSTRAINT; Schema: public; Owner: - -- Name: channels fk_rails_021c624081; Type: FK CONSTRAINT; Schema: public; Owner: -
-- --
@ -4967,6 +5253,110 @@ ALTER TABLE ONLY public.gallery_subscriptions
ADD CONSTRAINT fk_rails_fa77f3cebe FOREIGN KEY (gallery_id) REFERENCES public.galleries(id) ON UPDATE CASCADE ON DELETE CASCADE; ADD CONSTRAINT fk_rails_fa77f3cebe FOREIGN KEY (gallery_id) REFERENCES public.galleries(id) ON UPDATE CASCADE ON DELETE CASCADE;
--
-- Name: forum_post_notifications forum_post_notifications_post_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY public.forum_post_notifications
ADD CONSTRAINT forum_post_notifications_post_id_fkey FOREIGN KEY (post_id) REFERENCES public.posts(id) ON DELETE CASCADE;
--
-- Name: forum_post_notifications forum_post_notifications_topic_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY public.forum_post_notifications
ADD CONSTRAINT forum_post_notifications_topic_id_fkey FOREIGN KEY (topic_id) REFERENCES public.topics(id) ON DELETE CASCADE;
--
-- Name: forum_post_notifications forum_post_notifications_user_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY public.forum_post_notifications
ADD CONSTRAINT forum_post_notifications_user_id_fkey FOREIGN KEY (user_id) REFERENCES public.users(id) ON DELETE CASCADE;
--
-- Name: forum_topic_notifications forum_topic_notifications_topic_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY public.forum_topic_notifications
ADD CONSTRAINT forum_topic_notifications_topic_id_fkey FOREIGN KEY (topic_id) REFERENCES public.topics(id) ON DELETE CASCADE;
--
-- Name: forum_topic_notifications forum_topic_notifications_user_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY public.forum_topic_notifications
ADD CONSTRAINT forum_topic_notifications_user_id_fkey FOREIGN KEY (user_id) REFERENCES public.users(id) ON DELETE CASCADE;
--
-- Name: gallery_image_notifications gallery_image_notifications_gallery_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY public.gallery_image_notifications
ADD CONSTRAINT gallery_image_notifications_gallery_id_fkey FOREIGN KEY (gallery_id) REFERENCES public.galleries(id) ON DELETE CASCADE;
--
-- Name: gallery_image_notifications gallery_image_notifications_user_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY public.gallery_image_notifications
ADD CONSTRAINT gallery_image_notifications_user_id_fkey FOREIGN KEY (user_id) REFERENCES public.users(id) ON DELETE CASCADE;
--
-- Name: image_comment_notifications image_comment_notifications_comment_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY public.image_comment_notifications
ADD CONSTRAINT image_comment_notifications_comment_id_fkey FOREIGN KEY (comment_id) REFERENCES public.comments(id) ON DELETE CASCADE;
--
-- Name: image_comment_notifications image_comment_notifications_image_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY public.image_comment_notifications
ADD CONSTRAINT image_comment_notifications_image_id_fkey FOREIGN KEY (image_id) REFERENCES public.images(id) ON DELETE CASCADE;
--
-- Name: image_comment_notifications image_comment_notifications_user_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY public.image_comment_notifications
ADD CONSTRAINT image_comment_notifications_user_id_fkey FOREIGN KEY (user_id) REFERENCES public.users(id) ON DELETE CASCADE;
--
-- Name: image_merge_notifications image_merge_notifications_source_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY public.image_merge_notifications
ADD CONSTRAINT image_merge_notifications_source_id_fkey FOREIGN KEY (source_id) REFERENCES public.images(id) ON DELETE CASCADE;
--
-- Name: image_merge_notifications image_merge_notifications_target_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY public.image_merge_notifications
ADD CONSTRAINT image_merge_notifications_target_id_fkey FOREIGN KEY (target_id) REFERENCES public.images(id) ON DELETE CASCADE;
--
-- Name: image_merge_notifications image_merge_notifications_user_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY public.image_merge_notifications
ADD CONSTRAINT image_merge_notifications_user_id_fkey FOREIGN KEY (user_id) REFERENCES public.users(id) ON DELETE CASCADE;
-- --
-- Name: image_sources image_sources_image_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: - -- Name: image_sources image_sources_image_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
-- --
@ -5056,3 +5446,4 @@ INSERT INTO public."schema_migrations" (version) VALUES (20211107130226);
INSERT INTO public."schema_migrations" (version) VALUES (20211219194836); INSERT INTO public."schema_migrations" (version) VALUES (20211219194836);
INSERT INTO public."schema_migrations" (version) VALUES (20220321173359); INSERT INTO public."schema_migrations" (version) VALUES (20220321173359);
INSERT INTO public."schema_migrations" (version) VALUES (20240723122759); INSERT INTO public."schema_migrations" (version) VALUES (20240723122759);
INSERT INTO public."schema_migrations" (version) VALUES (20240728191353);