From 211780f4467f27f0e188623b03c46c25823c34bc Mon Sep 17 00:00:00 2001 From: Maxime Vergez Date: Tue, 6 Dec 2022 09:32:12 +0100 Subject: [PATCH] feat(db): wip: add upgrade and began downgrade Downgrade migration need a little bit more work due to the use of sql alchemy and not plain text sql --- backend/gn_module_monitoring/__init__.py | 2 +- .../362cf9d504ec_create_monitoring_schema.py | 62 ++++++++ .../migrations/__init__.py | 0 .../migrations/data/__init__.py | 0 .../migrations/data/monitoring.sql | 150 ++++++++++++++++++ setup.py | 2 +- 6 files changed, 214 insertions(+), 2 deletions(-) create mode 100644 backend/gn_module_monitoring/migrations/362cf9d504ec_create_monitoring_schema.py create mode 100644 backend/gn_module_monitoring/migrations/__init__.py create mode 100644 backend/gn_module_monitoring/migrations/data/__init__.py create mode 100644 backend/gn_module_monitoring/migrations/data/monitoring.sql diff --git a/backend/gn_module_monitoring/__init__.py b/backend/gn_module_monitoring/__init__.py index a797bae29..c95e1aa67 100644 --- a/backend/gn_module_monitoring/__init__.py +++ b/backend/gn_module_monitoring/__init__.py @@ -1,2 +1,2 @@ MODULE_CODE = "MONITORINGS" -MODULE_PICTO = "fa-puzzle-piece" \ No newline at end of file +MODULE_PICTO = "fa-eye" \ No newline at end of file diff --git a/backend/gn_module_monitoring/migrations/362cf9d504ec_create_monitoring_schema.py b/backend/gn_module_monitoring/migrations/362cf9d504ec_create_monitoring_schema.py new file mode 100644 index 000000000..68620b2f3 --- /dev/null +++ b/backend/gn_module_monitoring/migrations/362cf9d504ec_create_monitoring_schema.py @@ -0,0 +1,62 @@ +"""create_monitoring_schema + +Revision ID: 362cf9d504ec +Revises: +Create Date: 2021-03-29 18:38:24.512562 + +""" +import importlib + +from alembic import op +import sqlalchemy as sa +from sqlalchemy.sql import text, and_ + +from geonature.core.gn_permissions.models import TObjects +from geonature.core.gn_commons.models.base import BibTablesLocation +from geonature.utils.env import DB + +# revision identifiers, used by Alembic. +revision = "362cf9d504ec" +down_revision = None +branch_labels = ("monitorings",) +depends_on = ("f06cc80cc8ba",) # GeoNature 2.7.5 + + +monitorings_schema = "gn_monitoring" + + +def upgrade(): + op.execute( + text( + importlib.resources.read_text("gn_module_monitoring.migrations.data", "monitoring.sql") + ) + ) + + +def downgrade(): + op.drop_table("t_module_complements", monitorings_schema) + op.drop_table("t_observation_complements", monitorings_schema) + op.drop_table("t_observation_details", monitorings_schema) + op.drop_table("t_observations", monitorings_schema) + op.drop_table("t_site_complements", monitorings_schema) + op.drop_table("t_sites_groups", monitorings_schema) + op.drop_table("t_visit_complements", monitorings_schema) + + bind = op.get_bind() + session = sa.orm.Session(bind=bind) + + # Remove all GNM related objects + query = session.query(TObjects).filter(TObjects.code_object.like("GNM_%")) + session.delete(query) + + # Remove monitorings related rows in bib_table_locations + query = session.query(BibTablesLocation).filter( + and_( + BibTablesLocation.schema_name == monitorings_schema, + BibTablesLocation.table_name.in_( + "t_module_complements", "t_observations", "t_sites_groups" + ), + ) + ) + session.delete(query) + session.commit() diff --git a/backend/gn_module_monitoring/migrations/__init__.py b/backend/gn_module_monitoring/migrations/__init__.py new file mode 100644 index 000000000..e69de29bb diff --git a/backend/gn_module_monitoring/migrations/data/__init__.py b/backend/gn_module_monitoring/migrations/data/__init__.py new file mode 100644 index 000000000..e69de29bb diff --git a/backend/gn_module_monitoring/migrations/data/monitoring.sql b/backend/gn_module_monitoring/migrations/data/monitoring.sql new file mode 100644 index 000000000..06d8dac85 --- /dev/null +++ b/backend/gn_module_monitoring/migrations/data/monitoring.sql @@ -0,0 +1,150 @@ +-- schema qui complete gn_monitoring pour le module monitoring + +CREATE TABLE IF NOT EXISTS gn_monitoring.t_module_complements ( + + id_module SERIAL NOT NULL, + uuid_module_complement UUID DEFAULT uuid_generate_v4() NOT NULL, + + id_list_observer INTEGER, + id_list_taxonomy INTEGER, + b_synthese BOOLEAN DEFAULT TRUE, + taxonomy_display_field_name CHARACTER VARYING DEFAULT 'nom_vern,lb_nom', + b_draw_sites_group BOOLEAN, + + data JSONB, + + CONSTRAINT pk_t_module_complements PRIMARY KEY (id_module), + CONSTRAINT fk_t_module_complements_id_module FOREIGN KEY (id_module) + REFERENCES gn_commons.t_modules (id_module) MATCH SIMPLE + ON UPDATE CASCADE ON DELETE CASCADE, + CONSTRAINT fk_t_module_complements_id_list_observer FOREIGN KEY (id_list_observer) + REFERENCES utilisateurs.t_listes (id_liste) MATCH SIMPLE + ON UPDATE CASCADE ON DELETE CASCADE, + CONSTRAINT fk_t_module_complements_id_list_taxonomy FOREIGN KEY (id_list_taxonomy) + REFERENCES taxonomie.bib_listes (id_liste) MATCH SIMPLE + ON UPDATE CASCADE ON DELETE CASCADE + ); + + -- Les groupes de site + + CREATE TABLE IF NOT EXISTS gn_monitoring.t_sites_groups ( + id_sites_group SERIAL NOT NULL, + + id_module INTEGER NOT NULL, + sites_group_name character varying(255), + sites_group_code character varying(255), + sites_group_description TEXT, + uuid_sites_group UUID DEFAULT uuid_generate_v4() NOT NULL, + comments TEXT, + data JSONB, + meta_create_date timestamp without time zone DEFAULT now(), + meta_update_date timestamp without time zone DEFAULT now(), + + CONSTRAINT pk_t_sites_groups PRIMARY KEY (id_sites_group), + CONSTRAINT fk_t_sites_groups_id_module FOREIGN KEY (id_module) + REFERENCES gn_commons.t_modules (id_module) MATCH SIMPLE + ON UPDATE CASCADE ON DELETE CASCADE + ); + + DROP TRIGGER IF EXISTS tri_meta_dates_change_t_sites_groups ON gn_monitoring.t_sites_groups; + CREATE TRIGGER tri_meta_dates_change_t_sites_groups + BEFORE INSERT OR UPDATE + ON gn_monitoring.t_sites_groups + FOR EACH ROW + EXECUTE PROCEDURE public.fct_trg_meta_dates_change(); + + CREATE TABLE IF NOT EXISTS gn_monitoring.t_site_complements ( + + id_base_site INTEGER NOT NULL, + id_module INTEGER NOT NULL, + id_sites_group INTEGER, + data JSONB, + + CONSTRAINT pk_t_site_complements PRIMARY KEY (id_base_site), + CONSTRAINT fk_t_site_complements_id_module FOREIGN KEY (id_module) + REFERENCES gn_commons.t_modules (id_module) MATCH SIMPLE + ON UPDATE CASCADE ON DELETE CASCADE, + CONSTRAINT fk_t_site_complement_id_base_site FOREIGN KEY (id_base_site) + REFERENCES gn_monitoring.t_base_sites (id_base_site) MATCH SIMPLE + ON UPDATE CASCADE ON DELETE CASCADE, + CONSTRAINT fk_t_site_complement_id_sites_group FOREIGN KEY (id_sites_group) + REFERENCES gn_monitoring.t_sites_groups (id_sites_group) MATCH SIMPLE + ON UPDATE CASCADE ON DELETE SET NULL -- on ne supprime pas forcement les sites quand on supprime un groupe ?? + + ); + + CREATE TABLE IF NOT EXISTS gn_monitoring.t_visit_complements ( + + id_base_visit INTEGER NOT NULL, + data JSONB, + + CONSTRAINT pk_t_visit_complements PRIMARY KEY (id_base_visit), + CONSTRAINT fk_t_visit_complements_id_base_visit FOREIGN KEY (id_base_visit) + REFERENCES gn_monitoring.t_base_visits (id_base_visit) MATCH SIMPLE + ON UPDATE CASCADE ON DELETE CASCADE + ); + + + CREATE TABLE IF NOT EXISTS gn_monitoring.t_observations ( + id_observation SERIAL NOT NULL, + id_base_visit INTEGER NOT NULL, + cd_nom INTEGER NOT NULL, + comments TEXT, + uuid_observation UUID DEFAULT uuid_generate_v4() NOT NULL, + + + CONSTRAINT pk_t_observations PRIMARY KEY (id_observation), + CONSTRAINT fk_t_observations_id_base_visit FOREIGN KEY (id_base_visit) + REFERENCES gn_monitoring.t_base_visits (id_base_visit) MATCH SIMPLE + ON UPDATE CASCADE ON DELETE CASCADE + ); + + + -- champs en complément de t_observation: relation 1-1 + + CREATE TABLE IF NOT EXISTS gn_monitoring.t_observation_complements ( + + id_observation INTEGER NOT NULL, + data JSONB, + + CONSTRAINT pk_t_observation_complements PRIMARY KEY (id_observation), + CONSTRAINT fk_t_observation_complements_id_observation FOREIGN KEY (id_observation) + REFERENCES gn_monitoring.t_observations (id_observation) MATCH SIMPLE + ON UPDATE CASCADE ON DELETE CASCADE + ); + + -- table fille de t_observation relation 1-n + + CREATE TABLE IF NOT EXISTS gn_monitoring.t_observation_details ( + + id_observation_detail SERIAL NOT NULL, + id_observation INTEGER NOT NULL, + data JSONB, + + CONSTRAINT pk_t_observation_details PRIMARY KEY (id_observation), + CONSTRAINT fk_t_observation_details_id_observation FOREIGN KEY (id_observation) + REFERENCES gn_monitoring.t_observations (id_observation) MATCH SIMPLE + ON UPDATE CASCADE ON DELETE CASCADE + ); + + + -- pour ne pas remettre des lignes qui existent déjà + + INSERT INTO gn_commons.bib_tables_location(table_desc, schema_name, table_name, pk_field, uuid_field_name) + VALUES + ('Table centralisant les modules faisant l''objet de protocole de suivis', 'gn_monitoring', 't_module_complements', 'id_module', 'uuid_module_complement'), + ('Table centralisant les observations réalisées lors d''une visite sur un site', 'gn_monitoring', 't_observations', 'id_observation', 'uuid_observation'), + ('Table centralisant les sites faisant l''objet de protocole de suivis', 'gn_monitoring', 't_base_sites', 'id_base_site', 'uuid_base_site'), + ('Table centralisant les groupes de sites faisant l''objet de protocole de suivis', 'gn_monitoring', 't_sites_groups', 'id_sites_group', 'uuid_sites_group'), + ('Table centralisant les visites réalisées sur un site', 'gn_monitoring', 't_base_visits', 'id_base_visit', 'uuid_base_visit') + -- on evite de mettre 2 fois le meme couple (shema_name, table_name) + ON CONFLICT(schema_name, table_name) DO NOTHING; + + +INSERT INTO gn_permissions.t_objects (code_object, description_object) +VALUES +('GNM_SITES', 'Permissions sur les sites'), +('GNM_VISITES', 'Permissions sur les visites'), +('GNM_OBSERVATIONS', 'Permissions sur les observation'), +('GNM_GRP_SITES', 'Permissions sur les groupes de sites') + ON CONFLICT(code_object) DO NOTHING; diff --git a/setup.py b/setup.py index 3d486f968..88ae61131 100644 --- a/setup.py +++ b/setup.py @@ -32,7 +32,7 @@ 'picto = gn_module_monitoring:MODULE_PICTO', 'blueprint = gn_module_monitoring.blueprint:blueprint', 'config_schema = gn_module_monitoring.conf_schema_toml:GnModuleSchemaConf', - #'migrations = gn_module_monitoring:migrations', + 'migrations = gn_module_monitoring:migrations', ], }, classifiers=['Development Status :: 1 - Planning',