Thread: returning values to variables from dynamic SQL

returning values to variables from dynamic SQL

From
James Sharrett
Date:
I have a PG function ( using plpgsql) that calls a number of sub functions also in plpgsql.  I have two main problems that seem to be variations on the same theme of running dynamic SQL from a variable with the EXECUTE statement and returning the results back to a variable defined in the calling function.

Problem 1:  return the results of a table query to a variable.

I have a logging table that my sub functions write to.  At the beginning of my main function I want to read a run number from the logging table and increment it by one to then pass into my sub functions.  I've properly declared the variable (v_runnumber) and the data type is correct.  The following statement works fine in the main function and stores the value in the variable.

  select max(runnumber) into v_runnumber from MySchema.log_table;

However, MySchema is a parameter that gets passed into the main function because I need this to work for multiple schemas.  If I try and make this dynamic by using the following statement:

Sql := 'select max(run number) into v_runnumber from ' || MySchema || '.log_table;';
Execute Sql;

I get the following error message (even though the resulting value in the text variable Sql is valid code):

ERROR: query string argument of EXECUTE is null

SQL state: 22004



Problem 2: returning the results of a function call to a variable.


This is a similar issue to #1 but in this case, I'm calling a function from the main function and trying to get the return value back (a single integer) from the sub function to test for errors.  Again, I'm calling the function with  dynamical SQL because of the need to take user values from the main function to call the sub functions.  The function call:


sql := 'select * from public.elt_set_locking(1,' || quote_literal(tenant) || ','  || quote_literal(app) || ','  || quote_literal(cycle) || ','  || v_runnumber || ');';

execute sql;


Works fine.  However when I try and store the value coming back from the function into a main variable with the following call I get an error:

sql := 'select * into v_retcode from public.elt_set_locking(1,' || quote_literal(tenant) || ','  || quote_literal(app) || ','  || quote_literal(cycle) || ','  || v_runnumber || ');';
 execute sql;

"EXECUTE of SELECT ... INTO is not implemented"

Re: returning values to variables from dynamic SQL

From
"David Johnston"
Date:
>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>
From: pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-owner@postgresql.org]
On Behalf Of James Sharrett
Sent: Saturday, September 08, 2012 6:24 PM
To: pgsql-sql@postgresql.org
Subject: [SQL] returning values to variables from dynamic SQL

I have a PG function ( using plpgsql) that calls a number of sub functions
also in plpgsql.  I have two main problems that seem to be variations on the
same theme of running dynamic SQL from a variable with the EXECUTE statement
and returning the results back to a variable defined in the calling
function.

>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>

Please read:

http://www.postgresql.org/docs/9.0/interactive/plpgsql-statements.html#PLPGS
QL-STATEMENTS-EXECUTING-DYN

Basically when you use "EXECUTE" you do not embed the "INTO" as part of the
SQL query but rather INTO becomes a modifier of the EXECUTE itself:

EXECUTE 'some query'  INTO {variables}

David J.