From: | Robert Treat <xzilla(at)users(dot)sourceforge(dot)net> |
---|---|
To: | pgsql-sql(at)postgresql(dot)org, emilu(at)encs(dot)concordia(dot)ca |
Cc: | "A(dot) Kretschmer" <andreas(dot)kretschmer(at)schollglas(dot)com> |
Subject: | Re: in PlPgSQL function, how to use variable in a "select ... |
Date: | 2006-03-17 21:35:35 |
Message-ID: | 200603171635.35661.xzilla@users.sourceforge.net |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-sql |
On Friday 17 March 2006 15:33, Emi Lu wrote:
> >>Does not work either, the whole function is:
> >>
> >>create table t1(col1 varchar(3), col2 varchar(100));
> >>insert into t1 values('001', 'Result 1');
> >>insert into t1 values('002', 'Result 2');
> >>insert into t1 values('003', 'Result 3');
> >>
> >>CREATE OR REPLACE FUNCTION test(VARCHAR) RETURNS VARCHAR AS $$
> >>DECLARE
> >> col1_value ALIAS FOR $1;
> >>cm_tableName st1_legend.code_map_tablename%TYPE;
> >>lengendTableName VARCHAR := 't1';
> >> query_value VARCHAR ;
> >>BEGIN
> >>
> >> SELECT INTO cm_tableName col2 FROM lengendTableName WHERE col1 =
> >>col1_value ;
> >
> >This can't work, read the docu:
> >http://www.postgresql.org/docs/8.1/interactive/plpgsql-statements.html#PLP
> >GSQL-STATEMENTS-EXECUTING-DYN
> >
> >You should build a string with your SQL and EXECUTE this string.
>
> Thank you Andreas. Unfortunately it did not work. maybe I made something
> wrong?
>
> drop table t1;
> create table t1(col1 varchar(3), col2 varchar(100));
> insert into t1 values('001', 'Result 1');
> insert into t1 values('002', 'Result 2');
> insert into t1 values('003', 'Result 3');
>
> CREATE OR REPLACE FUNCTION test(VARCHAR) RETURNS VARCHAR AS $$
> DECLARE
> col1_value ALIAS FOR $1;
> cm_tableName st1_legend.code_map_tablename%TYPE;
> lengendTableName VARCHAR := 't1';
> query_value VARCHAR ;
> BEGIN
> query_value := 'SELECT col2 FROM lengendTableName WHERE col1 = \'' ||
> col1_value || '\'';
>
> EXECUTE query_value INTO cm_tableName;
>
> RETURN cm_tableName;
> END;
> $$ language 'plpgsql' IMMUTABLE STRICT;
> select test('001');
>
This function would work on 8.1, provided you created the sql statement
correctly:
query_value := 'SELECT col2 FROM ' ||lengendTableName||' WHERE col1 = \'' ||
col1_value || '\'';
>
> I am using postgresql 8.0.1, and I am afraid that 8.0 does not support
> "excecute ... into ...."
>
In which case you could use:
FOR cm_tableName IN EXECUTE query_value LOOP
RETURN cm_tableName
END LOOP
which is a little hacky, though you could use a second variable for assignment
if you felt strongly about it.
--
Robert Treat
Build A Brighter Lamp :: Linux Apache {middleware} PostgreSQL
From | Date | Subject | |
---|---|---|---|
Next Message | Jeff Frost | 2006-03-17 22:41:58 | update before drop causes OID problems in transaction? |
Previous Message | Emi Lu | 2006-03-17 20:33:18 | Re: in PlPgSQL function, how to use variable in a "select ... |