| From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
|---|---|
| To: | Jeff Janes <jeff(dot)janes(at)gmail(dot)com> |
| Cc: | Sam Saffron <sam(dot)saffron(at)gmail(dot)com>, PGSQL Mailing List <pgsql-general(at)postgresql(dot)org> |
| Subject: | Re: Why is posgres picking a suboptimal plan for this query? |
| Date: | 2017-05-24 22:14:07 |
| Message-ID: | 3069.1495664047@sss.pgh.pa.us |
| Views: | Whole Thread | Raw Message | Download mbox | Resend email |
| Thread: | |
| Lists: | pgsql-general |
Jeff Janes <jeff(dot)janes(at)gmail(dot)com> writes:
> On Wed, May 24, 2017 at 1:42 PM, Sam Saffron <sam(dot)saffron(at)gmail(dot)com> wrote:
>> I have this query that is not picking the right index unless I hard code
>> dates:
>> ...
> Maybe it should first execute the subquery and then re-plan the rest of the
> query based on the results. But there is no provision for it to do that,
> and no concrete plans (that I know of) to implement such a thing.
I don't know of any plans for that, either.
>> The results here simply do not make sense to me, should I be piping
>> dates in here to avoid this issue and running 2 queries instead of 1?
> That is the most pragmatic approach. It isn't very nice, but the
> alternatives are worse.
You could probably get the behavior you want by replacing the subquery
with a "stable" function:
create function first_topic_unread_for(userid int) returns timestamp as
'select first_topic_unread_at from user_stats us where us.user_id = $1'
language sql stable;
SELECT "topics".* FROM "topics"
WHERE topics.last_unread_at >= first_topic_unread_for(1);
This should convince the planner to pre-run the function to get an
estimated result at plan time.
regards, tom lane
| From | Date | Subject | |
|---|---|---|---|
| Next Message | Sam Saffron | 2017-05-24 22:33:03 | Re: Why is posgres picking a suboptimal plan for this query? |
| Previous Message | Jeff Janes | 2017-05-24 21:43:35 | Re: Why is posgres picking a suboptimal plan for this query? |