Re: plpgsql return select from multiple tables

Поиск
Список
Период
Сортировка
От Filip Rembiałkowski
Тема Re: plpgsql return select from multiple tables
Дата
Msg-id 92869e660809100743r41e3e660r17e352478ee1a6ae@mail.gmail.com
обсуждение исходный текст
Ответ на plpgsql return select from multiple tables  ("Artis Caune" <artis.caune@gmail.com>)
Ответы Re: plpgsql return select from multiple tables
Список pgsql-general
2008/9/10 Artis Caune <artis.caune@gmail.com>:
> Hi,
>
> What is the correct way of writing plpgsql function which needs return
> columns from multiple tables?
>
> e.x.:
> SELECT email FROM emails WHERE id = 1
> SELECT backend FROM backends WHERE id = 1
>
> I need plpgsql function return both email and backend in one line, like:
> SELECT email, backend FROM ...
>

in principle, you don't need procedural language for this:

SELECT
    (SELECT email FROM emails WHERE id = 1) as email,
    (SELECT backend FROM backends WHERE id = 1) as backend;


>
> I do like this:
>
> CREATE OR REPLACE FUNCTION get_user_data( INT )
> RETURNS SETOF RECORD AS $$
> DECLARE
>    v_email RECORD;
>    v_backend RECORD;
> BEGIN
>    SELECT email
>      INTO v_email
>      FROM emails
>     WHERE id = $1;
>
>    SELECT backend
>      INTO v_backend
>      FROM backends
>     WHERE id = $1;
>
>    RETURN QUERY SELECT v_email AS email,
>                        v_backend AS backend;
> END;
> $$ LANGUAGE 'plpgsql' SECURITY DEFINER;

nothing wrong here but this can also be rewritten to pure SQL function
(can be few percent faster and optimizable by planner)

CREATE OR REPLACE FUNCTION get_user_data( INT )
RETURNS SETOF RECORD AS $$
SELECT
    (SELECT email FROM emails WHERE id = $1) as email,
    (SELECT backend FROM backends WHERE id = $1) as backend
$$ LANGUAGE 'sql' STABLE STRICT SECURITY DEFINER;


one question, why SETOF? this is supposed to always return one row
always, right?
you could create a TYPE and return this. queries would be a bit simpler:

SELECT * FROM get_user_data('${id}');


finally, I am *almost* sure (maybe someone will correct me)  that if
you encapsulate this in a function, you will always have some
performance penalty because
SELECT email FROM get_user_data('${id}');
will always scan backends table, even if it's not needed.

for such usage, VIEWs are nicer.

create view user_data as
select u.id, e.email, b.backend
from users u [left?] join emails e on e.id=u.id [left?] join backends
b on b.id = u.id;

and

select * from user_data where id=1;




>
>
> and then doing selects:
> SELECT * FROM get_user_data('${id}') AS (email VARCHAR, backend VARCHAR)
>
>
> Is it okay, there will be a lot of those queries?
>
>
>
>
> --
> regards,
> Artis Caune
>
> <----. CCNA
> <----|====================
> <----' didii FreeBSD
>
> --
> Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
> To make changes to your subscription:
> http://www.postgresql.org/mailpref/pgsql-general
>



--
Filip Rembiałkowski

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

Предыдущее
От: Adrian Klaver
Дата:
Сообщение: Re: FW: How to upload data to postgres
Следующее
От: Jack Orenstein
Дата:
Сообщение: Re: Autocommit, isolation level, and vacuum behavior