Tsearch2 trigger firing... - Mailing list pgsql-general
From | Net Virtual Mailing Lists |
---|---|
Subject | Tsearch2 trigger firing... |
Date | |
Msg-id | 20041015093924.24704@mail.e-na.net Whole thread Raw |
In response to | Rules and locking within a transaction?... ("Net Virtual Mailing Lists" <mailinglists@net-virtual.com>) |
Responses |
Re: Tsearch2 trigger firing...
|
List | pgsql-general |
Hello, I have a table that uses tsearch2 and, of course, and index and trigger to keep everything updated..... Something like: CREATE TABLE sometable ( id SERIAL, someinteger INTEGER sometext TEXT, sometext2 TEXT, sometext3 TEXT, sometext_fti TSVECTOR ); UPDATE sometable SET sometext_fti=to_tsvector('default', COALESCE(sometext, '')); CREATE INDEX sometext_fti_idx ON sometable USING gist(sometext_fti); CREATE TRIGGER text_update BEFORE UPDATE OR INSERT ON sometable FOR EACH ROW EXECUTE PROCEDURE tsearch2(sometext_fti, sometable); There are two issues: #1. I need a way to be able to do a full-text search any combination of sometext, sometext2, and sometext3... So far the only way I've been able to figure out to do this is to actually create additional fields and indexes for all combinations (a total of 7), like the following: CREATE TABLE sometable ( id SERIAL, someinteger INTEGER, sometext_fti TSVECTOR, sometext TEXT, sometext_fti TSVECTOR, sometext2 TEXT, sometext2_fti TSVECTOR, sometext3 TEXT, sometext3_fti TSVECTOR sometext1_2_fti TSVECTOR sometext1_3_fti TSVECTOR sometext2_3_fti TSVECTOR sometext1_2_3_fti TSVECTOR ); UPDATE sometable SET sometext_fti=to_tsvector('default', COALESCE(sometext, '')); CREATE INDEX sometext_fti_idx ON sometable USING gist(sometext_fti); CREATE TRIGGER sometext_update BEFORE UPDATE OR INSERT ON sometable FOR EACH ROW EXECUTE PROCEDURE tsearch2(sometext_fti, sometable); UPDATE sometable SET sometext2_fti=to_tsvector('default', COALESCE(sometext2, '')); CREATE INDEX sometext2_fti_idx ON sometable USING gist(sometext2_fti); CREATE TRIGGER sometext2_update BEFORE UPDATE OR INSERT ON sometable FOR EACH ROW EXECUTE PROCEDURE tsearch2(sometext2_fti, sometable); UPDATE sometable SET sometext3_fti=to_tsvector('default', COALESCE(sometext3, '')); CREATE INDEX sometext3_fti_idx ON sometable USING gist(sometext3_fti); CREATE TRIGGER sometext3_update BEFORE UPDATE OR INSERT ON sometable FOR EACH ROW EXECUTE PROCEDURE tsearch2(sometext3_fti, sometable); UPDATE sometable SET sometext1_2_fti=to_tsvector('default', COALESCE(sometext1, '')||' '||COALESC(sometext2, '')); CREATE INDEX sometext1_2_fti_idx ON sometable USING gist(sometext1_2_fti); CREATE TRIGGER sometext1_2_update BEFORE UPDATE OR INSERT ON sometable FOR EACH ROW EXECUTE PROCEDURE tsearch2(sometext_1_2_fti, sometable); UPDATE sometable SET sometext1_3_fti=to_tsvector('default', COALESCE(sometext1, '')||' '||COALESC(sometext3, '')); CREATE INDEX sometext1_3_fti_idx ON sometable USING gist(sometext1_3_fti); CREATE TRIGGER sometext1_3_update BEFORE UPDATE OR INSERT ON sometable FOR EACH ROW EXECUTE PROCEDURE tsearch2(sometext1_3_fti, sometable); UPDATE sometable SET sometext2_3_fti=to_tsvector('default', COALESCE(sometext2, '')||' '||COALESC(sometext3, '')); CREATE INDEX sometext2_3_fti_idx ON sometable USING gist(sometext2_3_fti); CREATE TRIGGER sometext2_3_update BEFORE UPDATE OR INSERT ON sometable FOR EACH ROW EXECUTE PROCEDURE tsearch2(sometext2_3_fti, sometable); UPDATE sometable SET sometext1_2_3_fti=to_tsvector('default', COALESCE(sometext1, '')||' '||COALESCE(sometext2, '')||' '||COALESC(sometext3, '')); CREATE INDEX sometext1_2_3_fti_idx ON sometable USING gist(sometext1_2_3_fti); CREATE TRIGGER sometext1_2_3_update BEFORE UPDATE OR INSERT ON sometable FOR EACH ROW EXECUTE PROCEDURE tsearch2(sometext1_2_3_fti, sometable); ... of course, this creates an enormous load on the server for any update/delete operation... I tried just creating 3 indexes (one for each field) and doing a query like: SELECT * FROM sometable WHERE sometext1 @@ to_tsquery('default', 'postgres') OR sometext2 @@ to_tsquery('default', 'postgres') OR sometext3 @@ to_tsquery('default', 'postgres') -- but found this to be enormously expensive for queries.... .. with the arrangement above, I make some decision as to which field to query, for example: SELECT * FROM sometable WHERE sometext1_2_3 @@ to_tsquery('default', 'postgres'); -- this executes MUCH faster .. is there some way to get the best of both worlds here or am I trying to jam a square peg into a round hole?... #2. When doing an update on the above table, such as: "UPDATE sometable SET someinteger=0", it ends up firing off the triggers which of course takes a long time to update... Is there someway to make the trigger only fire if a the field it is tied to is updated?.... This is not a Thanks as always! - Greg
pgsql-general by date: