Skip to content

Commit 93f4328

Browse files
committed
Move TreeNode next-value logic into PL/pgSQL
The purpose of this was to solve a bug when more than 10 entries at any given level (including the root level) were inserted. The previous next-value logic sorted lexicographically but didn't pad values when converted back from integers, so 1000 got sorted between 100 and 200. This led to constraint violations when more than 10 rows were inserted. Because the previous Python code that generated a SQL expression to calculate the next value was a nightmare to read, and relied on a dirty hack overriding parts of the Django ORM's internals, I took this opportunity to rewrite it as a PL/pgSQL function; this means it can actually be written in an imperative manner where appropriate, without having to do multiple round-trips to the database.
1 parent 2c2d320 commit 93f4328

File tree

7 files changed

+86
-47
lines changed

7 files changed

+86
-47
lines changed
Lines changed: 58 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,58 @@
1+
# Generated by Django 2.1.2 on 2018-10-25 04:58
2+
3+
from django.db import migrations
4+
5+
6+
class Migration(migrations.Migration):
7+
8+
dependencies = []
9+
10+
operations = [
11+
migrations.RunSQL(
12+
"""
13+
CREATE OR REPLACE FUNCTION djpgtree_next(
14+
tbl regclass,
15+
prefix ltree,
16+
gap bigint,
17+
pad_length int
18+
) RETURNS ltree AS $function$
19+
DECLARE
20+
sibling_query lquery;
21+
previous_highest ltree;
22+
previous_rightmost_label text;
23+
next_rightmost_segment text;
24+
BEGIN
25+
-- Generate a lquery that matches all would-be siblings of
26+
-- the new row
27+
IF prefix = ''::ltree THEN
28+
sibling_query = '*{1}';
29+
ELSE
30+
sibling_query = prefix::text || '.*{1}';
31+
END IF;
32+
33+
-- Find the existing sibling with the highest tree_path
34+
EXECUTE format($$
35+
SELECT tree_path
36+
FROM %s
37+
WHERE tree_path ~ %L
38+
ORDER BY tree_path DESC LIMIT 1
39+
$$, tbl, sibling_query) INTO previous_highest;
40+
41+
IF previous_highest IS NULL THEN
42+
-- If there is no such row, start at the gap we were passed in,
43+
-- to allow room for other rows to be moved above us
44+
RETURN prefix || LPAD(gap::text, pad_length, '0');
45+
ELSE
46+
-- Otherwise, parse the rightmost label as a number, adding
47+
-- the gap to it, and reattach to the prefix
48+
previous_rightmost_label = subpath(previous_highest, -1);
49+
next_rightmost_segment = previous_rightmost_label::bigint + gap;
50+
RETURN prefix || LPAD(next_rightmost_segment, pad_length, '0');
51+
END IF;
52+
END
53+
$function$ LANGUAGE plpgsql;
54+
55+
""",
56+
"DROP FUNCTION djpgtree_next(regclass, ltree, bigint, int)",
57+
)
58+
]

django_pgtree/migrations/__init__.py

Whitespace-only changes.

django_pgtree/models.py

Lines changed: 18 additions & 43 deletions
Original file line numberDiff line numberDiff line change
@@ -1,11 +1,11 @@
11
from django.contrib.postgres.indexes import GistIndex
22
from django.db import models
3-
from django.db.models import functions as f
43
from django.db.transaction import atomic
54

65
from .fields import LtreeField
76

8-
GAP = 1000000000
7+
GAP = 10 ** 9
8+
PAD_LENGTH = 18
99

1010

1111
class LtreeConcat(models.Func):
@@ -21,6 +21,10 @@ class Text2Ltree(models.Func):
2121
function = "text2ltree"
2222

2323

24+
class DjPgTreeNext(models.Func):
25+
function = "djpgtree_next"
26+
27+
2428
class TreeQuerySet(models.QuerySet):
2529
def roots(self):
2630
return self.filter(tree_path__matches_lquery=["*{1}"])
@@ -56,47 +60,14 @@ def parent(self, new_parent):
5660
# Replace our tree_path with a new one that has our new parent's
5761
self.__new_parent = new_parent
5862

