Skip to content

Add support for explicit table-level locks #205

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 4 commits into from
Apr 6, 2023
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
3 changes: 3 additions & 0 deletions docs/source/api_reference.rst
Original file line number Diff line number Diff line change
Expand Up @@ -37,6 +37,9 @@ API Reference
.. autoclass:: ConditionalUniqueIndex
.. autoclass:: CaseInsensitiveUniqueIndex

.. automodule:: psqlextra.locking
:members:

.. automodule:: psqlextra.partitioning
:members:

Expand Down
5 changes: 5 additions & 0 deletions docs/source/index.rst
Original file line number Diff line number Diff line change
Expand Up @@ -35,6 +35,10 @@ Explore the documentation to learn about all features:

Support for ``TRUNCATE TABLE`` statements (including cascading).

* :ref:`Locking models & tables <locking_page>`

Support for explicit table-level locks.


.. toctree::
:maxdepth: 2
Expand All @@ -49,6 +53,7 @@ Explore the documentation to learn about all features:
table_partitioning
expressions
annotations
locking
settings
api_reference
major_releases
56 changes: 56 additions & 0 deletions docs/source/locking.rst
Original file line number Diff line number Diff line change
@@ -0,0 +1,56 @@
.. include:: ./snippets/postgres_doc_links.rst

.. _locking_page:

Locking
=======

`Explicit table-level locks`_ are supported through the :meth:`psqlextra.locking.postgres_lock_model` and :meth:`psqlextra.locking.postgres_lock_table` methods. All table-level lock methods are supported.

Locks are always bound to the current transaction and are released when the transaction is committed or rolled back. There is no support (in PostgreSQL) for explicitly releasing a lock.

.. warning::

Locks are only released when the *outer* transaction commits or when a nested transaction is rolled back. You can ensure that the transaction you created is the outermost one by passing the ``durable=True`` argument to ``transaction.atomic``.

.. note::

Use `django-pglocks <https://pypi.org/project/django-pglocks/>`_ if you need a advisory lock.

Locking a model
---------------

Use :class:`psqlextra.locking.PostgresTableLockMode` to indicate the type of lock to acquire.

.. code-block:: python

from django.db import transaction

from psqlextra.locking import PostgresTableLockMode, postgres_lock_table

with transaction.atomic(durable=True):
postgres_lock_model(MyModel, PostgresTableLockMode.EXCLUSIVE)

# locks are released here, when the transaction committed


Locking a table
---------------

Use :meth:`psqlextra.locking.postgres_lock_table` to lock arbitrary tables in arbitrary schemas.

.. code-block:: python

from django.db import transaction

from psqlextra.locking import PostgresTableLockMode, postgres_lock_table

with transaction.atomic(durable=True):
postgres_lock_table("mytable", PostgresTableLockMode.EXCLUSIVE)
postgres_lock_table(
"tableinotherschema",
PostgresTableLockMode.EXCLUSIVE,
schema_name="myschema"
)

# locks are released here, when the transaction committed
1 change: 1 addition & 0 deletions docs/source/snippets/postgres_doc_links.rst
Original file line number Diff line number Diff line change
Expand Up @@ -2,3 +2,4 @@
.. _TRUNCATE TABLE: https://www.postgresql.org/docs/9.1/sql-truncate.html
.. _hstore: https://www.postgresql.org/docs/11/hstore.html
.. _PostgreSQL Declarative Table Partitioning: https://www.postgresql.org/docs/current/ddl-partitioning.html#DDL-PARTITIONING-DECLARATIVE
.. _Explicit table-level locks: https://www.postgresql.org/docs/current/explicit-locking.html#LOCKING-TABLES
2 changes: 1 addition & 1 deletion docs/source/table_partitioning.rst
Original file line number Diff line number Diff line change
Expand Up @@ -101,7 +101,7 @@ Command-line options
Long flag Short flag Default Description
==================== ============= ================ ==================================================================================================== === === === === === ===
``--yes`` ``-y`` ``False`` Specifies yes to all questions. You will NOT be asked for confirmation before partition deletion.
``--using`` ``-u`` ``'default'`` Name of the database connection to use.
``--using`` ``-u`` ``'default'`` Optional name of the database connection to use.
``--skip-create`` ``False`` Whether to skip creating partitions.
``--skip-delete`` ``False`` Whether to skip deleting partitions.

