Skip to content

Commit

Permalink
feat(taxref): add cd_ref path (ltree) mat. view
Browse files Browse the repository at this point in the history
  • Loading branch information
bouttier committed Oct 8, 2024
1 parent adf7217 commit ba350c6
Show file tree
Hide file tree
Showing 2 changed files with 70 additions and 1 deletion.
61 changes: 61 additions & 0 deletions apptax/migrations/versions/83d7105edb76_taxref_tree.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,61 @@
"""create vm_taxref_tree
Revision ID: 83d7105edb76
Revises: 44447746cacc
Create Date: 2024-10-05 17:40:11.302423
"""

from alembic import op
import sqlalchemy as sa


# revision identifiers, used by Alembic.
revision = "83d7105edb76"
down_revision = "6a20cd1055ec"
branch_labels = None
depends_on = None


def upgrade():
op.execute("CREATE EXTENSION IF NOT EXISTS ltree")
op.execute(
"""
CREATE MATERIALIZED VIEW taxonomie.vm_taxref_tree
AS WITH RECURSIVE x AS (
SELECT t.cd_nom as cd_ref,
t.cd_nom::text::ltree AS path
FROM taxonomie.taxref t
WHERE t.cd_sup IS NULL AND t.cd_nom = t.cd_ref
UNION ALL
SELECT y.cd_nom AS cd_ref,
ltree_addtext(x_1.path, y.cd_nom::text) AS path
FROM x x_1,
taxonomie.taxref y
WHERE y.cd_nom = y.cd_ref AND x_1.cd_ref = y.cd_sup
)
SELECT x.cd_ref,
x.path
FROM x
WITH DATA
"""
)
op.create_index(
index_name="taxref_tree_cd_nom_idx",
schema="taxonomie",
table_name="vm_taxref_tree",
columns=["cd_ref"],
unique=True,
)
# required for these operators: <, <=, =, >=, >, @>, <@, @, ~, ?
op.create_index(
index_name="taxref_tree_path_idx",
schema="taxonomie",
table_name="vm_taxref_tree",
columns=["path"],
postgresql_using="gist",
)


def downgrade():
op.execute("DROP MATERIALIZED VIEW taxonomie.vm_taxref_tree")
10 changes: 9 additions & 1 deletion apptax/taxonomie/models.py
Original file line number Diff line number Diff line change
Expand Up @@ -3,7 +3,7 @@

from sqlalchemy.ext.hybrid import hybrid_property
from sqlalchemy.schema import FetchedValue
from sqlalchemy.orm import deferred, raiseload, joinedload, foreign, remote
from sqlalchemy.orm import backref, deferred, raiseload, joinedload, foreign, remote

from utils_flask_sqla.serializers import serializable
from ref_geo.models import LAreas
Expand Down Expand Up @@ -539,6 +539,14 @@ class TMetaTaxref(db.Model):
update_date = db.Column(db.DateTime, default=db.func.now(), nullable=False)


class TaxrefTree(db.Model):
__tablename__ = "vm_taxref_tree"
__table_args__ = {"schema": "taxonomie"}
cd_ref = db.Column(db.Integer, ForeignKey("taxonomie.taxref.cd_ref"), primary_key=True)
taxref = db.relationship(Taxref, backref=backref("tree", uselist=False))
path = db.Column(db.String, nullable=False)


# Taxref deffered properties

Taxref.nb_medias = deferred(
Expand Down

0 comments on commit ba350c6

Please sign in to comment.