Thread: Cursors and recursion

Cursors and recursion

From
Don Croata
Date:
Hi,
 
I've been trying to do recursion and cursors in PL/PgSQL (PostgreSQL 8.1). It's a function who has a cursor and calls itself, but the problem raises after the first recursion, when PgSQL complains:
 
ERROR:  cursor "cur" already in use
 
Are the cursors kept globally? or cached like TEMP TABLE?
 
There's an example code available in http://www.croata.cl/cur.sql . In fact, it is an abstraction of the real stored procedure where the problem occurs.
 
--
 
Thanks in advance,
Cro
 

Re: Cursors and recursion

From
Tom Lane
Date:
Don Croata <el.croata@gmail.com> writes:
> It's a function who has a cursor and calls itself, but the problem raises
> after the first recursion, when PgSQL complains:

> ERROR:  cursor "cur" already in use

> Are the cursors kept globally? or cached like TEMP TABLE?

Cursor names are global within a particular session.

IIRC there is a syntax for opening a cursor without specifying a name,
in which case plpgsql will pick one that's not in use.  This is probably
what you want to use.
        regards, tom lane


Re: Cursors and recursion

From
Michael Fuhr
Date:
On Wed, Dec 28, 2005 at 10:48:25AM -0500, Tom Lane wrote:
> Don Croata <el.croata@gmail.com> writes:
> > It's a function who has a cursor and calls itself, but the problem raises
> > after the first recursion, when PgSQL complains:
> 
> > ERROR:  cursor "cur" already in use
> 
> > Are the cursors kept globally? or cached like TEMP TABLE?
> 
> Cursor names are global within a particular session.
> 
> IIRC there is a syntax for opening a cursor without specifying a name,
> in which case plpgsql will pick one that's not in use.  This is probably
> what you want to use.

Or, if possible, use "FOR record_or_row IN query LOOP" instead of
an explicit cursor.

http://www.postgresql.org/docs/8.1/interactive/plpgsql-control-structures.html#PLPGSQL-RECORDS-ITERATING

-- 
Michael Fuhr


Re: Cursors and recursion

From
Don Croata
Date:
Please, if someone recalls a link, book, piece of code or anything with info about this technique for PL/PgSQL (8.1), please let us know. We've been searching into google, groups.google, http://archives.postgresql.org and http://www.postgresql.org/docs/8.1/interactive with no results. Most of the answers are related to unclosed cursors for the "ERROR: cursor ... already in use" message.
 
Here's the sample code for this issue (i.e. error because cursor already defined in recursive PL/PgSQL function) at: http://www.croata.cl/cur.sql
 
--
 
Thanx again,
Cro
 
On 12/28/05, Tom Lane <tgl@sss.pgh.pa.us> wrote:
Don Croata <el.croata@gmail.com> writes:
> It's a function who has a cursor and calls itself, but the problem raises
> after the first recursion, when PgSQL complains:

> ERROR:  cursor "cur" already in use

> Are the cursors kept globally? or cached like TEMP TABLE?

Cursor names are global within a particular session.

IIRC there is a syntax for opening a cursor without specifying a name,
in which case plpgsql will pick one that's not in use.  This is probably
what you want to use.

                       regards, tom lane

Re: Cursors and recursion

From
Michael Fuhr
Date:
On Wed, Dec 28, 2005 at 04:37:21PM -0300, Don Croata wrote:
> Please, if someone recalls a link, book, piece of code or anything with info
> about this technique for PL/PgSQL (8.1), please let us know. We've been
> searching into google, groups.google, http://archives.postgresql.org and
> http://www.postgresql.org/docs/8.1/interactive with no results. Most of the
> answers are related to unclosed cursors for the "ERROR: cursor ... already
> in use" message.

See the "Cursors" section of the PL/pgSQL documentation and read
about unbound cursors:

http://www.postgresql.org/docs/8.1/interactive/plpgsql-cursors.html

"Note:  A bound cursor variable is initialized to the string value
representing its name, so that the portal name is the same as the
cursor variable name, unless the programmer overrides it by assignment
before opening the cursor.  But an unbound cursor variable defaults
to the null value initially, so it will receive an automatically-generated
unique name, unless overridden."

For example, instead of
 DECLARE     cur CURSOR FOR SELECT ...; BEGIN     OPEN cur;

use
 DECLARE     cur refcursor; BEGIN     OPEN cur FOR SELECT ...;

But as I mentioned in a previous post, it's usually easier to use
FOR-IN-LOOP.

-- 
Michael Fuhr