JOINS and non use of indexes
От | Ian Cass |
---|---|
Тема | JOINS and non use of indexes |
Дата | |
Msg-id | 002001c1def9$e0fcc750$6602a8c0@salamander обсуждение исходный текст |
Ответы |
Re: JOINS and non use of indexes
|
Список | pgsql-sql |
Hi, Hope someone can spot where I'm going wrong here. I'm transferring a database & reporting scripts across from Oracle & a few of the SQL statements behave a little differently with regards to indexes. The one that's got me stumped at the moment is this... select * from messages, statusinds WHERE statusinds.gateway_id = messages.gateway_id AND (messages.client_id = '7' AND messages.user_name in ('U66515')) limit 5; It's using the index on the messages table. On Oracle, it would do a sequential index scan on the messages table & lookup the appropriate entry in the statusinds table using the index. However, on Postgres, I can't get it to use the statusinds index - it does a sequential scan through the entire table each time! As you can imagine, it's taking ages to do this where it used to take a few seconds on Oracle. I've tried explicitly specifying the JOIN type & I can't seem to find the right combination. I've tried doing a simple select on statusinds where gateway_id = 'xxx' and the explain tells me it's doing index lookups. Indexes are as follows... -- Index: statusinds_200204_ix1 CREATE UNIQUE INDEX statusinds_ix1 ON statusinds USING btree (gateway_id, status, logtime); -- Index: messages_200204_ix1 CREATE UNIQUE INDEX messages_200204_ix1 ON messages_200204 USING btree (host, qos_id); Explain plan.... Limit (cost=0.00..35.06 rows=5 width=620) -> Nested Loop (cost=0.00..30986063.51 rows=4418898 width=620) -> Append (cost=0.00..441.93 rows=111 width=496) -> Seq Scan on messages (cost=0.00..0.00 rows=1 width=496) -> Index Scan using messages_200203_ix2 on messages_200203 messages (cost=0.00..272.61 rows=68 width=383) -> Index Scan using messages_200204_ix2 on messages_200204 messages (cost=0.00..169.32 rows=42 width=384) -> Append (cost=0.00..180413.11 rows=7996912 width=124) -> Seq Scan on statusinds (cost=0.00..0.00 rows=1 width=124) -> Seq Scan on statusinds_200203 statusinds (cost=0.00..142835.73 rows=6292073 width=71) -> Seq Scan on statusinds_200204 statusinds (cost=0.00..37577.38 rows=1704838 width=65) (tables_YYYYMM are inherited) -- Ian Cass
В списке pgsql-sql по дате отправления: