Re: Issue with pg_get_functiondef

Поиск
Список
Период
Сортировка
От David Rowley
Тема Re: Issue with pg_get_functiondef
Дата
Msg-id CAApHDvoS9_7KdL3ghzvYSgUoqGU5b+Y54cD2_Yw4mQ+PcOJpmg@mail.gmail.com
обсуждение исходный текст
Ответ на Issue with pg_get_functiondef  (Edouard Tollet <edouard.tollet@stoik.io>)
Список pgsql-bugs
On Wed, 13 Dec 2023 at 00:26, Edouard Tollet <edouard.tollet@stoik.io> wrote:
> I'm having trouble understanding the following, I apologize in advance if it is not a bug.

> select * from (
>         select proname, prokind, pg_get_functiondef(oid) as def
>         from pg_proc
>         where pg_proc.prokind = 'f'
> ) def
> where def is not null;
> ERROR:  "array_agg" is an aggregate function

The EXPLAIN output shows you what's going on here:

                                  QUERY PLAN
-------------------------------------------------------------------------------
 Seq Scan on pg_proc  (cost=0.00..155.49 rows=3124 width=97)
   Filter: ((pg_get_functiondef(oid) IS NOT NULL) AND (prokind = 'f'::"char"))

You might think you're forcing the prokind = 'f' to be evaluated
before the "def is not null", but the query planner has optimisations
built-in and is able to pull up the subquery into the top-level query.
The planner also thinks evaluating the qual prokind = 'f' qual last is
more efficient.

This isn't a bug... or at least if we were to "fix it", many more
people would complain as we'd have to do something quite heavy-handed
like stop pulling up simple subqueries.  Even something less
heavy-handed like evaluating quals from deeper (original) levels first
could cause quite significant performance regressions.

The best solution for you is likely just to add an OFFSET 0 to the
subquery. That'll prevent the query planner from pulling up the
subquery into the top-level query.

David



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

Предыдущее
От: David Rowley
Дата:
Сообщение: Re: BUG #18240: Undefined behaviour in cash_mul_flt8() and friends
Следующее
От: Laurenz Albe
Дата:
Сообщение: Re: BUG #18242: pg_dump with non-superuser from pg14 to pg15 fails on ALTER FUNCTION