Fix timeouts in source:<url> searches and bookmarklet.

* Change the source index on posts from `(lower(source) gin_trgm_ops) WHERE source != ''`
  to just `(source gin_trgm_ops)`. The WHERE clause prevented the index
  from being used in source:<url> searches because we didn't specify
  the `source != ''` clause in the search itself. Excluding blank
  sources only saved a marginal amount of space anyway. This fixes
  timeouts in source:<url> searches and in the bookmarklet (since we do
  a source dupe check on the upload page too).

* Also switch from indexing `lower(name)` to `name` on pools and users.
  We don't need to lowercase the column because GIN indexes can be used
  with both LIKE and ILIKE queries.
This commit is contained in:
evazion
2019-09-02 18:53:27 -05:00
parent ffc693ef37
commit 5df3b01ca2
7 changed files with 44 additions and 11 deletions

View File

@@ -197,7 +197,7 @@ class PostQueryBuilder
if q[:source]
if q[:source] == "none"
relation = relation.where("posts.source = ''")
relation = relation.where_like(:source, '')
else
relation = relation.where_ilike(:source, q[:source].downcase + "*")
end
@@ -205,7 +205,7 @@ class PostQueryBuilder
if q[:source_neg]
if q[:source_neg] == "none"
relation = relation.where("posts.source != ''")
relation = relation.where_not_like(:source, '')
else
relation = relation.where_not_ilike(:source, q[:source_neg].downcase + "*")
end

View File

@@ -18,11 +18,11 @@ class ApplicationRecord < ActiveRecord::Base
end
def where_ilike(attr, value)
where("lower(#{qualified_column_for(attr)}) LIKE ? ESCAPE E'\\\\'", value.mb_chars.downcase.to_escaped_for_sql_like)
where("#{qualified_column_for(attr)} ILIKE ? ESCAPE E'\\\\'", value.mb_chars.to_escaped_for_sql_like)
end
def where_not_ilike(attr, value)
where.not("lower(#{qualified_column_for(attr)}) LIKE ? ESCAPE E'\\\\'", value.mb_chars.downcase.to_escaped_for_sql_like)
where.not("#{qualified_column_for(attr)} ILIKE ? ESCAPE E'\\\\'", value.mb_chars.to_escaped_for_sql_like)
end
# https://www.postgresql.org/docs/current/static/functions-matching.html#FUNCTIONS-POSIX-REGEXP

View File

@@ -47,7 +47,7 @@ class Pool < ApplicationRecord
def name_matches(name)
name = normalize_name_for_search(name)
name = "*#{name}*" unless name =~ /\*/
where("lower(pools.name) like ? escape E'\\\\'", name.to_escaped_for_sql_like)
where_ilike(:name, name)
end
def default_order
@@ -108,7 +108,7 @@ class Pool < ApplicationRecord
if name =~ /^\d+$/
where("pools.id = ?", name.to_i).first
elsif name
where("lower(pools.name) = ?", normalize_name_for_search(name)).first
where_ilike(:name, normalize_name_for_search(name)).first
else
nil
end

View File

@@ -139,7 +139,7 @@ class User < ApplicationRecord
# XXX downcasing is the wrong way to do case-insensitive comparison for unicode (should use casefolding).
def find_by_name(name)
where("lower(name) = ?", normalize_name(name)).first
where_ilike(:name, normalize_name(name)).first
end
def normalize_name(name)

View File

@@ -0,0 +1,23 @@
class FixTrigramIndexesOnLowerNames < ActiveRecord::Migration[6.0]
def up
remove_index :posts, name: "index_posts_on_source_trgm"
add_index :posts, "source gin_trgm_ops", name: "index_posts_on_source_trgm", using: :gin
remove_index :users, name: "index_users_on_name_trgm"
add_index :users, "name gin_trgm_ops", name: "index_users_on_name_trgm", using: :gin
remove_index :pools, name: "index_pools_on_name_trgm"
add_index :pools, "name gin_trgm_ops", name: "index_pools_on_name_trgm", using: :gin
end
def down
remove_index :posts, name: "index_posts_on_source_trgm"
add_index :posts, "lower(source) gin_trgm_ops", name: "index_posts_on_source_trgm", using: :gin, where: "source != ''"
remove_index :users, name: "index_users_on_name_trgm"
add_index :users, "lower(name) gin_trgm_ops", name: "index_users_on_name_trgm", using: :gin
remove_index :pools, name: "index_pools_on_name_trgm"
add_index :pools, "lower(name) gin_trgm_ops", name: "index_pools_on_name_trgm", using: :gin
end
end

View File

@@ -6552,7 +6552,7 @@ CREATE INDEX index_pools_on_name ON public.pools USING btree (name);
-- Name: index_pools_on_name_trgm; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX index_pools_on_name_trgm ON public.pools USING gin (lower((name)::text) public.gin_trgm_ops);
CREATE INDEX index_pools_on_name_trgm ON public.pools USING gin (name public.gin_trgm_ops);
--
@@ -6769,7 +6769,7 @@ CREATE INDEX index_posts_on_pixiv_id ON public.posts USING btree (pixiv_id) WHER
-- Name: index_posts_on_source_trgm; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX index_posts_on_source_trgm ON public.posts USING gin (lower((source)::text) public.gin_trgm_ops) WHERE ((source)::text <> ''::text);
CREATE INDEX index_posts_on_source_trgm ON public.posts USING gin (source public.gin_trgm_ops);
--
@@ -7007,7 +7007,7 @@ CREATE UNIQUE INDEX index_users_on_name ON public.users USING btree (lower((name
-- Name: index_users_on_name_trgm; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX index_users_on_name_trgm ON public.users USING gin (lower((name)::text) public.gin_trgm_ops);
CREATE INDEX index_users_on_name_trgm ON public.users USING gin (name public.gin_trgm_ops);
--
@@ -7315,6 +7315,7 @@ INSERT INTO "schema_migrations" (version) VALUES
('20190827234625'),
('20190828005453'),
('20190829052629'),
('20190829055758');
('20190829055758'),
('20190902224045');

View File

@@ -52,6 +52,15 @@ class PoolTest < ActiveSupport::TestCase
end
end
context "Searching pools" do
should "find pools by name" do
@pool = FactoryBot.create(:pool, name: "Test Pool")
assert_equal(@pool.id, Pool.find_by_name("test pool").id)
assert_equal(@pool.id, Pool.search(name_matches: "test pool").first.id)
end
end
context "Creating a pool" do
setup do
@posts = FactoryBot.create_list(:post, 5)