Re: Prepared statements and generic plans

Поиск
Список
Период
Сортировка
От 'bruce@momjian.us'
Тема Re: Prepared statements and generic plans
Дата
Msg-id 20160613194008.GA17745@momjian.us
обсуждение исходный текст
Ответ на Re: Prepared statements and generic plans  (Albe Laurenz <laurenz.albe@wien.gv.at>)
Ответы Re: Prepared statements and generic plans  ("David G. Johnston" <david.g.johnston@gmail.com>)
Re: Prepared statements and generic plans  (Albe Laurenz <laurenz.albe@wien.gv.at>)
Список pgsql-hackers
On Mon, Jun 13, 2016 at 01:26:04PM +0000, Albe Laurenz wrote:
> Bruce Momjian wrote:
> > Also, is it possible to do an EXPLAIN prepare() with the libpq/wire
> > protocol?  I can't do PREPARE EXPLAIN, but I can do EXPLAIN EXECUTE.
> > However, I don't see any way to inject EXPLAIN into the libpq/wire
> > prepare case.  Can you specify prepare(EXPLAIN SELECT)?  (PREPARE
> > EXPLAIN SELECT throws a syntax error.)
>
> I am not sure what you mean:
> EXPLAIN PREPARE to get EXPLAIN for PREPARE, or PREPARE ... FOR EXPLAIN
> to get an EXPLAIN statement with parameters.
> What should EXPLAIN PREPARE show that EXPLAIN SELECT wouldn't?
> Why the need for EXPLAIN statements with parameters?

Well, you can't use EXPLAIN with SQL PREPARE:

    test=> EXPLAIN PREPARE SELECT * FROM pg_class;
    ERROR:  syntax error at or near "PREPARE"
    LINE 1: EXPLAIN PREPARE SELECT * FROM pg_class;
                    ^
    test=> PREPARE EXPLAIN SELECT * FROM pg_class;
    ERROR:  syntax error at or near "SELECT"
    LINE 1: PREPARE EXPLAIN SELECT * FROM pg_class;
                        ^
You can only do EXPLAIN EXECUTE ..., which works fine, e.g.:

    EXPLAIN EXECUTE prep_c1(0);

However, for the wire protocol prepare/execute, how do you do EXPLAIN?
The only way I can see doing it is to put the EXPLAIN in the prepare
query, but I wasn't sure that works.  So, I just wrote and tested the
attached C program and it properly output the explain information, e.g.

    res = PQprepare(conn, "prep1", "EXPLAIN SELECT * FROM pg_language", 0, NULL);
                                    -------
generated:

    QUERY PLAN

    Seq Scan on pg_language  (cost=0.00..1.04 rows=4 width=114)

so that works --- good.

> > Looking at how the code behaves, it seems custom plans that are _more_
> > expensive (plus planning cost) than the generic plan switch to the
> > generic plan after five executions, as now documented.  Custom plans
> > that are significantly _cheaper_ than the generic plan _never_ use the
> > generic plan.
>
> Yes, that's what the suggested documentation improvement says as well,
> right?

Yes.  What is odd is that it isn't the plan of the actual supplied
parameters that is cheaper, just the generic plan that assumes each
distinct value in the query is equally likely to be used.  So, when we
say the generic plan is cheaper, it is just comparing the custom plan
with the supplied parameters vs. the generic plan --- it is not saying
that running the supplied constants with the generic plan will execute
faster, because in fact we might be using a sub-optimial generic plan.

For example, giving my test table that I posted earlier, if you ran the
most common constant (50% common) the first five time, the custom plan
would use a sequential scan.  On the sixth run of that same constant, a
bitmap scan generic plan would be used.  Now, that does have a lower
cost, but only for the _average_ distinct value, not for the 50%
constant that is being used.  A bitmap scan on a constant that would
normally use a sequential scan will take longer than even a sequential
scan, because if it didn't, the custom plan would have chosen the bitmap
scan.

I am not sure how we can improve things, but I wanted to clarify exactly
what is happening.

> > Updated patch attached.
>
> Upon re-read, one tiny question:
>
> !    Prepared statements can optionally use generic plans rather than
> !    re-planning with each set of supplied <command>EXECUTE</command> values.
>
> Maybe the "optionally" should be omitted, since the user has no choice.
>
> It is true that there is a cursor option CURSOR_OPT_CUSTOM_PLAN, but that
> cannot be used on the SQL level.

Right.  Updated patch attached.

--
  Bruce Momjian  <bruce@momjian.us>        http://momjian.us
  EnterpriseDB                             http://enterprisedb.com

+ As you are, so once was I. As I am, so you will be. +
+                     Ancient Roman grave inscription +

Вложения

В списке pgsql-hackers по дате отправления:

Предыдущее
От: Merlin Moncure
Дата:
Сообщение: Re: 10.0
Следующее
От: Tom Lane
Дата:
Сообщение: Re: ERROR: ORDER/GROUP BY expression not found in targetlist