Skip to content

Commit 6eff3f1

Browse files
committed
Add support to schema editor for moving tables between schemas
1 parent e1a43cd commit 6eff3f1

File tree

8 files changed

+361
-80
lines changed

8 files changed

+361
-80
lines changed

psqlextra/backend/introspection.py

Lines changed: 1 addition & 29 deletions
Original file line numberDiff line numberDiff line change
@@ -1,9 +1,6 @@
1-
from contextlib import contextmanager
21
from dataclasses import dataclass
32
from typing import Dict, List, Optional, Tuple
43

5-
from django.db import transaction
6-
74
from psqlextra.types import PostgresPartitioningMethod
85

96
from . import base_impl
@@ -250,6 +247,7 @@ def get_storage_settings(self, cursor, table_name: str) -> Dict[str, str]:
250247
pg_catalog.pg_am am ON (c.relam = am.oid)
251248
WHERE
252249
c.relname::text = %s
250+
AND pg_catalog.pg_table_is_visible(c.oid)
253251
"""
254252

255253
cursor.execute(sql, (table_name,))
@@ -288,29 +286,3 @@ def get_relations(self, cursor, table_name: str):
288286
[table_name],
289287
)
290288
return {row[0]: (row[2], row[1]) for row in cursor.fetchall()}
291-
292-
@contextmanager
293-
def in_search_path(self, search_path: List[str]):
294-
"""Changes the Postgres `search_path` within the context and switches
295-
it back when it exits."""
296-
297-
# Wrap in a transaction so a savepoint is created. If
298-
# something goes wrong, the `SET LOCAL search_path`
299-
# statement will be rolled back.
300-
with transaction.atomic(using=self.connection.alias):
301-
with self.connection.cursor() as cursor:
302-
cursor.execute("SHOW search_path")
303-
(original_search_path,) = cursor.fetchone()
304-
305-
# Syntax in Postgres is a bit weird here. It isn't really
306-
# a list of names like in `WHERE bla in (val1, val2)`.
307-
placeholder = ", ".join(["%s" for _ in search_path])
308-
cursor.execute(
309-
f"SET LOCAL search_path = {placeholder}", search_path
310-
)
311-
312-
yield self
313-
314-
cursor.execute(
315-
f"SET LOCAL search_path = {original_search_path}"
316-
)

psqlextra/backend/operations.py

Lines changed: 0 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -21,6 +21,3 @@ class PostgresOperations(base_impl.operations()):
2121
SQLUpdateCompiler,
2222
SQLInsertCompiler,
2323
]
24-
25-
def default_schema_name(self) -> str:
26-
return "public"

psqlextra/backend/schema.py

Lines changed: 60 additions & 11 deletions
Original file line numberDiff line numberDiff line change
@@ -12,6 +12,10 @@
1212
from django.db.backends.ddl_references import Statement
1313
from django.db.models import Field, Model
1414

15+
from psqlextra.settings import (
16+
postgres_prepend_local_search_path,
17+
postgres_reset_local_search_path,
18+
)
1519
from psqlextra.type_assertions import is_sql_with_params
1620
from psqlextra.types import PostgresPartitioningMethod
1721

@@ -40,6 +44,8 @@ class PostgresSchemaEditor(SchemaEditor):
4044
sql_alter_table_storage_setting = "ALTER TABLE %s SET (%s = %s)"
4145
sql_reset_table_storage_setting = "ALTER TABLE %s RESET (%s)"
4246

47+
sql_alter_table_schema = "ALTER TABLE %s SET SCHEMA %s"
48+
4349
sql_create_view = "CREATE VIEW %s AS (%s)"
4450
sql_replace_view = "CREATE OR REPLACE VIEW %s AS (%s)"
4551
sql_drop_view = "DROP VIEW IF EXISTS %s"
@@ -203,8 +209,8 @@ def clone_model_constraints_and_indexes_to_schema(
203209
resides.
204210
"""
205211

