stacker.news/prisma/migrations/20240415202735_index_item_o.../migration.sql

47 lines
2.2 KiB
MySQL
Raw Normal View History

Search bookmarks (#1075) * Support `is:bookmarked` search option to search my bookmarked items * Update the worker search module to include `bookmarkedBy: Array<Number>` which contains the list of user ids which have bookmarked a given item * Add a trigger on the `Bookmark` DB table to re-index the corresponding item when a bookmark is added/removed * Update the Search resolver to check for a `is:bookmarked` query option. If provided, include it as an option in the search request. This updates search to look for items which are bookmarked by the current user. By default, this preserves stacker privacy so you can only search your own bookmarks * Update the search page UI to show how to invoke searching your own bookmarks * undo `is:bookmarked` support, add `bookmarks` item in search select * short circuit return empty payload for anon requesting bookmarks * remove console.log for debugging * fix indexing a new item that has yet to be bookmarked * update db migration to re-index all existing bookmarked items one time * fix the case where deleting a bookmark doesn't trigger a new index of items explictly specify a `updatedAt` value when deleting a bookmark, to ensure that deleting a bookmark results in a new indexed version of the bookmarked item * update search indexer to use the latest of all three choices for the latest version * give bookmark index jobs longer expiration --------- Co-authored-by: Keyan <34140557+huumn@users.noreply.github.com> Co-authored-by: keyan <keyan.kousha+huumn@gmail.com>
2024-04-19 18:24:48 +00:00
CREATE OR REPLACE FUNCTION index_bookmarked_item() RETURNS TRIGGER AS $$
BEGIN
-- if a bookmark was created or updated, `NEW` will be used
IF NEW IS NOT NULL THEN
INSERT INTO pgboss.job (name, data) VALUES ('indexItem', jsonb_build_object('id', NEW."itemId"));
RETURN NEW;
END IF;
-- if a bookmark was deleted, `OLD` will be used
IF OLD IS NOT NULL THEN
-- include `updatedAt` in the `indexItem` job as `now()` to indicate when the indexed item should think it was updated
-- this is to facilitate the fact that deleted bookmarks do not show up when re-indexing the item, and therefore
-- we don't have a reliable way to calculate a more recent index version, to displace the prior version
INSERT INTO pgboss.job (name, data) VALUES ('indexItem', jsonb_build_object('id', OLD."itemId", 'updatedAt', now()));
RETURN OLD;
END IF;
-- This should never be reached
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
-- Re-index the bookmarked item when a bookmark changes, so new bookmarks are searchable
DROP TRIGGER IF EXISTS index_bookmarked_item ON "Bookmark";
CREATE TRIGGER index_bookmarked_item
AFTER INSERT OR UPDATE OR DELETE ON "Bookmark"
FOR EACH ROW
EXECUTE PROCEDURE index_bookmarked_item();
-- hack ... prisma doesn't know about our other schemas (e.g. pgboss)
-- and this is only really a problem on their "shadow database"
-- so we catch the exception it throws and ignore it
CREATE OR REPLACE FUNCTION reindex_all_current_bookmarked_items() RETURNS void AS $$
BEGIN
-- Re-index all existing bookmarked items so these bookmarks are searchable
INSERT INTO pgboss.job (name, data, priority, startafter, expirein)
SELECT 'indexItem', jsonb_build_object('id', "itemId"), -100, now() + interval '10 minutes', interval '1 day'
FROM "Bookmark"
GROUP BY "itemId";
EXCEPTION WHEN OTHERS THEN
-- catch the exception for prisma dev execution, but do nothing with it
END;
$$ LANGUAGE plpgsql;
-- execute the function once
SELECT reindex_all_current_bookmarked_items();
-- then drop it since we don't need it anymore
DROP FUNCTION reindex_all_current_bookmarked_items();