Expand Down
18 changes: 17 additions & 1 deletion psqlextra/backend/introspection.py
Original file line number Diff line number Diff line change
@@ -1,5 +1,5 @@
from dataclasses import dataclass
from typing import List, Optional
from typing import List, Optional, Tuple

from psqlextra.types import PostgresPartitioningMethod

Expand Down Expand Up @@ -198,3 +198,19 @@ def get_constraints(self, cursor, table_name: str):
constraint["definition"] = definition

return constraints

def get_table_locks(self, cursor) -> List[Tuple[str, str, str]]:
cursor.execute(
"""
SELECT
n.nspname,
t.relname,
l.mode
FROM pg_locks l
INNER JOIN pg_class t ON t.oid = l.relation
INNER JOIN pg_namespace n ON n.oid = t.relnamespace
WHERE t.relnamespace >= 2200
ORDER BY n.nspname, t.relname, l.mode"""
)

return cursor.fetchall()
104 changes: 104 additions & 0 deletions psqlextra/locking.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,104 @@
from enum import Enum
from typing import Optional, Type

from django.db import DEFAULT_DB_ALIAS, connections, models


class PostgresTableLockMode(Enum):
"""List of table locking modes.

See: https://www.postgresql.org/docs/current/explicit-locking.html
"""

ACCESS_SHARE = "ACCESS SHARE"
ROW_SHARE = "ROW SHARE"
ROW_EXCLUSIVE = "ROW EXCLUSIVE"
SHARE_UPDATE_EXCLUSIVE = "SHARE UPDATE EXCLUSIVE"
SHARE = "SHARE"
SHARE_ROW_EXCLUSIVE = "SHARE ROW EXCLUSIVE"
EXCLUSIVE = "EXCLUSIVE"
ACCESS_EXCLUSIVE = "ACCESS EXCLUSIVE"

@property
def alias(self) -> str:
return (
"".join([word.title() for word in self.name.lower().split("_")])
+ "Lock"
)


def postgres_lock_table(
table_name: str,
lock_mode: PostgresTableLockMode,
*,
schema_name: Optional[str] = None,
using: str = DEFAULT_DB_ALIAS,
) -> None:
"""Locks the specified table with the specified mode.

The lock is held until the end of the current transaction.

Arguments:
table_name:
Unquoted table name to acquire the lock on.

lock_mode:
Type of lock to acquire.

schema_name:
Optionally, the unquoted name of the schema
the table to lock is in. If not specified,
the table name is resolved by PostgreSQL
using it's ``search_path``.

using:
Optional name of the database connection to use.
"""

connection = connections[using]

with connection.cursor() as cursor:
quoted_fqn = connection.ops.quote_name(table_name)
if schema_name:
quoted_fqn = (
connection.ops.quote_name(schema_name) + "." + quoted_fqn
)

cursor.execute(f"LOCK TABLE {quoted_fqn} IN {lock_mode.value} MODE")


def postgres_lock_model(
model: Type[models.Model],
lock_mode: PostgresTableLockMode,
*,
using: str = DEFAULT_DB_ALIAS,
schema_name: Optional[str] = None,
) -> None:
"""Locks the specified model with the specified mode.

The lock is held until the end of the current transaction.

Arguments:
model:
The model of which to lock the table.

lock_mode:
Type of lock to acquire.

schema_name:
Optionally, the unquoted name of the schema
the table to lock is in. If not specified,
the table name is resolved by PostgreSQL
using it's ``search_path``.

Django models always reside in the default
("public") schema. You should not specify
this unless you're doing something special.

using:
Optional name of the database connection to use.
"""

postgres_lock_table(
model._meta.db_table, lock_mode, schema_name=schema_name, using=using
)
2 changes: 1 addition & 1 deletion psqlextra/management/commands/pgpartition.py
Original file line number Diff line number Diff line change
Expand Up @@ -37,7 +37,7 @@ def add_arguments(self, parser):
parser.add_argument(
"--using",
"-u",
help="Name of the database connection to use.",
help="Optional name of the database connection to use.",
default="default",
)

