From 51e9ea27729ff27ce65d06b6be61dca8b41f9e72 Mon Sep 17 00:00:00 2001 From: evazion Date: Sun, 10 Oct 2021 13:49:25 -0500 Subject: [PATCH] posts: add string_to_array(tag_string, ' ') index. This is preparation for removing tag_index and test_parser. --- ...ring_to_array_tag_string_index_on_posts.rb | 20 +++++++++++++++++++ db/structure.sql | 11 +++++++++- 2 files changed, 30 insertions(+), 1 deletion(-) create mode 100644 db/migrate/20211010181657_add_string_to_array_tag_string_index_on_posts.rb diff --git a/db/migrate/20211010181657_add_string_to_array_tag_string_index_on_posts.rb b/db/migrate/20211010181657_add_string_to_array_tag_string_index_on_posts.rb new file mode 100644 index 000000000..a7781b89d --- /dev/null +++ b/db/migrate/20211010181657_add_string_to_array_tag_string_index_on_posts.rb @@ -0,0 +1,20 @@ +class AddStringToArrayTagStringIndexOnPosts < ActiveRecord::Migration[6.1] + disable_ddl_transaction! + + def change + add_index :posts, "string_to_array(tag_string, ' ')", using: :gin, algorithm: :concurrently + + up_only do + # Set the statistics target on the index to 3000 so that Postgres will a) + # collect stats on the size of top 3000 largest tags and b) sample + # 3000*300 = 900k random posts to do so. This is necessary so that + # Postgres can generate good query plans based on the size of the tag. + # + # https://akorotkov.github.io/blog/2017/05/31/alter-index-weird/ + # https://www.postgresql.org/docs/current/planner-stats.html + # https://www.postgresql.org/docs/current/sql-alterindex.html + execute "ALTER INDEX index_posts_on_string_to_array_tag_string ALTER COLUMN 1 SET STATISTICS 3000" + execute "VACUUM (VERBOSE, ANALYZE) posts" + end + end +end diff --git a/db/structure.sql b/db/structure.sql index 4b098b712..768dd941a 100644 --- a/db/structure.sql +++ b/db/structure.sql @@ -4341,6 +4341,14 @@ CREATE INDEX index_posts_on_rating ON public.posts USING btree (rating) WHERE (r CREATE INDEX index_posts_on_source_trgm ON public.posts USING gin (source public.gin_trgm_ops); +-- +-- Name: index_posts_on_string_to_array_tag_string; Type: INDEX; Schema: public; Owner: - +-- + +CREATE INDEX index_posts_on_string_to_array_tag_string ON public.posts USING gin (string_to_array(tag_string, ' '::text)); +ALTER INDEX public.index_posts_on_string_to_array_tag_string ALTER COLUMN 1 SET STATISTICS 3000; + + -- -- Name: index_posts_on_tag_index; Type: INDEX; Schema: public; Owner: - -- @@ -5050,6 +5058,7 @@ INSERT INTO "schema_migrations" (version) VALUES ('20210921170444'), ('20210926123414'), ('20210926125826'), -('20211008091234'); +('20211008091234'), +('20211010181657');