Обсуждение: Atomar SQL Statement

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

Atomar SQL Statement

От
"Weber, Johann (ISS Kassel)"
Дата:
Guys,
I want to assure that a SQL statement is atomar. It trys to check if an
email address is already found in a table, if yes, it returns the id
field of the entry. If not found, it inserts the entry with the
previously generated increment id and returns - again - the id.
My concern: in a multi threaded environment, can a second thread
interrupt this statement and eventually insert the same email address in
the table with a different id? Or is this statement atomar?
Any help would be highely appreciated.

CODE: _id := nextval('email_id_increment');
INSERT INTO email_adr (email_id, email, lastupdate)
    SELECT _id, 'sender@example.com', now()::timestamp
        WHERE NOT EXISTS (SELECT * FROM email_adr WHERE
email='sender@example.com');



- Johann



Re: Atomar SQL Statement

От
Michael Glaesemann
Дата:
On Jul 7, 2006, at 7:55 , Weber, Johann (ISS Kassel) wrote:

> My concern: in a multi threaded environment, can a second thread
> interrupt this statement and eventually insert the same email  
> address in
> the table with a different id? Or is this statement atomar?

You're safe. Take a look at the FAQ entries on SERIAL:

http://www.postgresql.org/docs/faqs.FAQ.html#item4.11.2

Hope this helps.

Michael Glaesemann
grzm seespotcode net



Re: Atomar SQL Statement

От
Stephan Szabo
Дата:
On Fri, 7 Jul 2006, Michael Glaesemann wrote:

>
> On Jul 7, 2006, at 7:55 , Weber, Johann (ISS Kassel) wrote:
>
> > My concern: in a multi threaded environment, can a second thread
> > interrupt this statement and eventually insert the same email
> > address in
> > the table with a different id? Or is this statement atomar?
>
> You're safe. Take a look at the FAQ entries on SERIAL:
>
> http://www.postgresql.org/docs/faqs.FAQ.html#item4.11.2

I don't think he is, because I don't think the issue is the SERIAL
behavior, but instead the NOT EXISTS behavior.  Won't the NOT EXISTS in
read committed potentially be true for both concurrent sessions if the
second happens before the first commits, which then would mean that both
sessions will go on to attempt the insert (with their own respective ids
from the serial)? Without a unique constraint on email I think he can end
up with the same email address with two different ids.




Re: Atomar SQL Statement

От
Scott Marlowe
Дата:
On Fri, 2006-07-07 at 13:07, Stephan Szabo wrote:
> On Fri, 7 Jul 2006, Michael Glaesemann wrote:
> 
> >
> > On Jul 7, 2006, at 7:55 , Weber, Johann (ISS Kassel) wrote:
> >
> > > My concern: in a multi threaded environment, can a second thread
> > > interrupt this statement and eventually insert the same email
> > > address in
> > > the table with a different id? Or is this statement atomar?
> >
> > You're safe. Take a look at the FAQ entries on SERIAL:
> >
> > http://www.postgresql.org/docs/faqs.FAQ.html#item4.11.2
> 
> I don't think he is, because I don't think the issue is the SERIAL
> behavior, but instead the NOT EXISTS behavior.  Won't the NOT EXISTS in
> read committed potentially be true for both concurrent sessions if the
> second happens before the first commits, which then would mean that both
> sessions will go on to attempt the insert (with their own respective ids
> from the serial)? Without a unique constraint on email I think he can end
> up with the same email address with two different ids.

Yep, this is a possible race condition, if memory serves, and this is
the reason for unique indexes.  That way, should another transaction
manage to sneak in between the two parts of this query, the unique index
will still keep your data coherent.


Fwd: Atomar SQL Statement

От
"Aaron Bono"
Дата:
On 7/7/06, Scott Marlowe < smarlowe@g2switchworks.com> wrote:
On Fri, 2006-07-07 at 13:07, Stephan Szabo wrote:
> On Fri, 7 Jul 2006, Michael Glaesemann wrote:
>
> >
> > On Jul 7, 2006, at 7:55 , Weber, Johann (ISS Kassel) wrote:
> >
> > > My concern: in a multi threaded environment, can a second thread
> > > interrupt this statement and eventually insert the same email
> > > address in
> > > the table with a different id? Or is this statement atomar?
> >
> > You're safe. Take a look at the FAQ entries on SERIAL:
> >
> > http://www.postgresql.org/docs/faqs.FAQ.html#item4.11.2
>
> I don't think he is, because I don't think the issue is the SERIAL
> behavior, but instead the NOT EXISTS behavior.  Won't the NOT EXISTS in
> read committed potentially be true for both concurrent sessions if the
> second happens before the first commits, which then would mean that both
> sessions will go on to attempt the insert (with their own respective ids
> from the serial)? Without a unique constraint on email I think he can end
> up with the same email address with two different ids.

Yep, this is a possible race condition, if memory serves, and this is
the reason for unique indexes.  That way, should another transaction
manage to sneak in between the two parts of this query, the unique index
will still keep your data coherent.

I deal with these issues by first placing a unique constraint on the email field (as was suggested above) and then synchronizing the code that does the check and insert.  I have also looked for instances where a unique constraint error is thrown and had the system give the user a meaningful error or responded appropriately.

-Aaron

Re: Atomar SQL Statement

От
Michael Glaesemann
Дата:
On Jul 7, 2006, at 14:07 , Stephan Szabo wrote:

> I don't think he is, because I don't think the issue is the SERIAL
> behavior, but instead the NOT EXISTS behavior.

I guess I should have been clearer in the issue I was addressing,  
which is whether or not a separate transaction could slip in and  
interrupt his transaction, which my understanding is that it can't. I  
personally would handle the insert if necessary/select in a different  
way, but I don't see anything necessarily wrong with his statement. I  
assumed that he does have a UNIQUE constraint on the email address  
field. I should definitely know better than to make assumption.  
Sorry, Johann, for not addressing your complete email, but rather  
just a portion of it.

Michael Glaesemann
grzm seespotcode net