Interesting, it looks like this is broke for sensitive cursors prior
to IBM i 7.1 as there is a PTF for 7.1 but I've not found one for v5r4
yet...

http://www-01.ibm.com/support/docview.wss?uid=nas3c6542f0b463a266a8625770700526df0
SI38164 - OSP-DB-OTHER-UNPRED DB2_NUMBER_ROWS SQLERRD2 NOT SET FOR SEN

APAR Error Description / Circumvention

-----------------------------------------------
SQL GET DIAGNOSTICS DB2_NUMBER_ROWS and SQLCA SQLERRD2 return 0
for sensitive cursors.

CORRECTION FOR APAR SE41364 :
-----------------------------
SQL diagnostic area and SQLCA are correctly set. Database
processing now matches the SQL Reference.

Charles



On Mon, Jun 21, 2010 at 2:16 PM, Charles Wilt <charles.wilt@xxxxxxxxx> wrote:
Luis,

With the select statement defined with FOR READ ONLY but the cursor
defined as ASENSITIVE (either explicitly or implicitly by default), I
got zero as a row count.

Changing the cursor to INSENSITIVE, gave me a row count...but that
also means DB2 will build a temporary table for my results...which may
or may not be ok....we'll see how it performs on a larger set of data.

A good estimate would have been fine, but 0 is not even close to 37,284!

Charles

On Mon, Jun 21, 2010 at 12:33 PM, Luis Rodriguez <luisro58@xxxxxxxxx> wrote:
Charles,

Depending on which kind of cursor you have, the DB2 number of rows is,
AFAIK, an estimate or not. As per my electronically dog-eared PDF V5R3 SQL
Reference Manual:

***************************************

*ASENSITIVE, SENSITIVE, *or *INSENSITIVE *

*  *Specifies whether the cursor is asensitive, sensitive, or insensitive to
changes.

*ASENSITIVE *

*  *Specifies that if the cursor is read-only, the cursor behaves as
INSENSITIVE. (See “Result table of a cursor” on page 618.) Otherwise, the
cursor may behave as SENSITIVE or INSENSITIVE depending on how the
*select-statement
*is optimized. This is the default.

*SENSITIVE *

*  *Specifies that changes made to the database after the cursor is opened
are visible in the result table. The cursor has some level of sensitivity to
any updates or deletes made to the rows underlying its result table after
the cursor is opened. The cursor is always sensitive to positioned updates
or deletes using the same cursor. Additionally, the cursor can have
sensitivity to changes made outside this cursor. If the database manager
cannot make changes visible to the cursor, then an error is returned. The
database manager cannot make changes visible to the cursor when the cursor
implicitly becomes read-only. (See “Result table of a cursor” on page 618.)

*INSENSITIVE *

*  *Specifies that once the cursor is opened, it does not have sensitivity
to inserts, updates, or deletes performed by this or any other activation
group. If INSENSITIVE is specified, the cursor is read-only and a temporary
result is created when the cursor is opened. In addition, the SELECT
statement cannot contain a FOR UPDATE clause and the application must allow
a copy of the data (ALWCPYDTA(*OPTIMIZE) or ALWCPYDTA(*YES)).

***************************************

So it would seem that if your cursor is defined as READ ONLY or INSENSITIVE,
it should get a better estimate in the number of rows...

Me, I think I would prefer to have a SENSITIVE type of cursor and get the
latest data. Besides, it would be a better, more caring program :-)

Regards,
Luis Rodriguez
IBM Certified Systems Expert — eServer i5 iSeries


On Mon, Jun 21, 2010 at 11:16 AM, Charles Wilt <charles.wilt@xxxxxxxxx>wrote:

Luis,

Either I'm doing something wrong or I'm misunderstanding ROW_COUNT..

I've got this:

Open replCursor using subscriber;
Get Diagnostics recordCount = ROW_COUNT;

My recordCount is 0, even though rows are returned...

The v5r4 manual says:
ROW_COUNT Identifies the number of rows associated with the previous
SQL statement that was executed. If the previous SQL statement is a
DELETE, INSERT, REFRESH, or UPDATE statement, ROW_COUNT identifies the
number of rows deleted, inserted, or updated by that statement,
excluding rows affected by either triggers or referential integrity
constraints. If the previous statement is a PREPARE statement,
ROW_COUNT identifies the estimated number of result rows in the
prepared statement. If the previous SQL statement is a
multiple-row-fetch, ROW_COUNT identifies the number of rows fetched.
Otherwise, the value zero is returned.

DB2_NUMBER_ROWS If the previous SQL statement was an OPEN or a FETCH
which caused the size of the result table to be known, returns the
number of rows in the result table. For SENSITIVE cursors, this value
can be thought of as an approximation since rows inserted and deleted
will affect the next retrieval of this value. If the previous
statement was a PREPARE statement, returns the estimated number of
rows in the result table for the prepared statement. Otherwise, the
value zero is returned.

Given that ROW_COUNT doesn't mention OPEN whereas DB2_NUMBER_ROWS
does, I'm going to switch to DB2_NUMBER_ROWS.

However, it would seem that I'm likely to get only an estimate
regardless...

Charles



On Fri, Jun 18, 2010 at 5:02 PM, Luis Rodriguez <luisro58@xxxxxxxxx>
wrote:
Charles,
I would say after the OPEN. As my V5R3 SQL Reference Manual states:

"The rows of the result table can be derived during the execution of the
OPEN statement and a temporary table can be created to hold them; or they
can be derived during the execution of subsequent FETCH statements. In
either case, the cursor is placed in the open state and positioned before
the first row of its result table. If the table is empty the position of
the
cursor is effectively “after the last row.” "

So it would seem that as soon as you do the OPEN you would have the
number
of retrieved rows...

Regards,

Luis Rodriguez
IBM Certified Systems Expert — eServer i5 iSeries


On Fri, Jun 18, 2010 at 4:00 PM, Charles Wilt <charles.wilt@xxxxxxxxx
wrote:

Ok, looks like there's a DB2_NUMBER_ROWS / ROW_COUNT statement
information item I get get back using teh GET DIAGNOSTIC statement.

There's also SQLERRD(2) and SQLERRD(3)in the SQLCA....

Does anybody have any expirence using teh above with a dynamic SQL
statement that returns a cursor to the client.

Do I put the GET DIAGNOSTIC after the PREPARE or after the OPEN?

Thanks!
Charles

On Fri, Jun 18, 2010 at 3:42 PM, Charles Wilt <charles.wilt@xxxxxxxxx>
wrote:
I've got an SQL stored procedure that returns a cursor to the client.

Is there anyway to tell inside the stored proc, how many rows are
available to be returned to the client?

Running on v5r4.

Thanks!
Charles

--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing
list
To post a message email: MIDRANGE-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives
at http://archive.midrange.com/midrange-l.


--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing
list
To post a message email: MIDRANGE-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives
at http://archive.midrange.com/midrange-l.


--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives
at http://archive.midrange.com/midrange-l.


--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives
at http://archive.midrange.com/midrange-l.




As an Amazon Associate we earn from qualifying purchases.

This thread ...

Follow-Ups:
Replies:

Follow On AppleNews
Return to Archive home page | Return to MIDRANGE.COM home page

This mailing list archive is Copyright 1997-2024 by midrange.com and David Gibbs as a compilation work. Use of the archive is restricted to research of a business or technical nature. Any other uses are prohibited. Full details are available on our policy page. If you have questions about this, please contact [javascript protected email address].

Operating expenses for this site are earned using the Amazon Associate program and Google Adsense.