diff --git a/bookwyrm/migrations/0198_book_search_vector_author_aliases.py b/bookwyrm/migrations/0198_book_search_vector_author_aliases.py new file mode 100644 index 000000000..491cb64bb --- /dev/null +++ b/bookwyrm/migrations/0198_book_search_vector_author_aliases.py @@ -0,0 +1,57 @@ +# Generated by Django 3.2.25 on 2024-03-20 15:52 + +from django.db import migrations +import pgtrigger.compiler +import pgtrigger.migrations + + +class Migration(migrations.Migration): + + dependencies = [ + ("bookwyrm", "0197_author_search_vector"), + ] + + operations = [ + pgtrigger.migrations.RemoveTrigger( + model_name="author", + name="reset_search_vector_on_author_edit", + ), + pgtrigger.migrations.RemoveTrigger( + model_name="book", + name="update_search_vector_on_book_edit", + ), + pgtrigger.migrations.AddTrigger( + model_name="author", + trigger=pgtrigger.compiler.Trigger( + name="reset_book_search_vector_on_author_edit", + sql=pgtrigger.compiler.UpsertTriggerSql( + func="WITH updated_books AS (SELECT book_id FROM bookwyrm_book_authors WHERE author_id = new.id ) UPDATE bookwyrm_book SET search_vector = '' FROM updated_books WHERE id = updated_books.book_id;RETURN NEW;", + hash="68422c0f29879c5802b82159dde45297eff53e73", + operation='UPDATE OF "name", "aliases"', + pgid="pgtrigger_reset_book_search_vector_on_author_edit_a50c7", + table="bookwyrm_author", + when="AFTER", + ), + ), + ), + pgtrigger.migrations.AddTrigger( + model_name="book", + trigger=pgtrigger.compiler.Trigger( + name="update_search_vector_on_book_edit", + sql=pgtrigger.compiler.UpsertTriggerSql( + func="WITH author_names AS (SELECT array_to_string(bookwyrm_author.name || bookwyrm_author.aliases, ' ') AS name_and_aliases FROM bookwyrm_author LEFT JOIN bookwyrm_book_authors ON bookwyrm_author.id = bookwyrm_book_authors.author_id WHERE bookwyrm_book_authors.book_id = new.id ) SELECT setweight(coalesce(nullif(to_tsvector('english', new.title), ''), to_tsvector('simple', new.title)), 'A') || setweight(to_tsvector('english', coalesce(new.subtitle, '')), 'B') || (SELECT setweight(to_tsvector('simple', coalesce(array_to_string(array_agg(name_and_aliases), ' '), '')), 'C') FROM author_names) || setweight(to_tsvector('english', coalesce(new.series, '')), 'D') INTO new.search_vector;RETURN NEW;", + hash="9324f5ca76a6f5e63931881d62d11da11f595b2c", + operation='INSERT OR UPDATE OF "title", "subtitle", "series", "search_vector"', + pgid="pgtrigger_update_search_vector_on_book_edit_bec58", + table="bookwyrm_book", + when="BEFORE", + ), + ), + ), + migrations.RunSQL( + # Recalculate search vector for all Books because it now includes + # Author aliases. + sql="UPDATE bookwyrm_book SET search_vector = NULL;", + reverse_sql="UPDATE bookwyrm_book SET search_vector = NULL;", + ), + ] diff --git a/bookwyrm/models/author.py b/bookwyrm/models/author.py index 9c3621c3d..9dc3962ad 100644 --- a/bookwyrm/models/author.py +++ b/bookwyrm/models/author.py @@ -92,9 +92,9 @@ class Author(BookDataModel): ), ), pgtrigger.Trigger( - name="reset_search_vector_on_author_edit", + name="reset_book_search_vector_on_author_edit", when=pgtrigger.After, - operation=pgtrigger.UpdateOf("name"), + operation=pgtrigger.UpdateOf("name", "aliases"), func=format_trigger( """WITH updated_books AS ( SELECT book_id diff --git a/bookwyrm/models/book.py b/bookwyrm/models/book.py index e167e2138..5dba6532f 100644 --- a/bookwyrm/models/book.py +++ b/bookwyrm/models/book.py @@ -246,24 +246,34 @@ class Book(BookDataModel): operation=pgtrigger.Insert | pgtrigger.UpdateOf("title", "subtitle", "series", "search_vector"), func=format_trigger( - """new.search_vector := - -- title, with priority A (parse in English, default to simple if empty) - setweight(COALESCE(nullif( - to_tsvector('english', new.title), ''), - to_tsvector('simple', new.title)), 'A') || - -- subtitle, with priority B (always in English?) - setweight(to_tsvector('english', COALESCE(new.subtitle, '')), 'B') || - -- list of authors, with priority C (TODO: add aliases?, bookwyrm-social#3063) - (SELECT setweight(to_tsvector('simple', COALESCE(array_to_string(ARRAY_AGG(bookwyrm_author.name), ' '), '')), 'C') - FROM bookwyrm_author - LEFT JOIN bookwyrm_book_authors - ON bookwyrm_author.id = bookwyrm_book_authors.author_id - WHERE bookwyrm_book_authors.book_id = new.id - ) || - --- last: series name, with lowest priority - setweight(to_tsvector('english', COALESCE(new.series, '')), 'D'); - RETURN new; - """ + """ + WITH author_names AS ( + SELECT array_to_string(bookwyrm_author.name || bookwyrm_author.aliases, ' ') AS name_and_aliases + FROM bookwyrm_author + LEFT JOIN bookwyrm_book_authors + ON bookwyrm_author.id = bookwyrm_book_authors.author_id + WHERE bookwyrm_book_authors.book_id = new.id + ) + SELECT + -- title, with priority A (parse in English, default to simple if empty) + setweight(COALESCE(nullif( + to_tsvector('english', new.title), ''), + to_tsvector('simple', new.title)), 'A') || + + -- subtitle, with priority B (always in English?) + setweight(to_tsvector('english', COALESCE(new.subtitle, '')), 'B') || + + -- list of authors names and aliases (with priority C) + (SELECT setweight(to_tsvector('simple', COALESCE(array_to_string(ARRAY_AGG(name_and_aliases), ' '), '')), 'C') + FROM author_names + ) || + + --- last: series name, with lowest priority + setweight(to_tsvector('english', COALESCE(new.series, '')), 'D') + + INTO new.search_vector; + RETURN new; + """ ), ) ]