Re: [SQL] fetching unique pins in a high-transaction environment...

2006-11-06 Thread Bobus
I think we've figured out a way to implement the equivalent of a
READPAST hint in a function.

The basic idea is to loop until we find the next available unlocked
row, using the lock_not_available exception to determine if the record
is locked or not.  Our early testing seems to indicate that this
solution will work, but we would love to hear about simpler and more
efficient ways to accomplish this.

Here's a simplified version of the function which illustrates the
principle:

CREATE OR REPLACE FUNCTION "getpin"() RETURNS varchar
as $$
DECLARE
  v_id integer := 0;
  v_pin varchar;
BEGIN
  LOOP
BEGIN
  -- Find the first available PIN.
  -- Note: we cannot lock down the row here since we need to be
  -- able to store the ID of the pin to implement the READPAST.
  select id into v_id from pins where id > v_id and status = 0
  order by id limit 1;

  -- Exit if there are no PINs available.
  IF NOT FOUND THEN
RAISE EXCEPTION 'no pins available';
  END IF;

  -- Lock down the PIN.  If another transaction beat us to it, we
  -- trap the error (see below) and loop looking for the next
  -- available pin.  If another transaction already updated the
  -- status to 1 in between this select and the previous, then we
  -- loop (see ELSE statement).
  select pin into v_pin from pins where id = v_id and status = 0
  for update nowait;

  IF FOUND THEN
-- Update the PIN.  The status = 0 check is unnecessary,
-- but better safe than sorry.
update pins set status = 1 where id = v_id and status = 0;

-- I don't think this should ever happen.
IF NOT FOUND THEN
RAISE EXCEPTION 'this should never happen';
END IF;

RETURN v_pin;
  ELSE
-- Somebody snuck in and updated/grabbed the pin.  Loop.
  END IF;

EXCEPTION WHEN lock_not_available THEN
  -- Loop looking for the next available unlocked pin.
END;
  END LOOP;
END;
$$
language plpgsql;

Thanks...


---(end of broadcast)---
TIP 4: Have you searched our list archives?

   http://archives.postgresql.org


[SQL] fetching unique pins in a high-transaction environment...

2006-11-06 Thread Bobus
Hi,

I posted this question to the "general" forum, but then discovered this
one which I think is more appropriate.  Apologies for the cross-post.

We are in the process of porting an application from SQL Server to
PostgresQL.

We have a table which contains a bunch of prepaid PINs.  What is the
best way to fetch the next available unique pin from the table in a
high-traffic environment with lots of concurrent requests?

For example, our PINs table might look like this and contain thousands
of records.  (FYI, the PIN numbers are generated by a third party and
loaded into the table):

IDPIN USED_BYDATE_USED

100 1864678198
101 7862517189
102 6356178381


10 users request a pin at the same time.  What is the easiest/best way
to ensure that the 10 users will get 10 unique pins, while eliminating
any waiting?

SQL Server supports the notion of a SELECT FOR UPDATE with a READPAST
hint which tells SQL Server to skip over locked rows instead of waiting
until the lock is lifted.  This guarantees a unique pin will be
acquired every time without hampering performance.

Is there any equivalent in Postgres?

Any help would be greatly appreciated...


---(end of broadcast)---
TIP 7: You can help support the PostgreSQL project by donating at

http://www.postgresql.org/about/donate