Skip to content

Commit

Permalink
[Monitoring individuals] Add trigger calculate t_observations.cd_nom …
Browse files Browse the repository at this point in the history
…from t_individuals
  • Loading branch information
amandine-sahl committed Jan 7, 2025
1 parent d13fe4f commit 81d9215
Show file tree
Hide file tree
Showing 3 changed files with 97 additions and 17 deletions.
2 changes: 1 addition & 1 deletion backend/geonature/core/gn_monitoring/models.py
Original file line number Diff line number Diff line change
Expand Up @@ -246,7 +246,7 @@ class TObservations(DB.Model):
digitiser = DB.relationship(
User, primaryjoin=(User.id_role == id_digitiser), foreign_keys=[id_digitiser]
)
cd_nom = DB.Column(DB.Integer, DB.ForeignKey("taxonomie.taxref.cd_nom"))
cd_nom = DB.Column(DB.Integer, DB.ForeignKey("taxonomie.taxref.cd_nom"), nullable=False)
comments = DB.Column(DB.String)
uuid_observation = DB.Column(UUID(as_uuid=True), default=select(func.uuid_generate_v4()))

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -24,9 +24,6 @@
foreign_table = "t_individuals"
foreign_key = column_name

constraint_name = f"check_{table}_cd_nom_or_id_individual_not_null"
cd_nom_column_name = "cd_nom"


def upgrade():
op.add_column(
Expand All @@ -42,15 +39,6 @@ def upgrade():
),
schema=monitorings_schema,
)
op.alter_column(
table_name=table, column_name=cd_nom_column_name, nullable=True, schema=monitorings_schema
)
op.create_check_constraint(
table_name=table,
constraint_name=constraint_name,
condition=sa.or_(column(cd_nom_column_name).isnot(None), column(column_name).isnot(None)),
schema=monitorings_schema,
)


def downgrade():
Expand All @@ -62,7 +50,3 @@ def downgrade():
"""
)
op.drop_column(table_name=table, column_name=column_name, schema=monitorings_schema)
op.alter_column(
table_name=table, column_name=cd_nom_column_name, nullable=False, schema=monitorings_schema
)
# constraint automatically dropped with drop_column above
Original file line number Diff line number Diff line change
@@ -0,0 +1,96 @@
"""[monitoring] Add trigger get individual cd_nom
Revision ID: bc28b69025b3
Revises: 5b61bcaa18da
Create Date: 2025-01-07 14:50:55.877316
"""

from alembic import op
import sqlalchemy as sa


# revision identifiers, used by Alembic.
revision = "bc28b69025b3"
down_revision = "5b61bcaa18da"
branch_labels = None
depends_on = None


def upgrade():
# Création trigger mise à jour du cd_nom de la table des observations
# lors d'une modification d'un cd_nom d'un individu
op.execute(
"""
CREATE OR REPLACE FUNCTION gn_monitoring.fct_trg_t_individuals_t_observations_cd_nom()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
BEGIN
-- Mise à jour du cd_nom de la table observation
IF
NEW.id_individual = OLD.id_individual
THEN
UPDATE gn_monitoring.t_observations SET cd_nom = NEW.cd_nom WHERE id_individual = NEW.id_individual;
END IF;
RETURN NEW;
END;
$function$
;
CREATE TRIGGER trg_update_t_observations_cd_nom
AFTER UPDATE
ON gn_monitoring.t_individuals
FOR EACH ROW
EXECUTE PROCEDURE gn_monitoring.fct_trg_t_individuals_t_observations_cd_nom();
"""
)

# Création d'un trigger qui peuple le champ cd_nom de la table t_observation à partir
# des données de l'individus selectionné
op.execute(
"""
CREATE OR REPLACE FUNCTION gn_monitoring.fct_trg_t_observations_cd_nom()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
BEGIN
-- Récupération du cd_nom depuis la table des individus
IF
NOT NEW.id_individual IS NULL
THEN
NEW.cd_nom := (SELECT cd_nom FROM gn_monitoring.t_individuals ti WHERE id_individual = NEW.id_individual);
END IF;
RETURN NEW;
END;
$function$
;
CREATE TRIGGER trg_update_cd_nom
BEFORE INSERT OR UPDATE
ON gn_monitoring.t_observations
FOR EACH ROW
EXECUTE PROCEDURE gn_monitoring.fct_trg_t_observations_cd_nom();
"""
)


def downgrade():
op.execute(
"""
DROP TRIGGER trg_update_t_observations_cd_nom ON gn_monitoring.t_individuals;
DROP FUNCTION gn_monitoring.fct_trg_t_individuals_t_observations_cd_nom();
"""
)
op.execute(
"""
DROP TRIGGER trg_update_cd_nom ON gn_monitoring.t_observations;
DROP FUNCTION gn_monitoring.fct_trg_t_observations_cd_nom();
"""
)

0 comments on commit 81d9215

Please sign in to comment.