Chetan Suttraway wrote:
I am sorry but I am not able to got your points completely. My table definitions are as : Clause2 Table : CREATE TABLE clause2 ( id bigint NOT NULL DEFAULT nextval('clause_id_seq'::regclass), source_id integer, sentence_id integer, clause_id integer, tense character varying(30), clause text, CONSTRAINT pk_clause_demo_id PRIMARY KEY (id) ) WITH ( OIDS=FALSE ); CREATE INDEX idx_clause ON clause2 USING btree (clause_id, source_id, sentence_id); svo2 table :-- CREATE TABLE svo2 ( svo_id bigint NOT NULL DEFAULT nextval('svo_svo_id_seq'::regclass), doc_id integer, sentence_id integer, clause_id integer, negation integer, subject character varying(3000), verb character varying(3000), "object" character varying(3000), preposition character varying(3000), subject_type character varying(3000), object_type character varying(3000), subject_attribute character varying(3000), object_attribute character varying(3000), verb_attribute character varying(3000), subject_concept character varying(100), object_concept character varying(100), subject_sense character varying(100), object_sense character varying(100), subject_chain character varying(5000), object_chain character varying(5000), sub_type_id integer, obj_type_id integer, CONSTRAINT pk_svo_demo_id PRIMARY KEY (svo_id) ) WITH ( OIDS=FALSE ); CREATE INDEX idx_svo2 ON svo2 USING btree (clause_id, doc_id, sentence_id); Please correct me if I m wrong. I need to change the order of columns in indexes according to the filter conditions but in this query . After making set enable_mergejoin = false and random_page_cost =2.0 The problem remains the same.What is your recommendations for the new index so that the query runs even faster. I can change my original query to : explain analyze select c.clause,s.doc_id,s.subject,s.verb,s.object,s.subject_type,s.object_type from clause2 c, svo2 s where c.clause_id=s.clause_id and s.doc_id=c.source_id and c.sentence_id=s.sentence_id ; And the output is : QUERY PLAN ------------------------------------------------------------------------------------------------------------------------------------ Nested Loop (cost=0.00..128419720.68 rows=167324179 width=105) (actual time=11.179..285708.966 rows=30473117 loops=1) -> Seq Scan on svo2 s (cost=0.00..697537.60 rows=27471560 width=53) (actual time=0.013..19554.222 rows=27471560 loops=1) -> Index Scan using idx_clause on clause2 c (cost=0.00..4.63 rows=1 width=72) (actual time=0.006..0.007 rows=1 loops=27471560) Index Cond: ((c.clause_id = s.clause_id) AND (c.source_id = s.doc_id) AND (c.sentence_id = s.sentence_id)) Total runtime: 301599.274 ms Thanks & best Regards, Adarsh Sharma Regards, |