Thread: 'locking' the SELECTs based on indices...
I have a table, like this: CREATE TABLE bla (id int4, code_id int4, code_value varchar, CONSTRAINT bla_pk PRIMARY KEY (id)) And, i have index on the table: CREATE INDEX bla_idx1 ON bla(code_id) Now, when I do this from one connection (psql shell, for instance): [A]BEGIN TRANSACTION; [A]SELECT * FROM bla WHERE code_id = 1 FOR UPDATE; and then, from another psql i do: [B]SELECT * FROM bla WHERE code_id = 1 FOR UPDATE the second SELECT will wait untill I rollback or commit first transaction. That is cool. But, if I do second SELECT like this: [C]SELECT * FROM bla WHERE code_id = 2 FOR UPDATE I will get the rows. If I erase the index bla_idx1, then [C] select will wait, same as [B] select will wait. Is there a way to have this behaviour with the index on column code_id? Mario -- Mario Splivalo Mob-Art mario.splivalo@mobart.hr "I can do it quick, I can do it cheap, I can do it well. Pick any two."
Mario Splivalo <mario.splivalo@mobart.hr> writes: > Now, when I do this from one connection (psql shell, for instance): > [A]BEGIN TRANSACTION; > [A]SELECT * FROM bla WHERE code_id = 1 FOR UPDATE; > and then, from another psql i do: > [B]SELECT * FROM bla WHERE code_id = 1 FOR UPDATE > the second SELECT will wait untill I rollback or commit first > transaction. That is cool. > But, if I do second SELECT like this: > [C]SELECT * FROM bla WHERE code_id = 2 FOR UPDATE > I will get the rows. Well, of course. Why would you want something different? Why do you think the table's indexes should have anything to do with it? If you want a full-table lock then some form of LOCK TABLE seems like the proper answer. SELECT FOR UPDATE is designed to lock the specified rows, no more. > If I erase the index bla_idx1, then [C] select will wait, same as [B] > select will wait. I don't think so. If it does, it's a bug; please provide a reproducible test case. regards, tom lane
On Wed, 2006-02-22 at 13:58 -0500, Tom Lane wrote: > Mario Splivalo <mario.splivalo@mobart.hr> writes: > > Now, when I do this from one connection (psql shell, for instance): > > > [A]BEGIN TRANSACTION; > > [A]SELECT * FROM bla WHERE code_id = 1 FOR UPDATE; > > > and then, from another psql i do: > > [B]SELECT * FROM bla WHERE code_id = 1 FOR UPDATE > > > the second SELECT will wait untill I rollback or commit first > > transaction. That is cool. > > > But, if I do second SELECT like this: > > > [C]SELECT * FROM bla WHERE code_id = 2 FOR UPDATE > > > I will get the rows. > > Well, of course. Why would you want something different? Why do you > think the table's indexes should have anything to do with it? > > If you want a full-table lock then some form of LOCK TABLE seems like > the proper answer. SELECT FOR UPDATE is designed to lock the specified > rows, no more. Hm. But, is there a way to have just a part of table locked, for instance: BEGIN; SELECT * FROM bla WHERE code_id = 1 AND code_value = 'abla' FOR UPDATE and then, in second connection: BEGIN; SELECT * FROM bla WHERE code_id = 1 AND code_value = 'eble' FOR UPDATE I'd like to have second SELECT to hold. Now I'm doing it like this: First connection: BEGIN; SELECT * FROM bla WHERE code_id = 1 FOR UPDATE -- this is just for lock SELECT * FROM bla WHERE code_id = 1 AND code_value = 'abla' FOR UPDATE ... Second connection: BEGIN; SELECT * FROM bla WHERE code_id = 1 FOR UPDATE -- here it'll wait SELECT * FROM bla WHERE code_id = 1 AND code_value = 'eble' FOR UPDATE Since I'm actually doing this inside of a function, i'll use PERFORM for the first select. The problem is that SELECT COUNT(*) FROM bla WHERE code_id = 1 will return some 10M rows (on live data, my test data has some 100k rows, and I don't see any performance impact - yet). Is this a right way to go? > > If I erase the index bla_idx1, then [C] select will wait, same as [B] > > select will wait. > > I don't think so. If it does, it's a bug; please provide a reproducible > test case. > It's not a bug. My high fever must have something to do with it. I just tried it, removed the index, and [C] isn't waiting. Mike
On Thu, 2006-02-23 at 13:56 +0200, Achilleus Mantzios wrote: > The intersection of rows that satisfy BOTH > "code_id = 1 AND code_value = 'abla'" > and > "code_id = 1 AND code_value = 'eble'" > is ZERO!!! > > Why would you want irrelevant rows to wait for one another?? It was a bit silly representation of what I actually want :) I'll explain it later, down there. > > First connection: > > BEGIN; > > SELECT * FROM bla WHERE code_id = 1 FOR UPDATE -- this is just for lock > > SELECT * FROM bla WHERE code_id = 1 AND code_value = 'abla' FOR UPDATE > > ... > > > > Second connection: > > BEGIN; > > SELECT * FROM bla WHERE code_id = 1 FOR UPDATE -- here it'll wait > > SELECT * FROM bla WHERE code_id = 1 AND code_value = 'eble' FOR UPDATE > > > > Since I'm actually doing this inside of a function, i'll use PERFORM for > > the first select. The problem is that SELECT COUNT(*) FROM bla WHERE > > code_id = 1 will return some 10M rows (on live data, my test data has > > some 100k rows, and I don't see any performance impact - yet). > > > > Is this a right way to go? > > > > I'll repeat the first question... > > Lets say you have 100 rows with id=1, and from them 10 have > code_value = 'eble' and 20 have code_value = 'able', > > so you got 10 rows with id=1 and code_value = 'eble' > and 20 rows with id=1 and code_value = 'able' > > So in the first case you deal with 10 rows, in the second with 20 rows. > Why take into account the rest 90 and 80 rows respectively??? > > If for some reason you want INDEED the > "SELECT * FROM bla WHERE code_id = 1 FOR UPDATE" effect, > and the cardinalities are as you describe (more or less), > then go with the LOCK TABLE solution as Tom said. I have a actuall table, called code_values. There I have stored codes for the various prize-winning games. The table looks like this: CREATE TABLE code_values (code_id int4,service_id int4,code_value int4 ) code_id is, of course, PK for the table. Now, when a 'player' sends an SMS, or makes a phone call, I need to check if that code is valid, and then, if that code has allready been played. If it's invalid, or if it has been played, the user is discarded. Since the number of prize-winning games (or services) is around 50, and each service has around 1M codes, I didn't want to lock entire table, so ALL the services wait, but just the portion of the table that contains data for the desired service. So, when I check for the code: SELECT code_value FROM code_values WHERE service_id = 1 AND code_value = 'KFH1A' FOR UPDATE I lock just that particular row, which is no good. I need to have all the codes for the service 1 locked, so if it happens that two users send the very same code, one has to fail. Therefore, from within plpgsql I first do: PERFORM * FROM code_values WHERE service_id = 1 FOR UPDATE and then, later in code, i check for the actuall code. Now, If some other user want's his prize, when checking his code, if he sends code for some other service then service 1, that's ok. If he's sends code for the service 1 the PERFORM will wait untill I'm finished with previous user. I could go with the LOCK TABLE, but that seems to expensive. Or not? Mario > > P.S. > Ti si Hrvatski??? :) Yes! :) Ja sam Hrvat, govorim hrvatski :) > Dobro Jutro druga!!! Dobro jutro i tebi! :)
> I lock just that particular row, which is no good. I need to have all > the codes for the service 1 locked, so if it happens that two users send > the very same code, one has to fail. Therefore, from within plpgsql I > first do: I'm a bit tired tonight so I'll simplify your example : CREATE TABLE stuff ( a INT, b INT ); Basically you want to lock ALL rows with a certain value of a, in order to perform an operation on only one of them.You could do this : CREATE TABLE all_as ( a INT PRIMARY KEY ) CREATE TABLE stuff ( a INT REFERENCES all_as(a), b INT ); Now all the rows in "stuff" that have the same value of "a" reference the same row in "all_as".All you have to do is SELECT * FROM all_as WHERE a=the value FOR UPDATE and you lock all rows having that particular value of a in the big table.
> Now, If some other user want's his prize, when checking his code, if he > sends code for some other service then service 1, that's ok. If he's > sends code for the service 1 the PERFORM will wait untill I'm finished > with previous user. Sorry for the double post. If the rows in your table represent associations between codes and services that are one-use only, you could simply use UPDATE or DELETE, to mark the row in question as having been "consumed".Then, you check how many rows were deleted or updated. If it's 1, good. If it's 0, the code has been used already. If the code itself is one-use only, you should have a codes table and a codes_to_services table, with an ON DELETE CASCADE so that, when you use a code, you delete it from the codes table and it's "consumed" for all services.
On Thu, 2006-02-23 at 17:35 +0100, PFC wrote: > > > Now, If some other user want's his prize, when checking his code, if he > > sends code for some other service then service 1, that's ok. If he's > > sends code for the service 1 the PERFORM will wait untill I'm finished > > with previous user. > > Sorry for the double post. > > If the rows in your table represent associations between codes and > services that are one-use only, you could simply use UPDATE or DELETE, to > mark the row in question as having been "consumed". > Then, you check how many rows were deleted or updated. If it's 1, good. > If it's 0, the code has been used already. > > If the code itself is one-use only, you should have a codes table and a > codes_to_services table, with an ON DELETE CASCADE so that, when you use a > code, you delete it from the codes table and it's "consumed" for all > services. Thank you for the advice, I'll consider it too. The original idea was with UPDATE, so I could mark codes wich are used, but the table with codes will have 10M rows in the begining, for just one game. Later we'll have more games, with like 100M rows in the table. UPDATEing such table, when the server is under normal load (server also hosts some other games) is between 15 and 40 seconds. That is why I tried to eliminate UPDATEs and go with two tables, and INSERTS into the second table, for used codes. Mike