Is this planner choice easily explained?
От | Philip Warner |
---|---|
Тема | Is this planner choice easily explained? |
Дата | |
Msg-id | 5.1.0.14.0.20021121220031.052d5278@mail.rhyme.com.au обсуждение исходный текст |
Ответы |
Re: Is this planner choice easily explained?
|
Список | pgsql-bugs |
This is a summary from a thread on the dbmail mailing list. I am trying to understand some apparently odd behaviour with 7.2.1 and 7.2.3. Adding a LIMIT statement causes what seems like a very bad choice of strategy. The first statement is fine: explain SELECT messageblk FROM messageblks WHERE message_idnr = 100::bigint ORDER BY messageblk_idnr ; gives: Sort (cost=5793.33..5793.33 rows=1453 width=40) -> Index Scan using messageblks_msg_idx on messageblks (cost=0.00..5716.99 rows=1453 width=40) and returns almost instantly, whereas, just adding a limit: explain SELECT messageblk FROM messageblks WHERE message_idnr = 100::bigint ORDER BY messageblk_idnr limit 1; gives: Limit (cost=0.00..777.50 rows=1 width=40) -> Index Scan using messageblks_id_idx on messageblks (cost=0.00..1129984.15 rows=1453 width=40) which takes several minutes to run. The relevant metadata is: Table "messageblks" Column | Type | Modifiers -----------------+-------- +------------------------------------------------------- messageblk_idnr | bigint | not null default nextval('messageblk_idnr_seq'::text) message_idnr | bigint | not null default '0' messageblk | text | not null blocksize | bigint | not null default '0' Indexes: messageblks_msg_idx Primary key: messageblks_pkey Unique keys: messageblks_id_idx Index "messageblks_id_idx" Column | Type -----------------+-------- messageblk_idnr | bigint unique btree Index "messageblks_msg_idx" Column | Type --------------+-------- message_idnr | bigint btree If anyone could explain the likely reasons for the choice, I would be very interested. Even given the planner estimates, they don't look like sensible choices. ---------------------------------------------------------------- Philip Warner | __---_____ Albatross Consulting Pty. Ltd. |----/ - \ (A.B.N. 75 008 659 498) | /(@) ______---_ Tel: (+61) 0500 83 82 81 | _________ \ Fax: (+61) 03 5330 3172 | ___________ | Http://www.rhyme.com.au | / \| | --________-- PGP key available upon request, | / and from pgp5.ai.mit.edu:11371 |/
В списке pgsql-bugs по дате отправления: