Thread: in PlPgSQL function, how to use variable in a "select ... into .. where " query
Hello, In pl/pgsql (postgresql 8.01), how to use variables in select .. into .. command CREATE OR REPLACE FUNCTION test(VARCHAR) RETURNS VARCHAR AS $$ DECLARE var1 ALIAS FOR $1; cm_tableName tableA.col1%TYPE; T1 VARCHAR := 'sourceTable'; query_value VARCHAR ; BEGIN SELECT col2 INTO cm_tableName FROM T1 WHERE col1 = var1 ; EXECUTE query_value; RETURN cm_tableName;END; $$ language 'plpgsql' IMMUTABLE STRICT; select test('abc'); Failed. Also, tried "SELECT col2 INTO cm_tableName FROM || T1 WHERE col1 = || var1 " and "SELECT col2 INTO cm_tableName FROM || T1 || WHERE col1 = || var1" Failed as well. T1 and var1 both are variables, may I how to use variables in a "select ... into " query please? Thanks a lot, Ying
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 ; EXECUTE query_value; RETURN cm_tableName;END; $$ language 'plpgsql' IMMUTABLE STRICT; select test('001'); Error: ERROR: syntax error at or near "$1" at character 20 QUERY: SELECT col2 FROM $1 WHERE col1 = $2 CONTEXT: PL/pgSQL function "test" line 8 at select into variables LINE 1: SELECT col2 FROM $1 WHERE col1 = $2 Does it mean I have to use the cursor ? Thanks, Ying >I think it is SELECT INTO cm_tableName col2 FROM ... WHERE ... > >2006/3/17, Emi Lu <emilu@encs.concordia.ca>: > > >>Hello, >> >>In pl/pgsql (postgresql 8.01), how to use variables in select .. into .. >>command >> >>CREATE OR REPLACE FUNCTION test(VARCHAR) RETURNS VARCHAR AS $$ >>DECLARE >> var1 ALIAS FOR $1; >> cm_tableName tableA.col1%TYPE; >> T1 VARCHAR := 'sourceTable'; >> query_value VARCHAR ; >>BEGIN >> >> SELECT col2 INTO cm_tableName FROM T1 WHERE col1 = var1 ; >> EXECUTE query_value; >> >> >> RETURN cm_tableName; >> END; >>$$ language 'plpgsql' IMMUTABLE STRICT; >> >>select test('abc'); >> >>Failed. >> >> >>Also, tried "SELECT col2 INTO cm_tableName FROM || T1 WHERE col1 = || >>var1 " and >>"SELECT col2 INTO cm_tableName FROM || T1 || WHERE col1 = || var1" >> >>Failed as well. >> >>T1 and var1 both are variables, may I how to use variables in a "select >>... into " query please? >> >>Thanks a lot, >>Ying >> >> >> >> >> >>---------------------------(end of broadcast)--------------------------- >>TIP 6: explain analyze is your friend >> >> >>
am 17.03.2006, um 14:23:57 -0500 mailte Emi Lu folgendes: > 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#PLPGSQL-STATEMENTS-EXECUTING-DYN You should build a string with your SQL and EXECUTE this string. HTH, Andreas -- Andreas Kretschmer (Kontakt: siehe Header) Heynitz: 035242/47215, D1: 0160/7141639 GnuPG-ID 0x3FFF606C http://wwwkeys.de.pgp.net=== Schollglas Unternehmensgruppe ===
>>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#PLPGSQL-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'); Error: ERROR: syntax error at or near "$2" at character 20 QUERY: SELECT $1 INTO $2 CONTEXT: PL/pgSQL function "test" line 9 at execute statement LINE 1: SELECT $1 INTO $2 I am using postgresql 8.0.1, and I am afraid that 8.0 does not support "excecute ... into ...." http://www.postgresql.org/docs/8.0/static/plpgsql-statements.html I will try to use cursor. Thank you very much for all your help anyway. Ying
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 LOOPRETURN cm_tableNameEND 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