From 2e0c969359c4c8061cc225c98af0de0e561c29d0 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?=C3=89lie=20Bouttier?= Date: Tue, 8 Oct 2024 12:22:19 +0200 Subject: [PATCH] feat(taxref): add taxref_tree materialized view The MV containes for each cd_nom, the list of all parents cd_ref. --- .github/workflows/pytest.yml | 1 + .../versions/83d7105edb76_taxref_tree.py | 78 +++++++++++++++++++ apptax/taxonomie/commands/utils.py | 1 + apptax/taxonomie/models.py | 10 ++- docs/changelog.md | 10 +++ install_db.sh | 2 + 6 files changed, 101 insertions(+), 1 deletion(-) create mode 100644 apptax/migrations/versions/83d7105edb76_taxref_tree.py diff --git a/.github/workflows/pytest.yml b/.github/workflows/pytest.yml index b0dc6448..b7c6824f 100644 --- a/.github/workflows/pytest.yml +++ b/.github/workflows/pytest.yml @@ -61,6 +61,7 @@ jobs: psql -h localhost -U taxhubadmin -d taxhub -tc 'CREATE EXTENSION "unaccent";' psql -h localhost -U taxhubadmin -d taxhub -tc 'CREATE EXTENSION "uuid-ossp";' psql -h localhost -U taxhubadmin -d taxhub -tc 'CREATE EXTENSION "pg_trgm";' + psql -h localhost -U taxhubadmin -d taxhub -tc 'CREATE EXTENSION "ltree";' env: PGPASSWORD: taxhubpwd - uses: actions/checkout@v3 diff --git a/apptax/migrations/versions/83d7105edb76_taxref_tree.py b/apptax/migrations/versions/83d7105edb76_taxref_tree.py new file mode 100644 index 00000000..9964d53a --- /dev/null +++ b/apptax/migrations/versions/83d7105edb76_taxref_tree.py @@ -0,0 +1,78 @@ +"""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 childs AS ( + SELECT + t.cd_nom, + t.cd_ref::TEXT::ltree AS path, + 1 AS path_length, + t_ref.cd_sup AS cd_sup + FROM + taxonomie.taxref t + JOIN taxonomie.taxref t_ref ON + t.cd_ref = t_ref.cd_nom + UNION ALL + SELECT + child.cd_nom AS cd_nom, + parent.cd_ref::TEXT || child.path AS path, + child.path_length + 1 AS path_length, + parent_ref.cd_sup AS cd_sup + FROM + childs child + JOIN taxonomie.taxref parent ON + child.cd_sup = parent.cd_nom + JOIN taxonomie.taxref parent_ref ON + parent.cd_ref = parent_ref.cd_nom + ) + SELECT + DISTINCT ON + (cd_nom) cd_nom, + path + FROM + childs + ORDER BY + cd_nom, + path_length DESC + WITH DATA; + """ + ) + op.create_index( + index_name="taxref_tree_cd_nom_idx", + schema="taxonomie", + table_name="vm_taxref_tree", + columns=["cd_nom"], + 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") diff --git a/apptax/taxonomie/commands/utils.py b/apptax/taxonomie/commands/utils.py index c8875d0a..6133deaa 100644 --- a/apptax/taxonomie/commands/utils.py +++ b/apptax/taxonomie/commands/utils.py @@ -231,6 +231,7 @@ def refresh_taxref_vm(): db.session.execute("REFRESH MATERIALIZED VIEW taxonomie.vm_phylum") db.session.execute("REFRESH MATERIALIZED VIEW taxonomie.vm_regne") db.session.execute("REFRESH MATERIALIZED VIEW taxonomie.vm_taxref_list_forautocomplete") + db.session.execute("REFRESH MATERIALIZED VIEW taxonomie.vm_taxref_tree") def get_csv_field_names(f, encoding, delimiter): diff --git a/apptax/taxonomie/models.py b/apptax/taxonomie/models.py index a1f903f5..9b16f9cc 100644 --- a/apptax/taxonomie/models.py +++ b/apptax/taxonomie/models.py @@ -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 @@ -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_nom = db.Column(db.Integer, ForeignKey("taxonomie.taxref.cd_nom"), 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( diff --git a/docs/changelog.md b/docs/changelog.md index 6a5ac004..94fe0d2a 100644 --- a/docs/changelog.md +++ b/docs/changelog.md @@ -1,5 +1,6 @@ # CHANGELOG + 2.0.0 (unreleased) ------------------ @@ -25,6 +26,10 @@ Si vous utilisez GeoNature, TaxHub sera désormais intégré à celui-ci et il n - Suppression de la colonne "supprime" des médias qui effectuait une suppression logique et non physique des médias (#538) - Suppression de la colonne `id_droit` de la table `bib_themes`. +**💻 Développement** + +- Ajout d’une vue matérialisée `vm_taxref_tree` contenant pour chaque `cd_nom` la liste complète des `cd_ref` parents menant jusqu’au vivant (#567) + **⚠️ Notes de version** @@ -44,6 +49,11 @@ Si vous utilisez GeoNature, TaxHub sera désormais intégré à celui-ci et il n - L'image Docker de TaxHub n'est plus générée automatiquement en raison de son intégration à GeoNature (#519) - Suppression du code spécifique Amazon S3. Pour utiliser des services S3 de stockage des médias, il est toujours possible de monter un volume pour y déposer directement les médias. - Les branches `taxhub` et `taxhub-admin` ont été renommées en `taxhub-standalone` et `taxhub-standalone-sample`. +- Si votre utilisateur PostgreSQL n’a pas la permission `CREATE EXTENSION`, vous devez manuellement créer l’extension `ltree` : + +```bash +sudo -n -u postgres -s psql -d $db_name -c 'CREATE EXTENSION ltree;' +``` - Déplacement des médias à préciser/clarifier ? Avec GN ou sans c'est différent ? De /static/medias/ à media/taxhub/ ? diff --git a/install_db.sh b/install_db.sh index d872fd83..a104e120 100755 --- a/install_db.sh +++ b/install_db.sh @@ -58,6 +58,8 @@ then sudo -n -u postgres -s psql -d $db_name -c 'CREATE EXTENSION IF NOT EXISTS "uuid-ossp";' &>> $LOG_FILE + sudo -n -u postgres -s psql -d $db_name -c 'CREATE EXTENSION IF NOT EXISTS ltree;' &>> $LOG_FILE + sudo -n -u postgres -s psql -d $db_name -c 'CREATE EXTENSION IF NOT EXISTS "postgis";' &>> $LOG_FILE echo "Extracting PostGIS version..."