Created
April 9, 2011 09:21
-
-
Save orther/911266 to your computer and use it in GitHub Desktop.
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
-- Function: update_article_fts_index() | |
-- DROP FUNCTION update_article_fts_index(); | |
CREATE OR REPLACE FUNCTION update_article_fts_index() | |
RETURNS trigger AS | |
$BODY$ | |
BEGIN | |
-- Update the fts_index | |
NEW.fts_index = | |
setweight( to_tsvector( coalesce( (SELECT array_to_string(array(SELECT t.tag FROM articles_tags at JOIN tags t ON t.tag_id = at.tag_id WHERE at.article_id = NEW.article_id), ' ')) ,'')), 'A' ) || ' ' || | |
setweight( to_tsvector( coalesce(NEW.title,'')), 'B' ) || ' ' || | |
setweight( to_tsvector( coalesce(NEW.synopsis,'')), 'D' ) || ' ' || | |
setweight( to_tsvector( coalesce(NEW.body,'')),'D'); | |
-- Return the new row | |
RETURN NEW; | |
END | |
$BODY$ | |
LANGUAGE plpgsql VOLATILE | |
COST 100; | |
ALTER FUNCTION update_article_fts_index() OWNER TO think_done; |
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
-- how I would search for articles related to postgres | |
SELECT | |
ts_rank_cd(fts_index, q) AS rank, | |
article_id, title, synopsis, stat_quicktro, | |
to_char(date_created, 'Mon FMDD YYYY') AS created | |
FROM | |
articles, plainto_tsquery('postgres') q | |
WHERE | |
stat_active AND | |
q @@ fts_index |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment