Skip to content

Commit

Permalink
feat(taxref): add taxref_tree materialized view
Browse files Browse the repository at this point in the history
The MV containes for each cd_nom, the list of all parents cd_ref.
  • Loading branch information
bouttier committed Oct 22, 2024
1 parent 608d32b commit 0016d57
Show file tree
Hide file tree
Showing 6 changed files with 97 additions and 1 deletion.
1 change: 1 addition & 0 deletions .github/workflows/pytest.yml
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
78 changes: 78 additions & 0 deletions apptax/migrations/versions/83d7105edb76_taxref_tree.py
Original file line number Diff line number Diff line change
@@ -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")
1 change: 1 addition & 0 deletions apptax/taxonomie/commands/utils.py
Original file line number Diff line number Diff line change
Expand Up @@ -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):
Expand Down
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_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(
Expand Down
6 changes: 6 additions & 0 deletions docs/changelog.md
Original file line number Diff line number Diff line change
Expand Up @@ -27,6 +27,7 @@ Si vous utilisez GeoNature, TaxHub sera désormais intégré à celui-ci et il n
- Dépreciation de la route `/taxoninfo` au profit de la route `/taxref` (#554)
- Ajout d'une route `/bdc_statuts/status_symbologies` renvoyant la symbologie de statuts des taxons (couleurs des valeurs des listes rouges) (#510, par @edelclaux)
- Amélioration de la vue `taxonomie.vm_taxref_list_forautocomplete` pour afficher tous les noms d'un taxon (#332, par @JulienCorny et @andriacap)
- 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**

Expand All @@ -46,6 +47,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/ ?

Expand Down
2 changes: 2 additions & 0 deletions install_db.sh
Original file line number Diff line number Diff line change
Expand Up @@ -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..."
Expand Down

0 comments on commit 0016d57

Please sign in to comment.