Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

optimize vm_taxref_tree #587

Merged
merged 2 commits into from
Dec 5, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
90 changes: 90 additions & 0 deletions apptax/migrations/versions/3c4762751898_taxref_tree_v2.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,90 @@
"""create vm_taxref_tree v2
Revision ID: 3c4762751898
Revises: 83d7105edb76
Create Date: 2024-12-03 13:30:26.521216
"""

from alembic import op
import sqlalchemy as sa


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


def upgrade():
op.execute("DROP MATERIALIZED VIEW IF EXISTS taxonomie.vm_taxref_tree")
op.execute(
"""
CREATE MATERIALIZED VIEW taxonomie.vm_taxref_tree AS
WITH RECURSIVE
biota AS (
SELECT
t.cd_nom,
t.cd_ref::TEXT::ltree AS path
FROM
taxonomie.taxref t
WHERE
t.cd_nom = 349525
UNION ALL
SELECT
child.cd_nom AS cd_nom,
parent.path || child.cd_ref::TEXT AS path
FROM
taxonomie.taxref child
JOIN
taxonomie.taxref child_ref ON child.cd_ref = child_ref.cd_nom
JOIN
biota parent ON parent.cd_nom = child_ref.cd_sup
),
orphans AS (
SELECT
t.cd_nom,
t.cd_ref::TEXT::ltree AS path
FROM
taxonomie.taxref t
JOIN
taxonomie.taxref t_ref ON t.cd_ref = t_ref.cd_nom
LEFT JOIN
taxonomie.taxref parent ON t_ref.cd_sup = parent.cd_nom AND parent.cd_nom != t_ref.cd_nom
WHERE
parent.cd_nom IS NULL
)
SELECT
cd_nom,
path
FROM
biota
UNION DISTINCT -- do not include biota twice
SELECT
cd_nom,
path
FROM
orphans
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")
77 changes: 0 additions & 77 deletions apptax/migrations/versions/83d7105edb76_taxref_tree.py

This file was deleted.

25 changes: 25 additions & 0 deletions apptax/migrations/versions/83d7105edb76_taxref_tree_v1.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
"""create vm_taxref_tree v1
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():
pass


def downgrade():
op.execute("DROP MATERIALIZED VIEW IF EXISTS taxonomie.vm_taxref_tree")
5 changes: 5 additions & 0 deletions docs/changelog.md
Original file line number Diff line number Diff line change
@@ -1,5 +1,10 @@
# CHANGELOG

2.0.1 (unreleased)
------------------

- Optimisation de la VM `vm_taxref_tree` pour en améliorer les performances et gérer les cas où des taxons locaux ont été ajoutés à la table `taxref` (#587)

2.0.0 (2024-10-29)
------------------

Expand Down
Loading