59-
def __next_tree_path_qx(self, prefix=None):
60-
if prefix is None:
61-
prefix = []
62-
63-
# These are all the siblings of the target position, in reverse tree order.
64-
# If we don't have a prefix, this will be all root nodes.
65-
sibling_queryset = self.__class__.objects.filter(
66-
tree_path__matches_lquery=[*prefix, "*{1}"]
67-
).order_by("-tree_path")
68-
# This query expression is the full ltree of the last sibling by tree order.
69-
last_sibling_tree_path = models.Subquery(
70-
sibling_queryset.values("tree_path")[:1]
71-
)
72-
73-
# Django doesn't allow the use of column references in an INSERT statement,
74-
# because it makes the assumption that they refer to columns in the
75-
# to-be-inserted row, the values for which aren't yet known.
76-
# Unfortunately, this means we can't use a subquery that refers to column
77-
# values anywhere internally, even though the columns it refers to are subquery
78-
# result columns. To get around this, we override the contains_column_references
79-
# property on the subquery with a static False, so that Django's check doesn't
80-
# cross the subquery boundary.
81-
last_sibling_tree_path.contains_column_references = False
82-
83-
# This query expression is the rightmost component of that ltree. The double
84-
# cast is because PostgreSQL doesn't let you cast directly from ltree to bigint.
85-
last_sibling_last_value = f.Cast(
86-
f.Cast(Subpath(last_sibling_tree_path, -1), models.CharField()),
87-
models.BigIntegerField(),
88-
)
89-
# This query expression is an ltree containing that value, plus GAP, or just
90-
# GAP if there is no existing siblings. Again, we need to double cast.
91-
new_last_value = Text2Ltree(
92-
f.Cast(f.Coalesce(last_sibling_last_value, 0) + (GAP), models.CharField())
63+
def __next_tree_path_qx(self, prefix=()):
64+
return DjPgTreeNext(
65+
models.Value(self._meta.db_table),
66+
models.Value(".".join(prefix)),
67+
GAP,
68+
PAD_LENGTH,
9369
)
9470

95-
# If we have a prefix, we prepend that to the resulting ltree.
96-
if not prefix:
97-
return new_last_value
98-
return LtreeConcat(models.Value(".".join(prefix)), new_last_value)
99-
10071
def relocate(self, *, after=None, before=None):
10172
if after is None and before is None:
10273
raise ValueError("You must supply at least one of before or after")
@@ -133,11 +104,15 @@ def relocate(self, *, after=None, before=None):
133104

134105
next_v = int(new_next_child.tree_path[-1])
135106
if new_prev_child is None:
136-
self.tree_path = new_next_child.tree_path[:-1] + [str(next_v // 2)]
107+
self.tree_path = new_next_child.tree_path[:-1] + [
108+
str(next_v // 2).zfill(PAD_LENGTH)
109+
]
137110
else:
138111
prev_v = int(new_prev_child.tree_path[-1])
139112
this_v = prev_v + (next_v - prev_v) // 2
140-
self.tree_path = new_prev_child.tree_path[:-1] + [str(this_v)]
113+
self.tree_path = new_prev_child.tree_path[:-1] + [
114+
str(this_v).zfill(PAD_LENGTH)
115+
]
141116

142117
def save(self, *args, **kwargs): # pylint: disable=arguments-differ
143118
tree_path_needs_refresh = False

django_pgtree/tests.py

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -93,3 +93,9 @@ def test_relocate_in_between(animal):
9393
seal.relocate(after=cat)
9494
seal.save()
9595
assert [x.name for x in cat.parent.children] == ["Cat", "Seal", "Dog", "Bear"]
96+
97+
98+
def test_ordering_past_10():
99+
for i in range(1, 12):
100+
T.objects.create(name=str(i))
101+
assert [x.name for x in T.objects.all()] == [str(x) for x in range(1, 12)]

docs/install.rst

Lines changed: 3 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -1,7 +1,7 @@
11
Installing django-pgtree
22
========================
33

4-
First, install the ``django-pgtree`` package from PyPI using your package manager of choice:
4+
Install the ``django-pgtree`` package from PyPI using your package manager of choice:
55

66
.. code-block:: sh
77
@@ -11,11 +11,10 @@ First, install the ``django-pgtree`` package from PyPI using your package manage
1111
# or
1212
$ pipenv install django-pgtree
1313
14-
.. note::
1514
16-
Currently, you don't have to add anything to ``INSTALLED_APPS``.
15+
Then, add ``django_pgtree`` to ``INSTALLED_APPS``.
1716

18-
Second, run the following SQL command on any database that's going to use django-pgtree fields or models:
17+
On your development database and when you first deploy, you'll also need to run the following SQL command on any database that's going to use django-pgtree fields or models:
1918

2019
.. code-block:: sql
2120
File renamed without changes.

testproject/settings.py

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -37,6 +37,7 @@
3737
"django.contrib.sessions",
3838
"django.contrib.messages",
3939
"django.contrib.staticfiles",
40+
"django_pgtree",
4041
"testproject.testapp",
4142
]
4243

0 commit comments

Comments
 (0)