Search Postgresql Archives

Re: EXECUTE USING problem

[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]

 



Hello

2011/11/15 Graham <graham@xxxxxxxxxx>:
> Using PG 9.0.3, I wish to dynamically reference a column in a table passed
> into a PL/PgSQL function as follows:
>
> -- A table with some values.
>  DROP TABLE IF EXISTS table1;
>  CREATE TABLE table1 (
>     code INT,
>     descr TEXT
>  );
>
> INSERT INTO table1 VALUES ('1','a');
> INSERT INTO table1 VALUES ('2','b');
>
> -- The function code.
> DROP FUNCTION IF EXISTS foo (TEXT);
> CREATE FUNCTION foo (tbl_name TEXT) RETURNS VOID
>
> AS $$
> DECLARE
>    r RECORD;
>    d TEXT;
> BEGIN
>    FOR r IN
>    EXECUTE 'SELECT * FROM ' || tbl_name
>    LOOP
>    --SELECT r.descr INTO d; --IT WORK
>    EXECUTE 'SELECT ($1)' || '.descr' INTO d USING r;     --DOES NOT WORK
>    RAISE NOTICE '%', d;
> END LOOP;
>
> END;
> $$ LANGUAGE plpgsql STRICT;
>
> -- Call foo function on table1
> SELECT foo('table1');
>
>
> Another post suggested EXECUTE 'SELECT $1::text::table1.descr' INTO d USING
> r; but this does not work either. Can this be achieved currently? what would
> be the syntax ?
>

you cannot to do it in plpgsql :(. Try to use PLPython or PLPerl

I found a working solution, but it is ugly - only plpgsql is just not
good language for this purpose. Maybe with HStore it can be done more
cleanly

 CREATE or replace FUNCTION foo (tbl_name TEXT) RETURNS VOID
AS $$
DECLARE
   r RECORD;
   d TEXT;
BEGIN
   FOR r IN
   EXECUTE 'SELECT * FROM ' || tbl_name
   LOOP
     EXECUTE 'SELECT (''' || replace(r::text,'''','''''') || '''::' ||
tbl_name || ').descr' INTO d;
    RAISE NOTICE '%', d;
END LOOP;
END;
$$ LANGUAGE plpgsql STRICT;

Regards

Pavel Stehule

> Thanks in advance.
>
> --
> Sent via pgsql-general mailing list (pgsql-general@xxxxxxxxxxxxxx)
> To make changes to your subscription:
> http://www.postgresql.org/mailpref/pgsql-general
>

-- 
Sent via pgsql-general mailing list (pgsql-general@xxxxxxxxxxxxxx)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general



[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]
[Index of Archives]     [Postgresql Jobs]     [Postgresql Admin]     [Postgresql Performance]     [Linux Clusters]     [PHP Home]     [PHP on Windows]     [Kernel Newbies]     [PHP Classes]     [PHP Books]     [PHP Databases]     [Postgresql & PHP]     [Yosemite]
  Powered by Linux