Issue with pg_get_functiondef

Поиск
Список
Период
Сортировка
От Edouard Tollet
Тема Issue with pg_get_functiondef
Дата
Msg-id CAMTFitQobPvh0_wbW_S-o7V03qcGkTWgZD-3ozXAbfzCcGuvgQ@mail.gmail.com
обсуждение исходный текст
Ответы Re: Issue with pg_get_functiondef  (David Rowley <dgrowleyml@gmail.com>)
Re: Issue with pg_get_functiondef  (Laurenz Albe <laurenz.albe@cybertec.at>)
Список pgsql-bugs

Dear PostgreSQL developers,

I'm having trouble understanding the following, I apologize in advance if it is not a bug.
The following query works and lists the functions name and definitions as set in my database:

select * from (
    select proname, prokind, pg_get_functiondef(oid) as def
    from pg_proc
    where pg_proc.prokind = 'f'
) def

however, if I add the filter where def is not null, it returns an error:
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

(with VERBOSITY set to verbose I get:
ERREUR:  42809: « array_agg » est une fonction d'agrégat
EMPLACEMENT : pg_get_functiondef, ruleutils.c : 2926)

I understand that somehow the query above is calling pg_get_functiondef on array_agg where I believe it shouldn't since array_agg has prokind set to a.
Filtering for pg_proc.prokind <> 'a' makes the query works again:
select * from (
    select proname, prokind, pg_get_functiondef(oid) as def
    from pg_proc
    where pg_proc.prokind <> 'a'
) def
where def is not null;

I get an error if I write:
select * from (
        select proname, prokind, pg_get_functiondef(oid) as def
        from pg_proc
        where pg_proc.prokind in ('f')
) def
where def is not null;
ERROR:  "array_agg" is an aggregate function

but it works (and lists both functions and procedures) if I do:
select * from (
        select proname, prokind, pg_get_functiondef(oid) as def
        from pg_proc
        where pg_proc.prokind in ('f', 'p')
) def
where def is not null;

I was able to reproduce these steps on a clean, up to date, Debian 12 install, without any data or user defined function.
SELECT version();
                                                      version                                                      
-------------------------------------------------------------------------------------------------------------------
 PostgreSQL 15.5 (Debian 15.5-0+deb12u1) on x86_64-pc-linux-gnu, compiled by gcc (Debian 12.2.0-14) 12.2.0, 64-bit


Thanks in advance,
Best regards

--
Edouard Tollet
Data scientist | Stoïk

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

Предыдущее
От: Michael Paquier
Дата:
Сообщение: Re: BUG #18240: Undefined behaviour in cash_mul_flt8() and friends
Следующее
От: Richard Guo
Дата:
Сообщение: Re: BUG #18238: Cross-partitition MERGE/UPDATE with delete-preventing trigger leads to incorrect memory access