Обсуждение: Does a the block of code within a stored procedure constitute a transaction?

Поиск
Список
Период
Сортировка

Does a the block of code within a stored procedure constitute a transaction?

От
Дата:
I need to "manually" keep a sequence for each row of the employee table,
i.e., I don't want to use postgres's built-in sequences for this
application because the sequence numbers are used to generate expense
report numbers on a "per-employee" basis. That is, each employee has a
separate sequence counter, starting at one, to number their expense
reports. Since employees will come and go, I don't want to keep having to
create and delete postgres sequence objects as employees come and go.

Instead, I have a column of the employee table store the "last value" of
the corresponding expense report sequence counter, and in an ON INSERT
trigger to the expense report table, I call the following function to get
and increment the new sequence value:

CREATE OR REPLACE FUNCTION paid.expense_report_next(int4) RETURNS integer
AS '
DECLARE l_employee_pk ALIAS FOR $1; l_expense_report_seq INTEGER;
BEGIN SELECT INTO l_expense_report_seq expense_report_seq+1   FROM employee   WHERE employee_pk = l_employee_pk;
 UPDATE employee   SET expense_report_seq = l_expense_report_seq   WHERE employee_pk = l_employee_pk;
RETURN l_expense_report_seq;
END;'  LANGUAGE 'plpgsql' VOLATILE;


What I need to know is whether or not this is multi-user safe, i.e., will
the block of code in the procedure execute as a transaction so that if
more than one clerk creates an expense report for the same employee
simultaneously is it possible or impossible that value of the
employee.expense_report_seq gets updated by the second clerk between the
SELECT and UPDATE statements invoked by the first clerk?

And as a follow-up, should I add the FOR UPDATE clause to the SELECT
statement?

~Berend Tober





Re: Does a the block of code within a stored procedure constitute

От
Rod Taylor
Дата:
> What I need to know is whether or not this is multi-user safe, i.e., will
> the block of code in the procedure execute as a transaction so that if
> more than one clerk creates an expense report for the same employee
> simultaneously is it possible or impossible that value of the
> employee.expense_report_seq gets updated by the second clerk between the
> SELECT and UPDATE statements invoked by the first clerk?
>
> And as a follow-up, should I add the FOR UPDATE clause to the SELECT
> statement?

SELECT .. FOR UPDATE would be appropriate.

However, you could also do an update + 1 first and the select second to
find what you changed the value to.

Re: Does a the block of code within a stored procedure constitute a transaction?

От
Дата:
>> What I need to know is whether or not this is multi-user safe, i.e.,
>> will the block of code in the procedure execute as a transaction so
>> that if more than one clerk creates an expense report for the same
>> employee simultaneously is it possible or impossible that value of
>> the
>> employee.expense_report_seq gets updated by the second clerk between
>> the SELECT and UPDATE statements invoked by the first clerk?
>>
>> And as a follow-up, should I add the FOR UPDATE clause to the SELECT
>> statement?
>
> SELECT .. FOR UPDATE would be appropriate.
>
> However, you could also do an update + 1 first and the select second to
> find what you changed the value to.


Yes, and I like the fact that the UPDATE first approach eliminates a
local variable declaration as well!

~Berend Tober