Thread: Table-Level Locks and Transactions

Table-Level Locks and Transactions

From
Greg Rychlewski
Date:
Hi,

I'm curious to understand when table-level locks are released by one transaction to use in another.

For instance, say I have the following transaction, where index1 and index2 both belong to the same table.

BEGIN;
DROP INDEX index1;
CREATE INDEX index2;
COMMIT;

This transaction acquires an ACCESS EXCLUSIVE lock during the DROP INDEX step and then acquires a SHARE lock during the CREATE INDEX step. 

I understand that there will be no conflicts between the statements in this transaction, but I'm wondering if an outside transaction will think that the table has an ACCESS EXCLUSIVE lock until this entire transaction is completed.

Thanks

Re: Table-Level Locks and Transactions

From
Simon Riggs
Date:
On Thu, 9 Dec 2021 at 01:07, Greg Rychlewski <greg.rychlewski@gmail.com> wrote:
>
> I'm curious to understand when table-level locks are released by one transaction to use in another.

At the end of transaction.

> For instance, say I have the following transaction, where index1 and index2 both belong to the same table.
>
> BEGIN;
> DROP INDEX index1;
> CREATE INDEX index2;
> COMMIT;
>
> This transaction acquires an ACCESS EXCLUSIVE lock during the DROP INDEX step and then acquires a SHARE lock during
theCREATE INDEX step.
 
>
> I understand that there will be no conflicts between the statements in this transaction, but I'm wondering if an
outsidetransaction will think that the table has an ACCESS EXCLUSIVE lock until this entire transaction is completed.
 

No, just index1, but the SHARE lock will prevent writes.

Have you thought about using DROP INDEX CONCURRENTLY and CREATE INDEX
CONCURRENTLY?

If in doubt, try it. Look at pg_locks.

-- 
Simon Riggs                http://www.EnterpriseDB.com/



Re: Table-Level Locks and Transactions

From
Laurenz Albe
Date:
On Thu, 2021-12-09 at 10:33 +0000, Simon Riggs wrote:
> On Thu, 9 Dec 2021 at 01:07, Greg Rychlewski <greg.rychlewski@gmail.com> wrote:
> > 
> > I'm curious to understand when table-level locks are released by one transaction to use in another.
> 
> At the end of transaction.
> 
> > For instance, say I have the following transaction, where index1 and index2 both belong to the same table.
> > 
> > BEGIN;
> > DROP INDEX index1;
> > CREATE INDEX index2;
> > COMMIT;
> > 
> > This transaction acquires an ACCESS EXCLUSIVE lock during the DROP INDEX step and then acquires a SHARE lock during
theCREATE INDEX step.
 
> > 
> > I understand that there will be no conflicts between the statements in this transaction,
> > but I'm wondering if an outside transaction will think that the table has an ACCESS EXCLUSIVE
> > lock until this entire transaction is completed.
> 
> No, just index1, but the SHARE lock will prevent writes.

Not sure what you mean by that, but the ACCESS EXCLUSIVE lock from DROP INDEX
will be held until the end of the transaction.


> Have you thought about using DROP INDEX CONCURRENTLY and CREATE INDEX
> CONCURRENTLY?

These cannot be used in a transaction, however.

> If in doubt, try it. Look at pg_locks.

+1

Yours,
Laurenz Albe
-- 
Cybertec | https://www.cybertec-postgresql.com




Re: Table-Level Locks and Transactions

From
Simon Riggs
Date:
On Thu, 9 Dec 2021 at 11:47, Laurenz Albe <laurenz.albe@cybertec.at> wrote:

> > Have you thought about using DROP INDEX CONCURRENTLY and CREATE INDEX
> > CONCURRENTLY?
>
> These cannot be used in a transaction, however.

True, but they don't need to be for this case.


If this is the same index, look at REINDEX CONCURRENTLY.

-- 
Simon Riggs                http://www.EnterpriseDB.com/