Re: How to mark a transaction as SERIALIZABLE?
От | Joe Carr |
---|---|
Тема | Re: How to mark a transaction as SERIALIZABLE? |
Дата | |
Msg-id | AANLkTin79K4w5OU16ANkFLxfb_eUS-r9SM5Lb7cD_nSj@mail.gmail.com обсуждение исходный текст |
Ответ на | Re: How to mark a transaction as SERIALIZABLE? (Thom Brown <thom@linux.com>) |
Ответы |
Re: How to mark a transaction as SERIALIZABLE?
|
Список | pgsql-novice |
Thanks for the link. I've done some more reading, and now it appears impossible to set the isolation level of a transaction from within a function.
CREATE OR REPLACE FUNCTION test(character varying)
RETURNS integer AS
$BODY$
BEGIN
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;
RETURN 1;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
Creates successfully, but when executed reports : "ERROR: SET TRANSACTION ISOLATION LEVEL must be called before any query". I believe this is happening because I'm exercising the function with :
select * from test('test');
so that select is executed prior to the SET TRANSACTION. If I remove the SET TRANSACTION command from the function, and then call it by :
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;
select * from test('test');
that works. So, is that the correct way to set the isolation level for a function? Thanks again for your help.
On Tue, Nov 2, 2010 at 5:13 AM, Thom Brown <thom@linux.com> wrote:
BEGIN in your function isn't the same as BEGIN in an SQL statement block. It merely marks where the function begins, not the transaction. Note that you also shouldn't use a semi-colon after the BEGIN in a function. See this page for more info: http://www.postgresql.org/docs/9.0/interactive/plpgsql-structure.htmlOn 2 November 2010 01:51, Joe Carr <joe.carr@gmail.com> wrote:In version 9.0, I've been reading http://www.postgresql.org/docs/9.0/interactive/sql-begin.html. I've been using the following :CREATE OR REPLACE FUNCTION test(character varying)RETURNS SETOF integer AS$BODY$BEGIN TRANSACTION ISOLATION LEVEL SERIALIZABLE;--SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;RETURN 1;END;$BODY$LANGUAGE plpgsql VOLATILEwhich returns with the error :ERROR: syntax error at or near "TRANSACTION"LINE 1: TRANSACTION ISOLATION LEVEL SERIALIZABLEif the BEGIN line is empty with no semi-colon, the function will work :CREATE OR REPLACE FUNCTION test(character varying)RETURNS integer AS$BODY$BEGIN--TRANSACTION ISOLATION LEVEL SERIALIZABLE;--SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;RETURN 1;END;$BODY$LANGUAGE plpgsql VOLATILEbut if I place a semi-colon after BEGIN (e.g. BEGIN;), I get the error :ERROR: syntax error at or near ";"LINE 5: BEGIN;So any help you may be able to provide in the BEGIN syntax (or whatever I'm doing wrong) is greatly appreciated. Thanks!-Joe
--
Thom Brown
Twitter: @darkixion
IRC (freenode): dark_ixion
Registered Linux user: #516935
В списке pgsql-novice по дате отправления: