Thread: ERROR: cursor variable must be a simple variable (LINE XX: OPEN vQuery.cursorReturn FOR )

ERROR: cursor variable must be a simple variable (LINE XX: OPEN vQuery.cursorReturn FOR )

From
"Burke, William J Collins"
Date:

Hello,

 

I encountered the following error when compiling a pgsql function after an upgrade from PostgresSQL 9.3 on RHEL7 to PostgreSQL 12.9 on RHEL8, and could use some help from the community to figure out why.

 

ERROR: cursor variable must be a simple variable

LINE XX: OPEN vQuery.cursorReturn FOR

              ^

SQL state: 42804

 

After looking through the CURSOR documentation for PG9.3 and PG12, I noticed that the following statement is identical for both versions of PostgreSQL:

 

The cursor variable is opened and given the specified query to execute. The cursor cannot be open already, and it must have been declared as an unbound cursor variable (that is, as a simple refcursor variable). The query must be a SELECT, or something else that returns rows (such as EXPLAIN). The query is treated in the same way as other SQL commands in PL/pgSQL: PL/pgSQL variable names are substituted, and the query plan is cached for possible reuse. When a PL/pgSQL variable is substituted into the cursor query, the value that is substituted is the one it has at the time of the OPEN; subsequent changes to the variable will not affect the cursor's behavior. The SCROLL and NO SCROLL options have the same meanings as for a bound cursor.

 

Based on the statement highlighted above, I understand the error message. However, what I cannot figure out is why we did not get this error during compilation on PostgreSQL 9.3 with RHEL. Why does it work on PG9.3, but not on PG12? I feel like I am missing something.

 

Below is a sample pgsql function and composite type that are causing the error.

 

Custom composite type:

 

CREATE TYPE customCompositeType AS

(

       cursorReturn refcursor,

       code integer,

       message text

);

 

Function:

 

CREATE OR REPLACE FUNCTION getData()

  RETURNS record AS

$BODY$

DECLARE

   vQuery  customCompositeType;

 

BEGIN

   vQuery.cursorReturn := 'cursorName';

   vQuery.code         := 0;

   vQuery.message      := ‘TEST;

 

   -- Open Cursor

   OPEN vQuery.cursorReturn FOR

     SELECT column1,

            column2,

            column3

     FROM sampleTable

     ORDER BY column3 ASC;

      

   RETURN(vQuery);

 

END;

$BODY$

  LANGUAGE plpgsql

  COST 100;

 

 

I would appreciate any advice or feedback that the community has on this issue.

 

Thanks,

William

 

 

On Thu, Apr 28, 2022 at 8:03 AM Burke, William J Collins <William.Burke@collins.com> wrote:

Hello,

 

I encountered the following error when compiling a pgsql function after an upgrade from PostgresSQL 9.3 on RHEL7 to PostgreSQL 12.9 on RHEL8, and could use some help from the community to figure out why.

 

ERROR: cursor variable must be a simple variable

LINE XX: OPEN vQuery.cursorReturn FOR

              ^

SQL state: 42804

 

After looking through the CURSOR documentation for PG9.3 and PG12, I noticed that the following statement is identical for both versions of PostgreSQL:



Per testing on db-fiddle this started reporting an error in v11.

I took a peek but didn't see anything directly affecting this; but quite a bit of technical debt repayment happened that cycle and since the current behavior matches the documentation, and there were/are no test cases for this situation, the behavior change isn't surprising.

I'd accept a bug and backpatch solution here, though, if someone wished to write one.  We currently support a version (10) that allows this code to execute, seemingly without issue.

David J.

"Burke, William J                            Collins" <William.Burke@collins.com> writes:
> I encountered the following error when compiling a pgsql function after an upgrade from PostgresSQL 9.3 on RHEL7 to
PostgreSQL12.9 on RHEL8, and could use some help from the community to figure out why. 

> ERROR: cursor variable must be a simple variable
> LINE XX: OPEN vQuery.cursorReturn FOR
>               ^

> Based on the statement highlighted above, I understand the error message. However, what I cannot figure out is why we
didnot get this error during compilation on PostgreSQL 9.3 with RHEL. Why does it work on PG9.3, but not on PG12? I
feellike I am missing something. 

Hmm, that error check looks about the same as it did then: it's insisting
that the datum be of PLPGSQL_DTYPE_VAR type.  I think the behavior change
is a side-effect of the refactoring that was done awhile back to unify the
treatment of row (named-composite-type) variables with RECORD variables.
A field of a row was a separate variable back then, but now it isn't.

I don't recall whether we noticed this behavior change at the time, but
given the pre-existing documentation disclaimer, I'm not too sad about it.
If somebody did want to relax this restriction, the thing to do would be
to remove the datum type limitation altogether, not just restore bug
compatibility with the old behavior.

            regards, tom lane