Browse Source

Add topic tags to search

Previously, search only covered topic titles and markdown. This adds
tags to it as well, and will make it easier to add other things in the
future since there's now a custom function instead of using the built-in
one that only supports text columns.
merge-requests/48/head
Deimos 6 years ago
parent
commit
30d1e1b564
  1. 105
      tildes/alembic/versions/5a7dc1032efc_add_tags_to_topic_search_vector.py
  2. 18
      tildes/sql/init/triggers/topics/topics.sql

105
tildes/alembic/versions/5a7dc1032efc_add_tags_to_topic_search_vector.py

@ -0,0 +1,105 @@
"""Add tags to topic search vector
Revision ID: 5a7dc1032efc
Revises: 22a8ed36a3c9
Create Date: 2018-10-16 02:09:33.528836
"""
from alembic import op
import sqlalchemy as sa
# revision identifiers, used by Alembic.
revision = "5a7dc1032efc"
down_revision = "22a8ed36a3c9"
branch_labels = None
depends_on = None
def upgrade():
op.execute("DROP TRIGGER topic_update_search_tsv_insert ON topics")
op.execute("DROP TRIGGER topic_update_search_tsv_update ON topics")
op.execute(
"""
CREATE OR REPLACE FUNCTION update_topic_search_tsv() RETURNS TRIGGER AS $$
BEGIN
NEW.search_tsv :=
to_tsvector(NEW.title) ||
to_tsvector(coalesce(NEW.markdown, '')) ||
-- convert tags to space-separated string and replace periods with spaces
to_tsvector(replace(array_to_string(NEW.tags, ' '), '.', ' '));
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
"""
)
op.execute(
"""
CREATE TRIGGER topic_update_search_tsv_insert
BEFORE INSERT ON topics
FOR EACH ROW
EXECUTE PROCEDURE update_topic_search_tsv();
"""
)
op.execute(
"""
CREATE TRIGGER topic_update_search_tsv_update
BEFORE UPDATE ON topics
FOR EACH ROW
WHEN (
(OLD.title IS DISTINCT FROM NEW.title)
OR (OLD.markdown IS DISTINCT FROM NEW.markdown)
OR (OLD.tags IS DISTINCT FROM NEW.tags)
)
EXECUTE PROCEDURE update_topic_search_tsv();
"""
)
op.execute(
"""
UPDATE topics SET search_tsv =
to_tsvector(title) ||
to_tsvector(coalesce(markdown, '')) ||
to_tsvector(replace(array_to_string(tags, ' '), '.', ' '));
"""
)
def downgrade():
op.execute("DROP TRIGGER topic_update_search_tsv_update ON topics")
op.execute("DROP TRIGGER topic_update_search_tsv_insert ON topics")
op.execute("DROP FUNCTION update_topic_search_tsv()")
op.execute(
"""
CREATE TRIGGER topic_update_search_tsv_insert
BEFORE INSERT ON topics
FOR EACH ROW
EXECUTE PROCEDURE tsvector_update_trigger(search_tsv, 'pg_catalog.english', title, markdown);
"""
)
op.execute(
"""
CREATE TRIGGER topic_update_search_tsv_update
BEFORE UPDATE ON topics
FOR EACH ROW
WHEN (
(OLD.title IS DISTINCT FROM NEW.title)
OR (OLD.markdown IS DISTINCT FROM NEW.markdown)
)
EXECUTE PROCEDURE tsvector_update_trigger(search_tsv, 'pg_catalog.english', title, markdown);
"""
)
op.execute(
"""
UPDATE topics SET search_tsv =
to_tsvector(title) ||
to_tsvector(coalesce(markdown, ''));
"""
)

18
tildes/sql/init/triggers/topics/topics.sql

@ -17,10 +17,23 @@ CREATE TRIGGER delete_topic_set_deleted_time_update
EXECUTE PROCEDURE set_topic_deleted_time();
CREATE OR REPLACE FUNCTION update_topic_search_tsv() RETURNS TRIGGER AS $$
BEGIN
NEW.search_tsv :=
to_tsvector(NEW.title) ||
to_tsvector(coalesce(NEW.markdown, '')) ||
-- convert tags to space-separated string and replace periods with spaces
to_tsvector(replace(array_to_string(NEW.tags, ' '), '.', ' '));
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER topic_update_search_tsv_insert
BEFORE INSERT ON topics
FOR EACH ROW
EXECUTE PROCEDURE tsvector_update_trigger(search_tsv, 'pg_catalog.english', title, markdown);
EXECUTE PROCEDURE update_topic_search_tsv();
CREATE TRIGGER topic_update_search_tsv_update
BEFORE UPDATE ON topics
@ -28,5 +41,6 @@ CREATE TRIGGER topic_update_search_tsv_update
WHEN (
(OLD.title IS DISTINCT FROM NEW.title)
OR (OLD.markdown IS DISTINCT FROM NEW.markdown)
OR (OLD.tags IS DISTINCT FROM NEW.tags)
)
EXECUTE PROCEDURE tsvector_update_trigger(search_tsv, 'pg_catalog.english', title, markdown);
EXECUTE PROCEDURE update_topic_search_tsv();
Loading…
Cancel
Save