diff --git a/db/migrate/20191116001441_sync_indexes_with_production.rb b/db/migrate/20191116001441_sync_indexes_with_production.rb new file mode 100644 index 000000000..530cda4c4 --- /dev/null +++ b/db/migrate/20191116001441_sync_indexes_with_production.rb @@ -0,0 +1,41 @@ +class SyncIndexesWithProduction < ActiveRecord::Migration[6.0] + def change + execute "set statement_timeout = 0" + + # these indexes already existed in the production db but were undeclared. + add_index :wiki_page_versions, :updater_id + add_index :users, :inviter_id, where: "inviter_id IS NOT NULL" + add_index :tags, :post_count + add_index :posts, :approver_id, where: "approver_id IS NOT NULL" + add_index :post_votes, :created_at + add_index :mod_actions, :creator_id + add_index :mod_actions, :created_at + add_index :forum_posts, :updated_at + + # these indexes already existed but had different where clauses or + # uniqueness clauses in the production db. + remove_index :posts, column: :uploader_id + add_index :posts, :uploader_id, where: "uploader_id IS NOT NULL" + remove_index :posts, column: :parent_id + add_index :posts, :parent_id, where: "parent_id IS NOT NULL" + remove_index :ip_bans, column: :ip_addr + add_index :ip_bans, :ip_addr + remove_index :users, column: :email + add_index :users, :email, where: "email IS NOT NULL" + + reversible do |dir| + dir.up do + remove_index :tag_aliases, name: "index_tag_aliases_on_antecedent_name" + add_index :tag_aliases, :antecedent_name + end + + dir.down do + remove_index :tag_aliases, name: "index_tag_aliases_on_antecedent_name" + add_index :tag_aliases, :antecedent_name + end + end + + # this index was redundant with index_pools_on_lower_name. + remove_index :pools, column: :name, name: "index_pools_on_name" + end +end diff --git a/db/structure.sql b/db/structure.sql index f0ed11df2..2890fed0b 100644 --- a/db/structure.sql +++ b/db/structure.sql @@ -6519,6 +6519,13 @@ CREATE INDEX index_forum_posts_on_text_index ON public.forum_posts USING gin (te CREATE INDEX index_forum_posts_on_topic_id ON public.forum_posts USING btree (topic_id); +-- +-- Name: index_forum_posts_on_updated_at; Type: INDEX; Schema: public; Owner: - +-- + +CREATE INDEX index_forum_posts_on_updated_at ON public.forum_posts USING btree (updated_at); + + -- -- Name: index_forum_subscriptions_on_forum_topic_id; Type: INDEX; Schema: public; Owner: - -- @@ -6586,7 +6593,7 @@ CREATE INDEX index_forum_topics_on_updated_at ON public.forum_topics USING btree -- Name: index_ip_bans_on_ip_addr; Type: INDEX; Schema: public; Owner: - -- -CREATE UNIQUE INDEX index_ip_bans_on_ip_addr ON public.ip_bans USING btree (ip_addr); +CREATE INDEX index_ip_bans_on_ip_addr ON public.ip_bans USING btree (ip_addr); -- @@ -6596,6 +6603,20 @@ CREATE UNIQUE INDEX index_ip_bans_on_ip_addr ON public.ip_bans USING btree (ip_a CREATE INDEX index_janitor_trials_on_user_id ON public.janitor_trials USING btree (user_id); +-- +-- Name: index_mod_actions_on_created_at; Type: INDEX; Schema: public; Owner: - +-- + +CREATE INDEX index_mod_actions_on_created_at ON public.mod_actions USING btree (created_at); + + +-- +-- Name: index_mod_actions_on_creator_id; Type: INDEX; Schema: public; Owner: - +-- + +CREATE INDEX index_mod_actions_on_creator_id ON public.mod_actions USING btree (creator_id); + + -- -- Name: index_news_updates_on_created_at; Type: INDEX; Schema: public; Owner: - -- @@ -6694,13 +6715,6 @@ CREATE INDEX index_pools_on_is_deleted ON public.pools USING btree (is_deleted); CREATE INDEX index_pools_on_lower_name ON public.pools USING btree (lower((name)::text)); --- --- Name: index_pools_on_name; Type: INDEX; Schema: public; Owner: - --- - -CREATE INDEX index_pools_on_name ON public.pools USING btree (name); - - -- -- Name: index_pools_on_name_trgm; Type: INDEX; Schema: public; Owner: - -- @@ -6827,6 +6841,13 @@ CREATE INDEX index_post_replacements_on_creator_id ON public.post_replacements U CREATE INDEX index_post_replacements_on_post_id ON public.post_replacements USING btree (post_id); +-- +-- Name: index_post_votes_on_created_at; Type: INDEX; Schema: public; Owner: - +-- + +CREATE INDEX index_post_votes_on_created_at ON public.post_votes USING btree (created_at); + + -- -- Name: index_post_votes_on_post_id; Type: INDEX; Schema: public; Owner: - -- @@ -6841,6 +6862,13 @@ CREATE INDEX index_post_votes_on_post_id ON public.post_votes USING btree (post_ CREATE INDEX index_post_votes_on_user_id ON public.post_votes USING btree (user_id); +-- +-- Name: index_posts_on_approver_id; Type: INDEX; Schema: public; Owner: - +-- + +CREATE INDEX index_posts_on_approver_id ON public.posts USING btree (approver_id) WHERE (approver_id IS NOT NULL); + + -- -- Name: index_posts_on_created_at; Type: INDEX; Schema: public; Owner: - -- @@ -6915,7 +6943,7 @@ CREATE INDEX index_posts_on_mpixels ON public.posts USING btree (((((image_width -- Name: index_posts_on_parent_id; Type: INDEX; Schema: public; Owner: - -- -CREATE INDEX index_posts_on_parent_id ON public.posts USING btree (parent_id); +CREATE INDEX index_posts_on_parent_id ON public.posts USING btree (parent_id) WHERE (parent_id IS NOT NULL); -- @@ -6943,7 +6971,8 @@ CREATE INDEX index_posts_on_tags_index ON public.posts USING gin (tag_index); -- Name: index_posts_on_uploader_id; Type: INDEX; Schema: public; Owner: - -- -CREATE INDEX index_posts_on_uploader_id ON public.posts USING btree (uploader_id); +CREATE INDEX index_posts_on_uploader_id ON public.posts USING btree (uploader_id) WHERE (uploader_id IS NOT NULL); + -- -- Name: index_posts_on_uploader_ip_addr; Type: INDEX; Schema: public; Owner: - @@ -7071,6 +7100,13 @@ CREATE INDEX index_tags_on_name_prefix ON public.tags USING gin (regexp_replace( CREATE INDEX index_tags_on_name_trgm ON public.tags USING gin (name public.gin_trgm_ops); +-- +-- Name: index_tags_on_post_count; Type: INDEX; Schema: public; Owner: - +-- + +CREATE INDEX index_tags_on_post_count ON public.tags USING btree (post_count); + + -- -- Name: index_token_buckets_on_user_id; Type: INDEX; Schema: public; Owner: - -- @@ -7159,7 +7195,14 @@ CREATE INDEX index_users_on_created_at ON public.users USING btree (created_at); -- Name: index_users_on_email; Type: INDEX; Schema: public; Owner: - -- -CREATE UNIQUE INDEX index_users_on_email ON public.users USING btree (email); +CREATE INDEX index_users_on_email ON public.users USING btree (email) WHERE (email IS NOT NULL); + + +-- +-- Name: index_users_on_inviter_id; Type: INDEX; Schema: public; Owner: - +-- + +CREATE INDEX index_users_on_inviter_id ON public.users USING btree (inviter_id) WHERE (inviter_id IS NOT NULL); -- @@ -7190,6 +7233,13 @@ CREATE INDEX index_users_on_name_trgm ON public.users USING gin (name public.gin CREATE INDEX index_wiki_page_versions_on_created_at ON public.wiki_page_versions USING btree (created_at); +-- +-- Name: index_wiki_page_versions_on_updater_id; Type: INDEX; Schema: public; Owner: - +-- + +CREATE INDEX index_wiki_page_versions_on_updater_id ON public.wiki_page_versions USING btree (updater_id); + + -- -- Name: index_wiki_page_versions_on_updater_ip_addr; Type: INDEX; Schema: public; Owner: - -- @@ -7497,6 +7547,8 @@ INSERT INTO "schema_migrations" (version) VALUES ('20190926000912'), ('20191023191749'), ('20191024194544'), -('20191111004329'); +('20191111004329'), +('20191111024520'), +('20191116001441');