206-
with self.introspection.in_search_path(
207-
[schema_name, self.connection.ops.default_schema_name()]
212+
with postgres_prepend_local_search_path(
213+
[schema_name], using=self.connection.alias
208214
):
209215
for constraint in model._meta.constraints:
210216
self.add_constraint(model, constraint)
@@ -226,8 +232,8 @@ def clone_model_constraints_and_indexes_to_schema(
226232
# Django creates primary keys later added to the model with
227233
# a custom name. We want the name as it was created originally.
228234
if field.primary_key:
229-
with self.introspection.in_search_path(
230-
[self.connection.ops.default_schema_name()]
235+
with postgres_reset_local_search_path(
236+
using=self.connection.alias
231237
):
232238
[primary_key_name] = self._constraint_names(
233239
model, primary_key=True
@@ -251,8 +257,8 @@ def clone_model_constraints_and_indexes_to_schema(
251257
# a separate transaction later to validate the entries without
252258
# acquiring a AccessExclusiveLock.
253259
if field.remote_field:
254-
with self.introspection.in_search_path(
255-
[self.connection.ops.default_schema_name()]
260+
with postgres_reset_local_search_path(
261+
using=self.connection.alias
256262
):
257263
[fk_name] = self._constraint_names(
258264
model, [field.column], foreign_key=True
@@ -277,8 +283,8 @@ def clone_model_constraints_and_indexes_to_schema(
277283
# manually.
278284
field_check = field.db_parameters(self.connection).get("check")
279285
if field_check:
280-
with self.introspection.in_search_path(
281-
[self.connection.ops.default_schema_name()]
286+
with postgres_reset_local_search_path(
287+
using=self.connection.alias
282288
):
283289
[field_check_name] = self._constraint_names(
284290
model,
@@ -337,10 +343,12 @@ def clone_model_foreign_keys_to_schema(
337343
resides.
338344
"""
339345

340-
with self.introspection.in_search_path(
341-
[schema_name, self.connection.ops.default_schema_name()]
346+
constraint_names = self._constraint_names(model, foreign_key=True)
347+
348+
with postgres_prepend_local_search_path(
349+
[schema_name], using=self.connection.alias
342350
):
343-
for fk_name in self._constraint_names(model, foreign_key=True):
351+
for fk_name in constraint_names:
344352
self.execute(
345353
self.sql_validate_fk
346354
% (
@@ -438,6 +446,47 @@ def reset_model_storage_setting(
438446

439447
self.reset_table_storage_setting(model._meta.db_table, name)
440448

449+
def alter_table_schema(self, table_name: str, schema_name: str) -> None:
450+
"""Moves the specified table into the specified schema.
451+
452+
WARNING: Moving models into a different schema than the default
453+
will break querying the model.
454+
455+
Arguments:
456+
table_name:
457+
Name of the table to move into the specified schema.
458+
459+
schema_name:
460+
Name of the schema to move the table to.
461+
"""
462+
463+
self.execute(
464+
self.sql_alter_table_schema
465+
% (self.quote_name(table_name), self.quote_name(schema_name))
466+
)
467+
468+
def alter_model_schema(self, model: Type[Model], schema_name: str) -> None:
469+
"""Moves the specified model's table into the specified schema.
470+
471+
WARNING: Moving models into a different schema than the default
472+
will break querying the model.
473+
474+
Arguments:
475+
model:
476+
Model of which to move the table.
477+
478+
schema_name:
479+
Name of the schema to move the model's table to.
480+
"""
481+
482+
self.execute(
483+
self.sql_alter_table_schema
484+
% (
485+
self.quote_name(model._meta.db_table),
486+
self.quote_name(schema_name),
487+
)
488+
)
489+
441490
def refresh_materialized_view_model(
442491
self, model: Type[Model], concurrently: bool = False
443492
) -> None:

psqlextra/settings.py

Lines changed: 118 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,118 @@
1+
from contextlib import contextmanager
2+
from typing import Dict, List, Optional, Union
3+
4+
from django.core.exceptions import SuspiciousOperation
5+
from django.db import DEFAULT_DB_ALIAS, connections
6+
7+
8+
@contextmanager
9+
def postgres_set_local(
10+
*,
11+
using: str = DEFAULT_DB_ALIAS,
12+
**options: Dict[str, Optional[Union[str, int, float, List[str]]]],
13+
) -> None:
14+
"""Sets the specified PostgreSQL options using SET LOCAL so that they apply
15+
to the current transacton only.
16+
17+
The effect is undone when the context manager exits.
18+
19+
See https://www.postgresql.org/docs/current/runtime-config-client.html
20+
for an overview of all available options.
21+
"""
22+
23+
connection = connections[using]
24+
qn = connection.ops.quote_name
25+
26+
if not connection.in_atomic_block:
27+
raise SuspiciousOperation(
28+
"SET LOCAL makes no sense outside a transaction. Start a transaction first."
29+
)
30+
31+
sql = []
32+
params = []
33+
for name, value in options.items():
34+
if value is None:
35+
sql.append(f"SET LOCAL {qn(name)} TO DEFAULT")
36+
continue
37+
38+
# Settings that accept a list of values are actually
39+
# stored as string lists. We cannot just pass a list
40+
# of values. We have to create the comma separated
41+
# string ourselves.
42+
if isinstance(value, list) or isinstance(value, tuple):
43+
placeholder = ", ".join(["%s" for _ in value])
44+
params.extend(value)
45+
else:
46+
placeholder = "%s"
47+
params.append(value)
48+
49+
sql.append(f"SET LOCAL {qn(name)} = {placeholder}")
50+
51+
with connection.cursor() as cursor:
52+
cursor.execute(
53+
"SELECT name, setting FROM pg_settings WHERE name = ANY(%s)",
54+
(list(options.keys()),),
55+
)
56+
original_values = dict(cursor.fetchall())
57+
cursor.execute("; ".join(sql), params)
58+
59+
yield
60+
61+
# Put everything back to how it was. DEFAULT is
62+
# not good enough as a outer SET LOCAL might
63+
# have set a different value.
64+
with connection.cursor() as cursor:
65+
sql = []
66+
params = []
67+
68+
for name, value in options.items():
69+
original_value = original_values.get(name)
70+
if original_value:
71+
sql.append(f"SET LOCAL {qn(name)} = {original_value}")
72+
else:
73+
sql.append(f"SET LOCAL {qn(name)} TO DEFAULT")
74+
75+
cursor.execute("; ".join(sql), params)
76+
77+
78+
@contextmanager
79+
def postgres_set_local_search_path(
80+
search_path: List[str], *, using: str = DEFAULT_DB_ALIAS
81+
) -> None:
82+
"""Sets the search path to the specified schemas."""
83+
84+
with postgres_set_local(search_path=search_path, using=using):
85+
yield
86+
87+
88+
@contextmanager
89+
def postgres_prepend_local_search_path(
90+
search_path: List[str], *, using: str = DEFAULT_DB_ALIAS
91+
) -> None:
92+
"""Prepends the current local search path with the specified schemas."""
93+
94+
connection = connections[using]
95+
96+
with connection.cursor() as cursor:
97+
cursor.execute("SHOW search_path")
98+
[
99+
original_search_path,
100+
] = cursor.fetchone()
101+
102+
placeholders = ", ".join(["%s" for _ in search_path])
103+
cursor.execute(
104+
f"SET LOCAL search_path = {placeholders}, {original_search_path}",
105+
tuple(search_path),
106+
)
107+
108+
yield
109+
110+
cursor.execute(f"SET LOCAL search_path = {original_search_path}")
111+
112+
113+
@contextmanager
114+
def postgres_reset_local_search_path(*, using: str = DEFAULT_DB_ALIAS) -> None:
115+
"""Resets the local search path to the default."""
116+
117+
with postgres_set_local(search_path=None, using=using):
118+
yield

tests/db_introspection.py

Lines changed: 4 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -9,15 +9,14 @@
99

1010
from django.db import connection
1111

12+
from psqlextra.settings import postgres_set_local
13+
1214

1315
@contextmanager
1416
def introspect(schema_name: Optional[str] = None):
15-
default_schema_name = connection.ops.default_schema_name()
16-
search_path = [schema_name or default_schema_name]
17-
18-
with connection.introspection.in_search_path(search_path) as introspection:
17+
with postgres_set_local(search_path=schema_name or None):
1918
with connection.cursor() as cursor:
20-
yield introspection, cursor
19+
yield connection.introspection, cursor
2120

2221

2322
def table_names(
Lines changed: 44 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,44 @@
1+
import pytest
2+
3+
from django.db import connection, models
4+
5+
from psqlextra.backend.schema import PostgresSchemaEditor
6+
7+
from .fake_model import get_fake_model
8+
9+
10+
@pytest.fixture
11+
def fake_model():
12+
return get_fake_model(
13+
{
14+
"text": models.TextField(),
15+
}
16+
)
17+
18+
19+
def test_schema_editor_alter_table_schema(fake_model):
20+
obj = fake_model.objects.create(text="hello")
21+
22+
with connection.cursor() as cursor:
23+
cursor.execute("CREATE SCHEMA target")
24+
25+
schema_editor = PostgresSchemaEditor(connection)
26+
schema_editor.alter_table_schema(fake_model._meta.db_table, "target")
27+
28+
with connection.cursor() as cursor:
29+
cursor.execute(f"SELECT * FROM target.{fake_model._meta.db_table}")
30+
assert cursor.fetchall() == [(obj.id, obj.text)]
31+
32+
33+
def test_schema_editor_alter_model_schema(fake_model):
34+
obj = fake_model.objects.create(text="hello")
35+
36+
with connection.cursor() as cursor:
37+
cursor.execute("CREATE SCHEMA target")
38+
39+
schema_editor = PostgresSchemaEditor(connection)
40+
schema_editor.alter_model_schema(fake_model, "target")
41+
42+
with connection.cursor() as cursor:
43+
cursor.execute(f"SELECT * FROM target.{fake_model._meta.db_table}")
44+
assert cursor.fetchall() == [(obj.id, obj.text)]

0 commit comments

Comments
 (0)