Expand Down
2 changes: 1 addition & 1 deletion psqlextra/partitioning/manager.py
Original file line number Diff line number Diff line change
Expand Up @@ -39,7 +39,7 @@ def plan(
for deletion, regardless of the configuration.

using:
Name of the database connection to use.
Optional name of the database connection to use.

Returns:
A plan describing what partitions would be created
Expand Down
2 changes: 1 addition & 1 deletion psqlextra/partitioning/plan.py
Original file line number Diff line number Diff line change
Expand Up @@ -28,7 +28,7 @@ def apply(self, using: Optional[str]) -> None:

Arguments:
using:
Name of the database connection to use.
Optional name of the database connection to use.
"""

connection = connections[using or "default"]
Expand Down
2 changes: 1 addition & 1 deletion psqlextra/query.py
Original file line number Diff line number Diff line change
Expand Up @@ -131,7 +131,7 @@ def bulk_insert(
just dicts.

using:
Name of the database connection to use for
Optional name of the database connection to use for
this query.

Returns:
Expand Down
106 changes: 106 additions & 0 deletions tests/test_locking.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,106 @@
import uuid

import pytest

from django.db import connection, models, transaction

from psqlextra.locking import (
PostgresTableLockMode,
postgres_lock_model,
postgres_lock_table,
)

from .fake_model import get_fake_model


@pytest.fixture
def mocked_model():
return get_fake_model(
{
"name": models.TextField(),
}
)


def get_table_locks():
with connection.cursor() as cursor:
return connection.introspection.get_table_locks(cursor)


@pytest.mark.django_db(transaction=True)
def test_postgres_lock_table(mocked_model):
lock_signature = (
"public",
mocked_model._meta.db_table,
"AccessExclusiveLock",
Copy link
Contributor

@sewi-cpan sewi-cpan Apr 5, 2023

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

What about using @pytest.mark.parametrize with PostgresTableLockMode to ensure that all lock modes are working?

)
with transaction.atomic():
postgres_lock_table(
mocked_model._meta.db_table, PostgresTableLockMode.ACCESS_EXCLUSIVE
)
assert lock_signature in get_table_locks()

assert lock_signature not in get_table_locks()


@pytest.mark.django_db(transaction=True)
def test_postgres_lock_table_in_schema():
schema_name = str(uuid.uuid4())[:8]
table_name = str(uuid.uuid4())[:8]
quoted_schema_name = connection.ops.quote_name(schema_name)
quoted_table_name = connection.ops.quote_name(table_name)

with connection.cursor() as cursor:
cursor.execute(f"CREATE SCHEMA {quoted_schema_name}")
cursor.execute(
f"CREATE TABLE {quoted_schema_name}.{quoted_table_name} AS SELECT 'hello world'"
)

lock_signature = (schema_name, table_name, "ExclusiveLock")
with transaction.atomic():
postgres_lock_table(
table_name, PostgresTableLockMode.EXCLUSIVE, schema_name=schema_name
)
assert lock_signature in get_table_locks()

assert lock_signature not in get_table_locks()


@pytest.mark.parametrize("lock_mode", list(PostgresTableLockMode))
@pytest.mark.django_db(transaction=True)
def test_postgres_lock_model(mocked_model, lock_mode):
lock_signature = (
"public",
mocked_model._meta.db_table,
lock_mode.alias,
)

with transaction.atomic():
postgres_lock_model(mocked_model, lock_mode)
assert lock_signature in get_table_locks()

assert lock_signature not in get_table_locks()


@pytest.mark.django_db(transaction=True)
def test_postgres_lock_model_in_schema(mocked_model):
schema_name = str(uuid.uuid4())[:8]
quoted_schema_name = connection.ops.quote_name(schema_name)
quoted_table_name = connection.ops.quote_name(mocked_model._meta.db_table)

with connection.cursor() as cursor:
cursor.execute(f"CREATE SCHEMA {quoted_schema_name}")
cursor.execute(
f"CREATE TABLE {quoted_schema_name}.{quoted_table_name} (LIKE public.{quoted_table_name} INCLUDING ALL)"
)

lock_signature = (schema_name, mocked_model._meta.db_table, "ExclusiveLock")
with transaction.atomic():
postgres_lock_model(
mocked_model,
PostgresTableLockMode.EXCLUSIVE,
schema_name=schema_name,
)
assert lock_signature in get_table_locks()

assert lock_signature not in get_table_locks()