Thread: encouraging index-only scans
A client is testing a migration from 9.1 to 9.2, and has found that a large number of queries run much faster if they use index-only scans. However, the only way he has found to get such a plan is by increasing the seq_page_cost to insanely high levels (3.5). Is there any approved way to encourage such scans that's a but less violent than this? cheers andrew
On 12/12/2012 04:32 PM, Tom Lane wrote: > Andrew Dunstan <andrew@dunslane.net> writes: >> A client is testing a migration from 9.1 to 9.2, and has found that a >> large number of queries run much faster if they use index-only scans. >> However, the only way he has found to get such a plan is by increasing >> the seq_page_cost to insanely high levels (3.5). Is there any approved >> way to encourage such scans that's a but less violent than this? > Is the pg_class.relallvisible estimate for the table realistic? They > might need a few more VACUUM and ANALYZE cycles to get it into the > neighborhood of reality, if not. That was the problem - I didn't know this hadn't been done. > > Keep in mind also that small values of random_page_cost necessarily > decrease the apparent advantage of index-only scans. If you think 3.5 > is an "insanely high" setting, I wonder whether you haven't driven those > numbers too far in the other direction to compensate for something else. Right. Thanks for the help. cheers andrew
On 12/12/2012 05:12 PM, Andrew Dunstan wrote: > > On 12/12/2012 04:32 PM, Tom Lane wrote: >> Andrew Dunstan <andrew@dunslane.net> writes: >>> A client is testing a migration from 9.1 to 9.2, and has found that a >>> large number of queries run much faster if they use index-only scans. >>> However, the only way he has found to get such a plan is by increasing >>> the seq_page_cost to insanely high levels (3.5). Is there any approved >>> way to encourage such scans that's a but less violent than this? >> Is the pg_class.relallvisible estimate for the table realistic? They >> might need a few more VACUUM and ANALYZE cycles to get it into the >> neighborhood of reality, if not. > > That was the problem - I didn't know this hadn't been done. > Actually, the table had been analysed but not vacuumed, so this kinda begs the question what will happen to this value on pg_upgrade? Will people's queries suddenly get slower until autovacuum kicks in on the table? cheers andrew
Andrew Dunstan <andrew@dunslane.net> writes: > A client is testing a migration from 9.1 to 9.2, and has found that a > large number of queries run much faster if they use index-only scans. > However, the only way he has found to get such a plan is by increasing > the seq_page_cost to insanely high levels (3.5). Is there any approved > way to encourage such scans that's a but less violent than this? Is the pg_class.relallvisible estimate for the table realistic? They might need a few more VACUUM and ANALYZE cycles to get it into the neighborhood of reality, if not. Keep in mind also that small values of random_page_cost necessarily decrease the apparent advantage of index-only scans. If you think 3.5 is an "insanely high" setting, I wonder whether you haven't driven those numbers too far in the other direction to compensate for something else. regards, tom lane