Commit ebe1be13 authored by Bruce Momjian's avatar Bruce Momjian

This patch improves the behavior of FOUND in PL/PgSQL. In Oracle,

FOUND is set whenever a SELECT INTO returns > 0 rows, *or* when an
INSERT, UPDATE, or DELETE affects > 0 rows. We implemented the first
part of this behavior, but not the second.

I also improved the documentation on the various situations in which
FOUND can be set (excluding inside FOR loops, which I still need to
think about), and added some regression tests for this behavior.

Neil Conway
parent 818a33e4
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/plpgsql.sgml,v 1.1 2002/07/30 19:36:10 momjian Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/plpgsql.sgml,v 1.2 2002/08/20 05:28:23 momjian Exp $
--> -->
<chapter id="plpgsql"> <chapter id="plpgsql">
...@@ -126,7 +126,7 @@ END; ...@@ -126,7 +126,7 @@ END;
them to define operators or use them in functional indexes. them to define operators or use them in functional indexes.
</para> </para>
<sect2 id="plpgsql-advantages"> <sect2 id="plpgsql-advantages">
<title>Advantages of Using PL/pgSQL</title> <title>Advantages of Using <application>PL/pgSQL</application></title>
<itemizedlist> <itemizedlist>
<listitem> <listitem>
...@@ -852,10 +852,58 @@ SELECT INTO <replaceable>target</replaceable> <replaceable>expressions</replacea ...@@ -852,10 +852,58 @@ SELECT INTO <replaceable>target</replaceable> <replaceable>expressions</replacea
</para> </para>
<para> <para>
There is a special variable named FOUND of type There is a special variable named <literal>FOUND</literal> of
<type>boolean</type> that can be used immediately after a SELECT type <type>boolean</type>. The initial value of
INTO to check if an assignment had success (that is, at least one <literal>FOUND</literal> is false; it is set to true when one of
row was returned by the SELECT). For example, the following events occurs:
<itemizedlist>
<listitem>
<para>
A SELECT INTO statement is executed, and it returns one or
more rows.
</para>
</listitem>
<listitem>
<para>
A UPDATE, INSERT, or DELETE statement is executed, and it
affects one or more rows.
</para>
</listitem>
<listitem>
<para>
A PERFORM statement is executed, and it discards one or more
rows.
</para>
</listitem>
<listitem>
<para>
A FETCH statement is executed, and it returns an additional
row.
</para>
</listitem>
<listitem>
<para>
A FOR statement is executed, and it iterates one or more
times. This applies to all three variants of the FOR statement
(integer FOR loops, record-set FOR loops, and dynamic
record-set FOR loops). <literal>FOUND</literal> is only set
when the FOR loop exits: inside the execution of the loop,
<literal>FOUND</literal> is not modified, although it may be
set by the execution of other statements.
</para>
</listitem>
</itemizedlist>
If none of these events occur, <literal>FOUND</literal> is set to
false. <literal>FOUND</literal> is a local variable; any changes
to it effect only the current <application>PL/pgSQL</application>
function.
</para>
<para>
You can use <literal>FOUND</literal> immediately after a SELECT
INTO statement to determine whether the assignment was successful
(that is, at least one row was was returned by the SELECT
statement). For example:
<programlisting> <programlisting>
SELECT INTO myrec * FROM EMP WHERE empname = myname; SELECT INTO myrec * FROM EMP WHERE empname = myname;
...@@ -902,10 +950,10 @@ PERFORM <replaceable>query</replaceable>; ...@@ -902,10 +950,10 @@ PERFORM <replaceable>query</replaceable>;
This executes a <literal>SELECT</literal> This executes a <literal>SELECT</literal>
<replaceable>query</replaceable> and discards the <replaceable>query</replaceable> and discards the
result. <application>PL/pgSQL</application> variables are substituted result. <application>PL/pgSQL</application> variables are
in the query as usual. Also, the special variable FOUND is set to substituted in the query as usual. Also, the special variable
true if the query produced at least one row, or false if it produced <literal>FOUND</literal> is set to true if the query produced at
no rows. least one row, or false if it produced no rows.
</para> </para>
<note> <note>
...@@ -1638,8 +1686,8 @@ FETCH <replaceable>cursor</replaceable> INTO <replaceable>target</replaceable>; ...@@ -1638,8 +1686,8 @@ FETCH <replaceable>cursor</replaceable> INTO <replaceable>target</replaceable>;
FETCH retrieves the next row from the cursor into a target, FETCH retrieves the next row from the cursor into a target,
which may be a row variable, a record variable, or a comma-separated which may be a row variable, a record variable, or a comma-separated
list of simple variables, just like SELECT INTO. As with list of simple variables, just like SELECT INTO. As with
SELECT INTO, the special variable FOUND may be checked to see SELECT INTO, the special variable <literal>FOUND</literal> may be
whether a row was obtained or not. checked to see whether a row was obtained or not.
<programlisting> <programlisting>
FETCH curs1 INTO rowvar; FETCH curs1 INTO rowvar;
......
This diff is collapsed.
...@@ -1534,3 +1534,59 @@ SELECT recursion_test(4,3); ...@@ -1534,3 +1534,59 @@ SELECT recursion_test(4,3);
4,3,2,1,3 4,3,2,1,3
(1 row) (1 row)
--
-- Test the FOUND magic variable
--
CREATE TABLE found_test_tbl (a int);
create function test_found ()
returns boolean as '
declare
begin
insert into found_test_tbl values (1);
if FOUND then
insert into found_test_tbl values (2);
end if;
update found_test_tbl set a = 100 where a = 1;
if FOUND then
insert into found_test_tbl values (3);
end if;
delete from found_test_tbl where a = 9999; -- matches no rows
if not FOUND then
insert into found_test_tbl values (4);
end if;
for i in 1 .. 10 loop
-- no need to do anything
end loop;
if FOUND then
insert into found_test_tbl values (5);
end if;
-- never executes the loop
for i in 2 .. 1 loop
-- no need to do anything
end loop;
if not FOUND then
insert into found_test_tbl values (6);
end if;
return true;
end;' language 'plpgsql';
select test_found();
test_found
------------
t
(1 row)
select * from found_test_tbl;
a
-----
2
100
3
4
5
6
(6 rows)
...@@ -1414,3 +1414,47 @@ BEGIN ...@@ -1414,3 +1414,47 @@ BEGIN
END;' LANGUAGE 'plpgsql'; END;' LANGUAGE 'plpgsql';
SELECT recursion_test(4,3); SELECT recursion_test(4,3);
--
-- Test the FOUND magic variable
--
CREATE TABLE found_test_tbl (a int);
create function test_found ()
returns boolean as '
declare
begin
insert into found_test_tbl values (1);
if FOUND then
insert into found_test_tbl values (2);
end if;
update found_test_tbl set a = 100 where a = 1;
if FOUND then
insert into found_test_tbl values (3);
end if;
delete from found_test_tbl where a = 9999; -- matches no rows
if not FOUND then
insert into found_test_tbl values (4);
end if;
for i in 1 .. 10 loop
-- no need to do anything
end loop;
if FOUND then
insert into found_test_tbl values (5);
end if;
-- never executes the loop
for i in 2 .. 1 loop
-- no need to do anything
end loop;
if not FOUND then
insert into found_test_tbl values (6);
end if;
return true;
end;' language 'plpgsql';
select test_found();
select * from found_test_tbl;
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment