transactions in functions, possible bug or what I"m doing wrong?

transactions in functions, possible bug or what I"m doing wrong?

am 19.11.2004 12:52:31 von abief_ag_-postgresql

Hi All,

PostgreSQL 7.4.5

assume this script:

---
create table test_table
(
id serial,
test_value text
) without oids;

insert into test_table
(test_value)
values ('A');

insert into test_table
(test_value)
values ('B');

insert into test_table
(test_value)
values ('C');

insert into test_table
(test_value)
values ('D');

CREATE OR REPLACE FUNCTION test_with_transaction()
RETURNS text AS
'declare my_test_record record;
declare my_return_value text;

begin
my_return_value := '''';
start transaction;
for my_test_record in select * from test_table
loop
my_return_value := my_return_value || my_test_record.test_value;
end loop;
return my_return_value;
commit;
end;'
LANGUAGE 'plpgsql' VOLATILE;

CREATE OR REPLACE FUNCTION test_without_transaction()
RETURNS text AS
'declare my_test_record record;
declare my_return_value text;
begin
my_return_value := '''';
for my_test_record in select * from test_table
loop
my_return_value := my_return_value || my_test_record.test_value;
end loop;
return my_return_value;
end;'
LANGUAGE 'plpgsql' VOLATILE;
---

Why does select test_without_transaction();
return this info:
"ABCD" (as should be)

and select test_with_transaction();
returns this error?

ERROR: SPI_prepare() failed on "start transaction"
CONTEXT: PL/pgSQL function "test_with_transaction" line 6 at SQL
statement

I've been investigating the matter in the doc I have, but to no avail.
google was not helpful either.

any suggestion? is this a bug? or the bug resides in my head?

regards,

Riccardo


---------------------------(end of broadcast)---------------------------
TIP 7: don't forget to increase your free space map settings

Re: transactions in functions, possible bug or what I"m doing

am 19.11.2004 13:59:07 von dev

Riccardo G. Facchini wrote:

> Why does select test_without_transaction();
> return this info:
> "ABCD" (as should be)
>
> and select test_with_transaction();
> returns this error?
>
> ERROR: SPI_prepare() failed on "start transaction"
> CONTEXT: PL/pgSQL function "test_with_transaction" line 6 at SQL
> statement
>
> I've been investigating the matter in the doc I have, but to no avail.
> google was not helpful either.

The function-call is already within a transaction (every command is),
and you can't have nested transactions in 7.4.

You can have what are called "savepoints" in version 8.0 though, which
lets you trap errors and rollback to a named (saved) point in your function.

--
Richard Huxton
Archonet Ltd

---------------------------(end of broadcast)---------------------------
TIP 9: the planner will ignore your desire to choose an index scan if your
joining column's datatypes do not match

Re: transactions in functions, possible bug or what I"m doing

am 19.11.2004 17:23:09 von Mike

On Fri, Nov 19, 2004 at 12:59:07PM +0000, Richard Huxton wrote:

> You can have what are called "savepoints" in version 8.0 though, which
> lets you trap errors and rollback to a named (saved) point in your function.

Savepoints in functions don't work as of 8.0.0beta4, unless I'm
doing something wrong:

CREATE TABLE foo (id SERIAL PRIMARY KEY, name TEXT NOT NULL);

CREATE FUNCTION fooins(TEXT) RETURNS BOOLEAN AS $$
BEGIN
SAVEPOINT x;
INSERT INTO foo (name) VALUES ($1);
ROLLBACK TO x;
RETURN TRUE;
END;
$$ LANGUAGE plpgsql;

BEGIN;
SELECT fooins('John');
ERROR: SPI_execute_plan failed executing query "SAVEPOINT x": SPI_ERROR_TRANSACTION
CONTEXT: PL/pgSQL function "fooins" line 2 at SQL statement

Error trapping does work, however:

CREATE FUNCTION fooins(TEXT) RETURNS BOOLEAN AS $$
BEGIN
INSERT INTO foo (name) VALUES ($1 || '-1');

BEGIN
INSERT INTO foo (id, name) VALUES (currval('foo_id_seq'), $1 || '-2');
EXCEPTION
WHEN unique_violation THEN
NULL;
END;

INSERT INTO foo (name) VALUES ($1 || '-3');

RETURN TRUE;
END;
$$ LANGUAGE plpgsql;

SELECT fooins('John');
fooins
--------
t
(1 row)

SELECT * FROM foo;
id | name
----+--------
1 | John-1
2 | John-3
(2 rows)

--
Michael Fuhr
http://www.fuhr.org/~mfuhr/

---------------------------(end of broadcast)---------------------------
TIP 9: the planner will ignore your desire to choose an index scan if your
joining column's datatypes do not match

Re: transactions in functions, possible bug or what I"m doing

am 19.11.2004 18:08:50 von tgl

Michael Fuhr writes:
> On Fri, Nov 19, 2004 at 12:59:07PM +0000, Richard Huxton wrote:
>> You can have what are called "savepoints" in version 8.0 though, which
>> lets you trap errors and rollback to a named (saved) point in your function.

> Savepoints in functions don't work as of 8.0.0beta4, unless I'm
> doing something wrong:

You can't use explicit savepoint commands, but the exception syntax does
essentially the same thing implicitly.

regards, tom lane

---------------------------(end of broadcast)---------------------------
TIP 4: Don't 'kill -9' the postmaster