diff --git a/db-migrations/migrations/20240404132816-clear-historic-mechanism.cjs b/db-migrations/migrations/20240404132816-clear-historic-mechanism.cjs new file mode 100644 index 00000000..81880b78 --- /dev/null +++ b/db-migrations/migrations/20240404132816-clear-historic-mechanism.cjs @@ -0,0 +1,201 @@ +'use strict' + +require('dotenv').config() + +const {POSTGRES_BAN_USER} = process.env + +/** @type {import('sequelize-cli').Migration} */ +module.exports = { + async up(queryInterface) { + try { + // Clear trigger and trigger function + await queryInterface.sequelize.query(` + DROP TRIGGER IF EXISTS ban_9trigger_histo_on_adress ON ban.address; + DROP TRIGGER IF EXISTS ban_9trigger_histo_on_ct ON ban.common_toponym; + DROP TRIGGER IF EXISTS ban_9trigger_histo_on_district ON ban.district; + DROP FUNCTION IF EXISTS public.historisation(); + `) + + // Drop all historic tables + await queryInterface.sequelize.query(` + DROP TABLE IF EXISTS ban.address_h; + DROP TABLE IF EXISTS ban.common_toponym_h; + DROP TABLE IF EXISTS ban.district_h; + `) + + // Delete data that was previously "deleted" by the trigger + await queryInterface.sequelize.query(` + DELETE FROM ban.address WHERE upper(range_validity) IS NOT NULL; + DELETE FROM ban.common_toponym WHERE upper(range_validity) IS NOT NULL; + DELETE FROM ban.district WHERE upper(range_validity) IS NOT NULL; + `) + + // Drop range_validity on all current tables + await queryInterface.sequelize.query(` + ALTER TABLE ban.address DROP COLUMN range_validity; + ALTER TABLE ban.common_toponym DROP COLUMN range_validity; + ALTER TABLE ban.district DROP COLUMN range_validity; + `) + + await queryInterface.sequelize.query('DROP EXTENSION IF EXISTS btree_gist;') + } catch (error) { + console.error(error) + } + }, + + async down(queryInterface) { + try { + // Add range_validity column on common_toponym table + await queryInterface.sequelize.query(` + ALTER TABLE ban.address ADD range_validity tstzrange DEFAULT tstzrange(CURRENT_TIMESTAMP,NULL); + ALTER TABLE ban.address ALTER COLUMN range_validity DROP DEFAULT; + ALTER TABLE ban.address ALTER COLUMN range_validity SET NOT NULL; + ALTER TABLE ban.address ADD CONSTRAINT range_validity CHECK(ISEMPTY(range_validity)IS False); + `) + + // Add range_validity column on common_toponym table + await queryInterface.sequelize.query(` + ALTER TABLE ban.common_toponym ADD range_validity tstzrange DEFAULT tstzrange(CURRENT_TIMESTAMP,NULL); + ALTER TABLE ban.common_toponym ALTER COLUMN range_validity DROP DEFAULT; + ALTER TABLE ban.common_toponym ALTER COLUMN range_validity SET NOT NULL; + ALTER TABLE ban.common_toponym ADD CONSTRAINT range_validity CHECK(ISEMPTY(range_validity)IS False); + `) + + // Add range_validity column on district table + await queryInterface.sequelize.query(` + ALTER TABLE ban.district ADD range_validity tstzrange DEFAULT tstzrange(CURRENT_TIMESTAMP,NULL); + ALTER TABLE ban.district ALTER COLUMN range_validity DROP DEFAULT; + ALTER TABLE ban.district ALTER COLUMN range_validity SET NOT NULL; + ALTER TABLE ban.district ADD CONSTRAINT range_validity CHECK(ISEMPTY(range_validity)IS False); + `) + + await queryInterface.sequelize.query('CREATE EXTENSION IF NOT EXISTS btree_gist;') + + // Create address_h historic table + // the adresse_h_id_range_validity_excl constraint ensures that no two rows have the same id value and overlapping range_validity ranges. + await queryInterface.sequelize.query(` + CREATE TABLE ban.address_h (LIKE ban.address); + ALTER TABLE ban.address_h ADD CONSTRAINT adresse_h_id_fkey FOREIGN KEY (id) + REFERENCES ban.address (id) MATCH SIMPLE + ON UPDATE NO ACTION + ON DELETE NO ACTION; + ALTER TABLE ban.address_h ADD CONSTRAINT adresse_h_id_range_validity_excl EXCLUDE USING gist ( + id WITH =, + range_validity WITH &&); + CREATE INDEX ON ban.address_h (id); + CREATE INDEX ON ban.address_h USING GIST (range_validity); + ALTER TABLE ban.address_h ALTER COLUMN range_validity SET NOT NULL; + ALTER TABLE ban.address_h ADD CONSTRAINT range_validity CHECK(ISEMPTY(range_validity)IS False); + `) + + // Create common_toponym_h historic table + // the common_toponym_h_id_range_validity_excl constraint ensures that no two rows have the same id value and overlapping range_validity ranges. + await queryInterface.sequelize.query(` + CREATE TABLE ban.common_toponym_h (LIKE ban.common_toponym); + ALTER TABLE ban.common_toponym_h ADD CONSTRAINT common_toponym_h_id_fkey FOREIGN KEY (id) + REFERENCES ban.common_toponym (id) MATCH SIMPLE + ON UPDATE NO ACTION + ON DELETE NO ACTION; + ALTER TABLE ban.common_toponym_h ADD CONSTRAINT common_toponym_h_id_range_validity_excl EXCLUDE USING gist ( + id WITH =, + range_validity WITH &&); + CREATE INDEX ON ban.common_toponym_h (id); + CREATE INDEX ON ban.common_toponym_h USING GIST (range_validity); + ALTER TABLE ban.common_toponym_h ALTER COLUMN range_validity SET NOT NULL; + ALTER TABLE ban.common_toponym_h ADD CONSTRAINT range_validity CHECK(ISEMPTY(range_validity)IS False); + `) + + // Create district_h historic table + // the district_h_id_range_validity_excl constraint ensures that no two rows have the same id value and overlapping range_validity ranges. + await queryInterface.sequelize.query(` + CREATE TABLE ban.district_h (LIKE ban.district); + ALTER TABLE ban.district_h ADD CONSTRAINT district_h_id_fkey FOREIGN KEY (id) + REFERENCES ban.district (id) MATCH SIMPLE + ON UPDATE NO ACTION + ON DELETE NO ACTION; + ALTER TABLE ban.district_h ADD CONSTRAINT district_h_id_range_validity_excl EXCLUDE USING gist ( + id WITH =, + range_validity WITH &&); + CREATE INDEX ON ban.district_h (id); + CREATE INDEX ON ban.district_h USING GIST (range_validity); + ALTER TABLE ban.district_h ALTER COLUMN range_validity SET NOT NULL; + ALTER TABLE ban.district_h ADD CONSTRAINT range_validity CHECK(ISEMPTY(range_validity)IS False); + `) + // Grant permissions to ban user + await queryInterface.sequelize.query(`GRANT SELECT, INSERT ON TABLE ban.address_h, ban.common_toponym_h, ban.district_h TO "${POSTGRES_BAN_USER}";`) + + await queryInterface.sequelize.query(` + --@version 0.02, 2024-02-26 + --@author IGN + ------------------ FONCTION TRIGGER----------------------------------------------------- + CREATE OR REPLACE FUNCTION public.historisation() + RETURNS trigger + LANGUAGE 'plpgsql' + + AS $BODY$ + + BEGIN + IF (TG_OP = 'INSERT') THEN + NEW.range_validity = tstzrange(current_timestamp::timestamp,NULL); + RETURN NEW; + ELSEIF (TG_OP = 'UPDATE') THEN + --si il n'y a pas de changement pas d'update et pas action dans historique on interrompt l'action du trigger-- + IF NEW IS NOT DISTINCT FROM OLD THEN + RAISE NOTICE 'table %s: id=% objet sans modification, aucune opération réalisée!', TG_TABLE_NAME,OLD.ID; + RETURN NULL; + END IF; + -- le changement d'id ne doit pas arriver, au cas où on renvoie une exception + IF NEW.ID IS DISTINCT FROM OLD.ID THEN + RAISE EXCEPTION 'table %s: update sur le champ id de l''objet %s non valide',TG_TABLE_NAME, OLD.ID USING ERRCODE = '09000'; + END IF; + -- le changement du champ date_validity n'est pas autorisé à ce niveau, et ne doit être réalisé que par le trigger, on renvoie une exception + IF NEW.range_validity IS DISTINCT FROM OLD.range_validity OR upper(NEW.range_validity) IS NOT NULL THEN + RAISE EXCEPTION 'table %s: operation update sur le champ range_validity (valeur upper=%) de l''objet %s non autorisé',TG_TABLE_NAME,NEW.range_validity, OLD.ID USING ERRCODE = '09000'; + END IF; + --IF upper(NEW.range_validity) is NOT NULL THEN + --RAISE NOTICE 'table %s: id=% cas non prévu!', TG_TABLE_NAME,OLD.ID; + --RETURN NULL; + --END IF; + OLD.range_validity = tstzrange(lower(OLD.range_validity),current_timestamp); + NEW.range_validity = tstzrange(current_timestamp,NULL); + + EXECUTE format('INSERT INTO '|| TG_TABLE_SCHEMA ||'.' || TG_TABLE_NAME || '_h VALUES ($1.*)') USING OLD; + RETURN NEW; + ELSEIF (TG_OP = 'DELETE') THEN -- c'est un update sans enregistrement dans l'historique ne doit pas declencher une recursion du trigger + IF upper(OLD.range_validity) IS NOT NULL THEN -- objet avec date fin de validité anciennement présente, on ne fait rien + RAISE NOTICE 'table %s: id=% date de fin de validité déjà présente, aucune opération réalisée!', TG_TABLE_NAME,OLD.ID; + RETURN NULL; + END IF; + + EXECUTE format('UPDATE %I.%I SET range_validity=tstzrange(lower(range_validity),current_timestamp) WHERE id=%L;', + TG_TABLE_SCHEMA,TG_TABLE_NAME,OLD.ID ); + RETURN NULL; + ELSE + RETURN NEW; + END IF; + END + $BODY$; + + -----------------TRIGGERS------------------------------------------- + --exclusion du champ date_validity pour eviter appels recursifs, ajout du champ id -à priori inutile -mais pour contrôle supplémentaire + --address + DROP TRIGGER IF EXISTS ban_9trigger_histo_on_adress ON ban.address ; + CREATE TRIGGER ban_9trigger_histo_on_adress BEFORE INSERT OR DELETE OR UPDATE + OF id, "mainCommonToponymID","secondaryCommonToponymIDs","districtID","number",suffix,labels,certified,positions,"updateDate",meta + ON ban.address FOR EACH ROW EXECUTE PROCEDURE public.historisation(); + --common_toponym + DROP TRIGGER IF EXISTS ban_9trigger_histo_on_ct ON ban.common_toponym; + CREATE TRIGGER ban_9trigger_histo_on_ct BEFORE INSERT OR DELETE OR UPDATE + OF id, "districtID",labels,geometry,"updateDate",meta + ON ban.common_toponym FOR EACH ROW EXECUTE PROCEDURE public.historisation(); + --district + DROP TRIGGER IF EXISTS ban_9trigger_histo_on_district ON ban.district; + CREATE TRIGGER ban_9trigger_histo_on_district BEFORE INSERT OR DELETE OR UPDATE + OF id, labels,"updateDate",config,meta + ON ban.district FOR EACH ROW EXECUTE PROCEDURE public.historisation(); + `) + } catch (error) { + console.error(error) + } + } +} diff --git a/db-migrations/migrations/20240404134334-add-range-validity-and-is-active.cjs b/db-migrations/migrations/20240404134334-add-range-validity-and-is-active.cjs new file mode 100644 index 00000000..1ddaa0e2 --- /dev/null +++ b/db-migrations/migrations/20240404134334-add-range-validity-and-is-active.cjs @@ -0,0 +1,52 @@ +'use strict' + +/** @type {import('sequelize-cli').Migration} */ +module.exports = { + async up(queryInterface) { + try { + // Add range_validity and isActive columns on address table + await queryInterface.sequelize.query(` + ALTER TABLE ban.address ADD range_validity tstzrange DEFAULT tstzrange(CURRENT_TIMESTAMP,NULL); + ALTER TABLE ban.address ADD "isActive" boolean DEFAULT true; + ALTER TABLE ban.address ALTER COLUMN "isActive" SET NOT NULL; + `) + + // Add range_validity and isActive columns on common_toponym table + await queryInterface.sequelize.query(` + ALTER TABLE ban.common_toponym ADD range_validity tstzrange DEFAULT tstzrange(CURRENT_TIMESTAMP,NULL); + ALTER TABLE ban.common_toponym ADD "isActive" boolean DEFAULT true; + ALTER TABLE ban.common_toponym ALTER COLUMN "isActive" SET NOT NULL; + `) + + // Add range_validity and isActive columns on district table + await queryInterface.sequelize.query(` + ALTER TABLE ban.district ADD range_validity tstzrange DEFAULT tstzrange(CURRENT_TIMESTAMP,NULL); + ALTER TABLE ban.district ADD "isActive" boolean DEFAULT true; + ALTER TABLE ban.district ALTER COLUMN "isActive" SET NOT NULL; + `) + } catch (error) { + console.error(error) + } + }, + + async down(queryInterface) { + try { + await queryInterface.sequelize.query(` + ALTER TABLE ban.address DROP COLUMN range_validity; + ALTER TABLE ban.address DROP COLUMN "isActive"; + `) + + await queryInterface.sequelize.query(` + ALTER TABLE ban.common_toponym DROP COLUMN range_validity; + ALTER TABLE ban.common_toponym DROP COLUMN "isActive"; + `) + + await queryInterface.sequelize.query(` + ALTER TABLE ban.district DROP COLUMN range_validity; + ALTER TABLE ban.district DROP COLUMN "isActive"; + `) + } catch (error) { + console.error(error) + } + } +} diff --git a/db-migrations/migrations/20240404140053-clear-delete-right.cjs b/db-migrations/migrations/20240404140053-clear-delete-right.cjs new file mode 100644 index 00000000..20a135c2 --- /dev/null +++ b/db-migrations/migrations/20240404140053-clear-delete-right.cjs @@ -0,0 +1,28 @@ +'use strict' + +require('dotenv').config() + +const {POSTGRES_BAN_USER} = process.env + +/** @type {import('sequelize-cli').Migration} */ +module.exports = { + async up(queryInterface) { + try { + await queryInterface.sequelize.query(`REVOKE DELETE ON ban.address FROM "${POSTGRES_BAN_USER}"`) + await queryInterface.sequelize.query(`REVOKE DELETE ON ban.common_toponym FROM "${POSTGRES_BAN_USER}"`) + await queryInterface.sequelize.query(`REVOKE DELETE ON ban.district FROM "${POSTGRES_BAN_USER}"`) + } catch (error) { + console.log(error) + } + }, + + async down(queryInterface) { + try { + await queryInterface.sequelize.query(`GRANT DELETE ON ban.address TO "${POSTGRES_BAN_USER}"`) + await queryInterface.sequelize.query(`GRANT DELETE ON ban.common_toponym TO "${POSTGRES_BAN_USER}"`) + await queryInterface.sequelize.query(`GRANT DELETE ON ban.district TO "${POSTGRES_BAN_USER}"`) + } catch (error) { + console.log(error) + } + } +} diff --git a/db-migrations/migrations/20240404142921-rebuild-historic-tables.cjs b/db-migrations/migrations/20240404142921-rebuild-historic-tables.cjs new file mode 100644 index 00000000..d5c1361e --- /dev/null +++ b/db-migrations/migrations/20240404142921-rebuild-historic-tables.cjs @@ -0,0 +1,84 @@ +'use strict' + +require('dotenv').config() + +const {POSTGRES_BAN_USER} = process.env + +/** @type {import('sequelize-cli').Migration} */ +module.exports = { + async up(queryInterface) { + try { + // Add btree_gist extension used for creating exclusion constraints using GiST indexes on range types + await queryInterface.sequelize.query('CREATE EXTENSION IF NOT EXISTS btree_gist;') + + // Create address_h historic table + // the adresse_h_id_range_validity_excl constraint ensures that no two rows have the same id value and overlapping range_validity ranges. + await queryInterface.sequelize.query(` + CREATE TABLE ban.address_h (LIKE ban.address); + ALTER TABLE ban.address_h ADD CONSTRAINT adresse_h_id_fkey FOREIGN KEY (id) + REFERENCES ban.address (id) MATCH SIMPLE + ON UPDATE NO ACTION + ON DELETE NO ACTION; + ALTER TABLE ban.address_h ADD CONSTRAINT adresse_h_id_range_validity_excl EXCLUDE USING gist ( + id WITH =, + range_validity WITH &&); + CREATE INDEX ON ban.address_h (id); + CREATE INDEX ON ban.address_h USING GIST (range_validity); + ALTER TABLE ban.address_h ALTER COLUMN range_validity SET NOT NULL; + ALTER TABLE ban.address_h ADD CONSTRAINT range_validity CHECK(ISEMPTY(range_validity)IS False); + `) + + // Create common_toponym_h historic table + // the common_toponym_h_id_range_validity_excl constraint ensures that no two rows have the same id value and overlapping range_validity ranges. + await queryInterface.sequelize.query(` + CREATE TABLE ban.common_toponym_h (LIKE ban.common_toponym); + ALTER TABLE ban.common_toponym_h ADD CONSTRAINT common_toponym_h_id_fkey FOREIGN KEY (id) + REFERENCES ban.common_toponym (id) MATCH SIMPLE + ON UPDATE NO ACTION + ON DELETE NO ACTION; + ALTER TABLE ban.common_toponym_h ADD CONSTRAINT common_toponym_h_id_range_validity_excl EXCLUDE USING gist ( + id WITH =, + range_validity WITH &&); + CREATE INDEX ON ban.common_toponym_h (id); + CREATE INDEX ON ban.common_toponym_h USING GIST (range_validity); + ALTER TABLE ban.common_toponym_h ALTER COLUMN range_validity SET NOT NULL; + ALTER TABLE ban.common_toponym_h ADD CONSTRAINT range_validity CHECK(ISEMPTY(range_validity)IS False); + `) + + // Create district_h historic table + // the district_h_id_range_validity_excl constraint ensures that no two rows have the same id value and overlapping range_validity ranges. + await queryInterface.sequelize.query(` + CREATE TABLE ban.district_h (LIKE ban.district); + ALTER TABLE ban.district_h ADD CONSTRAINT district_h_id_fkey FOREIGN KEY (id) + REFERENCES ban.district (id) MATCH SIMPLE + ON UPDATE NO ACTION + ON DELETE NO ACTION; + ALTER TABLE ban.district_h ADD CONSTRAINT district_h_id_range_validity_excl EXCLUDE USING gist ( + id WITH =, + range_validity WITH &&); + CREATE INDEX ON ban.district_h (id); + CREATE INDEX ON ban.district_h USING GIST (range_validity); + ALTER TABLE ban.district_h ALTER COLUMN range_validity SET NOT NULL; + ALTER TABLE ban.district_h ADD CONSTRAINT range_validity CHECK(ISEMPTY(range_validity)IS False); + `) + // Grant permissions to ban user + await queryInterface.sequelize.query(`GRANT SELECT, INSERT ON TABLE ban.address_h, ban.common_toponym_h, ban.district_h TO "${POSTGRES_BAN_USER}";`) + } catch (error) { + console.log(error) + } + }, + + async down(queryInterface) { + try { + // Drop historic tables + await queryInterface.sequelize.query('DROP TABLE IF EXISTS ban.address_h;') + await queryInterface.sequelize.query('DROP TABLE IF EXISTS ban.common_toponym_h;') + await queryInterface.sequelize.query('DROP TABLE IF EXISTS ban.district_h;') + + // Drop btree_gist extension + await queryInterface.sequelize.query('DROP EXTENSION IF EXISTS btree_gist;') + } catch (error) { + console.log(error) + } + } +} diff --git a/db-migrations/migrations/20240404142956-rebuild-historic-trigger.cjs b/db-migrations/migrations/20240404142956-rebuild-historic-trigger.cjs new file mode 100644 index 00000000..8cdcdceb --- /dev/null +++ b/db-migrations/migrations/20240404142956-rebuild-historic-trigger.cjs @@ -0,0 +1,111 @@ +'use strict' + +/** @type {import('sequelize-cli').Migration} */ +module.exports = { + async up(queryInterface) { + try { + await queryInterface.sequelize.query(` + ALTER TABLE ban.address ALTER COLUMN range_validity DROP DEFAULT; + ALTER TABLE ban.address ALTER COLUMN range_validity SET NOT NULL; + ALTER TABLE ban.address ADD CONSTRAINT range_validity CHECK(ISEMPTY(range_validity)IS False); + `) + + await queryInterface.sequelize.query(` + ALTER TABLE ban.common_toponym ALTER COLUMN range_validity DROP DEFAULT; + ALTER TABLE ban.common_toponym ALTER COLUMN range_validity SET NOT NULL; + ALTER TABLE ban.common_toponym ADD CONSTRAINT range_validity CHECK(ISEMPTY(range_validity)IS False); + `) + + await queryInterface.sequelize.query(` + ALTER TABLE ban.district ALTER COLUMN range_validity DROP DEFAULT; + ALTER TABLE ban.district ALTER COLUMN range_validity SET NOT NULL; + ALTER TABLE ban.district ADD CONSTRAINT range_validity CHECK(ISEMPTY(range_validity)IS False); + `) + + await queryInterface.sequelize.query(` + --@version 0.02, 2024-02-26 + --@author IGN + ------------------ FONCTION TRIGGER----------------------------------------------------- + CREATE OR REPLACE FUNCTION public.historisation() + RETURNS trigger + LANGUAGE 'plpgsql' + + AS $BODY$ + + BEGIN + IF (TG_OP = 'INSERT') THEN + NEW.range_validity = tstzrange(current_timestamp::timestamp,NULL); + RETURN NEW; + ELSEIF (TG_OP = 'UPDATE') THEN + --s'il n'y a pas de changement, pas d'update et pas d'action dans l'historique, on interrompt l'action du trigger-- + IF NEW IS NOT DISTINCT FROM OLD THEN + RAISE NOTICE 'table %s: id=% objet sans modification, aucune opération réalisée!', TG_TABLE_NAME,OLD.ID; + RETURN NULL; + END IF; + -- le changement d'id ne doit pas arriver, au cas où, on renvoie une exception + IF NEW.ID IS DISTINCT FROM OLD.ID THEN + RAISE EXCEPTION 'table %s: update sur le champ id de l''objet %s non valide',TG_TABLE_NAME, OLD.ID USING ERRCODE = '09000'; + END IF; + -- le changement du champ range_validity n'est pas autorisé à ce niveau et ne doit être réalisé que par le trigger, on renvoie une exception + IF NEW.range_validity IS DISTINCT FROM OLD.range_validity OR upper(NEW.range_validity) IS NOT NULL THEN + RAISE EXCEPTION 'table %s: opération update sur le champ range_validity (valeur upper=%) de l''objet %s non autorisé',TG_TABLE_NAME,NEW.range_validity, OLD.ID USING ERRCODE = '09000'; + END IF; + OLD.range_validity = tstzrange(lower(OLD.range_validity),current_timestamp); + NEW.range_validity = tstzrange(current_timestamp,NULL); + + EXECUTE format('INSERT INTO '|| TG_TABLE_SCHEMA ||'.' || TG_TABLE_NAME || '_h VALUES ($1.*)') USING OLD; + RETURN NEW; + ELSE + RETURN NEW; + END IF; + END + $BODY$; + -----------------TRIGGERS------------------------------------------- + --exclusion du champ range_validity pour éviter des appels récursifs, ajout du champ id -à priori inutile -mais pour contrôle supplémentaire + --address + DROP TRIGGER IF EXISTS ban_9trigger_histo_on_adress ON ban.address ; + CREATE TRIGGER ban_9trigger_histo_on_adress BEFORE INSERT OR UPDATE + OF id, "mainCommonToponymID","secondaryCommonToponymIDs","districtID","number",suffix,labels,certified,positions,"updateDate",meta,"isActive" + ON ban.address FOR EACH ROW EXECUTE PROCEDURE public.historisation(); + --common_toponym + DROP TRIGGER IF EXISTS ban_9trigger_histo_on_ct ON ban.common_toponym; + CREATE TRIGGER ban_9trigger_histo_on_ct BEFORE INSERT OR UPDATE + OF id, "districtID",labels,geometry,"updateDate",meta,"isActive" + ON ban.common_toponym FOR EACH ROW EXECUTE PROCEDURE public.historisation(); + --district + DROP TRIGGER IF EXISTS ban_9trigger_histo_on_district ON ban.district; + CREATE TRIGGER ban_9trigger_histo_on_district BEFORE INSERT OR UPDATE + OF id, labels,"updateDate",config,meta,"isActive" + ON ban.district FOR EACH ROW EXECUTE PROCEDURE public.historisation(); + `) + } catch (error) { + console.log(error) + } + }, + + async down(queryInterface) { + try { + await queryInterface.sequelize.query('DROP TRIGGER IF EXISTS ban_9trigger_histo_on_adress ON ban.address;') + await queryInterface.sequelize.query('DROP TRIGGER IF EXISTS ban_9trigger_histo_on_ct ON ban.common_toponym;') + await queryInterface.sequelize.query('DROP TRIGGER IF EXISTS ban_9trigger_histo_on_district ON ban.district;') + + await queryInterface.sequelize.query(` + ALTER TABLE ban.address DROP CONSTRAINT range_validity; + ALTER TABLE ban.address ALTER COLUMN range_validity DROP NOT NULL; + ALTER TABLE ban.address ALTER COLUMN range_validity SET DEFAULT tstzrange(CURRENT_TIMESTAMP,NULL); + `) + await queryInterface.sequelize.query(` + ALTER TABLE ban.common_toponym DROP CONSTRAINT range_validity; + ALTER TABLE ban.common_toponym ALTER COLUMN range_validity DROP NOT NULL; + ALTER TABLE ban.common_toponym ALTER COLUMN range_validity SET DEFAULT tstzrange(CURRENT_TIMESTAMP,NULL); + `) + await queryInterface.sequelize.query(` + ALTER TABLE ban.district DROP CONSTRAINT range_validity; + ALTER TABLE ban.district ALTER COLUMN range_validity DROP NOT NULL; + ALTER TABLE ban.district ALTER COLUMN range_validity SET DEFAULT tstzrange(CURRENT_TIMESTAMP,NULL); + `) + } catch (error) { + console.log(error) + } + } +} diff --git a/lib/api/address/__mocks__/address-data-mock.js b/lib/api/address/__mocks__/address-data-mock.js index 20df6553..a1984824 100644 --- a/lib/api/address/__mocks__/address-data-mock.js +++ b/lib/api/address/__mocks__/address-data-mock.js @@ -104,7 +104,8 @@ export const bddAddressMock = [ idfix: { hash: 'd80b0d6020798ff15e8d5416911201aa' } - } + }, + isActive: true }, { id: '00000000-0000-4fff-9fff-00000000002b', @@ -124,7 +125,8 @@ export const bddAddressMock = [ idfix: { hash: '2ce8a4621b2843043725992ab2a61acc' } - } + }, + isActive: true }, { id: '00000000-0000-4fff-9fff-00000000002c', @@ -144,6 +146,7 @@ export const bddAddressMock = [ idfix: { hash: 'be796e420febda49c29e38745db3cae2' } - } + }, + isActive: true } ] diff --git a/lib/api/address/__mocks__/address-models.js b/lib/api/address/__mocks__/address-models.js index d8a4035f..cc160c67 100644 --- a/lib/api/address/__mocks__/address-models.js +++ b/lib/api/address/__mocks__/address-models.js @@ -5,7 +5,7 @@ export async function getAddresses(addressIDs) { } export async function getAllAddressIDsWithHashFromDistrict(districtID) { - return bddAddressMock.filter(({districtID: districtIDAddress}) => districtIDAddress === districtID).map(({id, meta}) => ({id, hash: meta?.idfix?.hash})) + return bddAddressMock.filter(({districtID: districtIDAddress}) => districtIDAddress === districtID).map(({id, meta, isActive}) => ({id, hash: meta?.idfix?.hash, isActive})) } export async function getAllAddressIDsOutsideDistrict(addressIDs, districtID) { diff --git a/lib/api/address/models.js b/lib/api/address/models.js index 6ea0c77c..f7c90e49 100644 --- a/lib/api/address/models.js +++ b/lib/api/address/models.js @@ -6,8 +6,8 @@ export const getAddress = addressID => Address.findByPk(addressID, {raw: true}) export const getAddresses = addressIDs => Address.findAll({where: {id: addressIDs}, raw: true}) export const getAllAddressIDsWithHashFromDistrict = async districtID => { - const addresses = await Address.findAll({where: {districtID}, attributes: ['id', 'meta'], raw: true}) - return addresses.map(address => ({id: address.id, hash: address.meta?.idfix?.hash})) + const addresses = await Address.findAll({where: {districtID}, attributes: ['id', 'meta', 'isActive'], raw: true}) + return addresses.map(address => ({id: address.id, hash: address.meta?.idfix?.hash, isActive: address.isActive})) } export const getAllAddressIDsOutsideDistrict = async (addressIDs, districtID) => { @@ -18,7 +18,7 @@ export const getAllAddressIDsOutsideDistrict = async (addressIDs, districtID) => export const setAddresses = addresses => Address.bulkCreate(addresses) export const updateAddresses = async addresses => { - const bulkOperations = addresses.map(address => Address.update(address, {where: {id: address.id}})) + const bulkOperations = addresses.map(address => Address.update({...address, isActive: true}, {where: {id: address.id}})) return Promise.all(bulkOperations) } @@ -28,7 +28,7 @@ export const patchAddresses = async addresses => { const {meta, ...addressRest} = address const addressID = address.id const addressDB = await Address.findByPk(addressID) - addressDB.set(addressRest) + addressDB.set({...addressRest, isActive: true}) addressDB.meta = {...addressDB.meta, ...meta} return addressDB.save() }) @@ -36,9 +36,9 @@ export const patchAddresses = async addresses => { return Promise.all(bulkOperations) } -export const deleteAddress = addressID => Address.destroy({where: {id: addressID}}) +export const deleteAddress = addressID => Address.update({isActive: false}, {where: {id: addressID}}) -export const deleteAddresses = addressIDs => Address.destroy({where: {id: addressIDs}}) +export const deleteAddresses = addressIDs => Address.update({isActive: false}, {where: {id: addressIDs}}) export const getAllDistrictIDsFromAddresses = async addressIDs => { const addresses = await Address.findAll({where: {id: addressIDs}, attributes: ['districtID'], raw: true}) diff --git a/lib/api/address/utils.js b/lib/api/address/utils.js index b0ef3f38..9edf6a95 100644 --- a/lib/api/address/utils.js +++ b/lib/api/address/utils.js @@ -85,7 +85,7 @@ export const checkAddressesRequest = async (addresses, actionType) => { export const getDeltaReport = async (addressIDsWithHash, districtID) => { const addressIDsWithHashMap = new Map(addressIDsWithHash.map(({id, hash}) => [id, hash])) const allAddressIDsWithHashFromDistrict = await getAllAddressIDsWithHashFromDistrict(districtID) - const allAddressIDsWithHashFromDistrictMap = new Map(allAddressIDsWithHashFromDistrict.map(({id, hash}) => [id, hash])) + const allAddressIDsWithHashFromDistrictMap = new Map(allAddressIDsWithHashFromDistrict.map(({id, hash, isActive}) => [id, {hash, isActive}])) let idsToCreate = [] const idsToUpdate = [] @@ -93,7 +93,7 @@ export const getDeltaReport = async (addressIDsWithHash, districtID) => { for (const [id, hash] of addressIDsWithHashMap) { if (allAddressIDsWithHashFromDistrictMap.has(id)) { - if (allAddressIDsWithHashFromDistrictMap.get(id) !== hash) { + if (allAddressIDsWithHashFromDistrictMap.get(id).hash !== hash || !allAddressIDsWithHashFromDistrictMap.get(id).isActive) { idsToUpdate.push(id) } } else { @@ -102,7 +102,7 @@ export const getDeltaReport = async (addressIDsWithHash, districtID) => { } for (const id of allAddressIDsWithHashFromDistrictMap.keys()) { - if (!addressIDsWithHashMap.has(id)) { + if (!addressIDsWithHashMap.has(id) && allAddressIDsWithHashFromDistrictMap.get(id).isActive) { idsToDelete.push(id) } } diff --git a/lib/api/address/utils.spec.js b/lib/api/address/utils.spec.js index da86be9a..e72a1790 100644 --- a/lib/api/address/utils.spec.js +++ b/lib/api/address/utils.spec.js @@ -112,7 +112,7 @@ describe('checkAddressesRequest', () => { }) it('Some unavailable common toponym IDs on update', async () => { - const addressesValidation = await checkAddressesRequest(bddAddressMock.map(addr => ({...addr, mainCommonToponymID: '00000000-0000-4fff-9fff-00000000001d'})), 'update') + const addressesValidation = await checkAddressesRequest(bddAddressMock.map(({isActive, ...addrRest}) => ({...addrRest, mainCommonToponymID: '00000000-0000-4fff-9fff-00000000001d'})), 'update') const testSchema = await addressesValidationSchema.isValid(addressesValidation, {strict: true}) expect(testSchema).toBe(true) expect(addressesValidation?.isValid).toBe(false) @@ -120,7 +120,7 @@ describe('checkAddressesRequest', () => { }) it('Some unavailable district IDs on update', async () => { - const addressesValidation = await checkAddressesRequest(bddAddressMock.map(addr => ({...addr, districtID: '00000000-0000-4fff-9fff-000000000003'})), 'update') + const addressesValidation = await checkAddressesRequest(bddAddressMock.map(({isActive, ...addrRest}) => ({...addrRest, districtID: '00000000-0000-4fff-9fff-000000000003'})), 'update') const testSchema = await addressesValidationSchema.isValid(addressesValidation, {strict: true}) expect(testSchema).toBe(true) expect(addressesValidation?.isValid).toBe(false) @@ -128,7 +128,7 @@ describe('checkAddressesRequest', () => { }) it('Available addresses on update', async () => { - const addressesValidation = await checkAddressesRequest(bddAddressMock.map(addr => ({...addr, certified: true})), 'update') + const addressesValidation = await checkAddressesRequest(bddAddressMock.map(({isActive, ...addrRest}) => ({...addrRest, certified: true})), 'update') const testSchema = await addressesValidationSchema.isValid(addressesValidation, {strict: true}) expect(testSchema).toBe(true) expect(addressesValidation?.isValid).toBe(true) diff --git a/lib/api/common-toponym/__mocks__/common-toponym-data-mock.js b/lib/api/common-toponym/__mocks__/common-toponym-data-mock.js index f59a3005..f554f82e 100644 --- a/lib/api/common-toponym/__mocks__/common-toponym-data-mock.js +++ b/lib/api/common-toponym/__mocks__/common-toponym-data-mock.js @@ -76,7 +76,8 @@ export const bddCommonToponymMock = [ idfix: { hash: '1a4ead8b39d17dfe89418452c9bba770' } - } + }, + isActive: true }, { id: '00000000-0000-4fff-9fff-00000000001b', @@ -94,7 +95,8 @@ export const bddCommonToponymMock = [ idfix: { hash: 'd80b0d6020798ff15e8d5416911201aa' } - } + }, + isActive: true }, { id: '00000000-0000-4fff-9fff-00000000001c', @@ -112,6 +114,7 @@ export const bddCommonToponymMock = [ idfix: { hash: '2ce8a4621b2843043725992ab2a61acc' } - } + }, + isActive: true } ] diff --git a/lib/api/common-toponym/__mocks__/common-toponym-models.js b/lib/api/common-toponym/__mocks__/common-toponym-models.js index 459fcaa1..cd79b531 100644 --- a/lib/api/common-toponym/__mocks__/common-toponym-models.js +++ b/lib/api/common-toponym/__mocks__/common-toponym-models.js @@ -5,7 +5,7 @@ export async function getCommonToponyms(commonToponymIDs) { } export async function getAllCommonToponymIDsWithHashFromDistrict(districtID) { - return bddCommonToponymMock.filter(({districtID: districtIDCommonToponym}) => districtIDCommonToponym === districtID).map(({id, meta}) => ({id, hash: meta?.idfix?.hash})) + return bddCommonToponymMock.filter(({districtID: districtIDCommonToponym}) => districtIDCommonToponym === districtID).map(({id, meta, isActive}) => ({id, hash: meta?.idfix?.hash, isActive})) } export async function getAllCommonToponymIDsOutsideDistrict(commonToponymIDs, districtID) { diff --git a/lib/api/common-toponym/models.js b/lib/api/common-toponym/models.js index ce9d91ec..9232df6b 100644 --- a/lib/api/common-toponym/models.js +++ b/lib/api/common-toponym/models.js @@ -7,9 +7,9 @@ export const getCommonToponyms = commonToponymIDs => CommonToponym.findAll({wher export const getAllCommonToponymIDsWithHashFromDistrict = async districtID => { const commonToponyms = await CommonToponym.findAll( - {where: {districtID}, attributes: ['id', 'meta'], raw: true} + {where: {districtID}, attributes: ['id', 'meta', 'isActive'], raw: true} ) - return commonToponyms.map(commonToponym => ({id: commonToponym.id, hash: commonToponym.meta?.idfix?.hash})) + return commonToponyms.map(commonToponym => ({id: commonToponym.id, hash: commonToponym.meta?.idfix?.hash, isActive: commonToponym.isActive})) } export const getAllCommonToponymIDsOutsideDistrict = async (commonToponymIDs, districtID) => { @@ -23,7 +23,7 @@ export const setCommonToponyms = commonToponyms => CommonToponym.bulkCreate(comm export const updateCommonToponyms = commonToponyms => { const bulkOperations = commonToponyms.map(commonToponym => - CommonToponym.update(commonToponym, {where: {id: commonToponym.id}}) + CommonToponym.update({...commonToponym, isActive: true}, {where: {id: commonToponym.id}}) ) return Promise.all(bulkOperations) } @@ -34,7 +34,7 @@ export const patchCommonToponyms = async commonToponyms => { const {meta, ...commonToponymRest} = commonToponym const commonToponymID = commonToponym.id const commonToponymDB = await CommonToponym.findByPk(commonToponymID) - commonToponymDB.set(commonToponymRest) + commonToponymDB.set({...commonToponymRest, isActive: true}) commonToponymDB.meta = {...commonToponymDB.meta, ...meta} return commonToponymDB.save() }) @@ -42,9 +42,9 @@ export const patchCommonToponyms = async commonToponyms => { return Promise.all(bulkOperations) } -export const deleteCommonToponym = commonToponymID => CommonToponym.destroy({where: {id: commonToponymID}}) +export const deleteCommonToponym = commonToponymID => CommonToponym.update({isActive: false}, {where: {id: commonToponymID}}) -export const deleteCommonToponyms = commonToponymIDs => CommonToponym.destroy({where: {id: commonToponymIDs}}) +export const deleteCommonToponyms = commonToponymIDs => CommonToponym.update({isActive: false}, {where: {id: commonToponymIDs}}) export const getAllDistrictIDsFromCommonToponyms = async commonToponymIDs => { const commonToponyms = await CommonToponym.findAll({where: {id: commonToponymIDs}, attributes: ['districtID'], raw: true}) diff --git a/lib/api/common-toponym/utils.js b/lib/api/common-toponym/utils.js index b5038688..58f9003d 100644 --- a/lib/api/common-toponym/utils.js +++ b/lib/api/common-toponym/utils.js @@ -77,7 +77,7 @@ export const checkCommonToponymsRequest = async (commonToponyms, actionType) => export const getDeltaReport = async (commonToponymIDsWithHash, districtID) => { const commonToponymIDsWithHashMap = new Map(commonToponymIDsWithHash.map(({id, hash}) => [id, hash])) const allCommonToponymIDsWithHashFromDistrict = await getAllCommonToponymIDsWithHashFromDistrict(districtID) - const allCommonToponymIDsWithHashFromDistrictMap = new Map(allCommonToponymIDsWithHashFromDistrict.map(({id, hash}) => [id, hash])) + const allCommonToponymIDsWithHashFromDistrictMap = new Map(allCommonToponymIDsWithHashFromDistrict.map(({id, hash, isActive}) => [id, {hash, isActive}])) let idsToCreate = [] const idsToUpdate = [] @@ -85,7 +85,7 @@ export const getDeltaReport = async (commonToponymIDsWithHash, districtID) => { for (const [id, hash] of commonToponymIDsWithHashMap) { if (allCommonToponymIDsWithHashFromDistrictMap.has(id)) { - if (allCommonToponymIDsWithHashFromDistrictMap.get(id) !== hash) { + if (allCommonToponymIDsWithHashFromDistrictMap.get(id).hash !== hash || !allCommonToponymIDsWithHashFromDistrictMap.get(id).isActive) { idsToUpdate.push(id) } } else { @@ -94,7 +94,7 @@ export const getDeltaReport = async (commonToponymIDsWithHash, districtID) => { } for (const id of allCommonToponymIDsWithHashFromDistrictMap.keys()) { - if (!commonToponymIDsWithHashMap.has(id)) { + if (!commonToponymIDsWithHashMap.has(id) && allCommonToponymIDsWithHashFromDistrictMap.get(id).isActive) { idsToDelete.push(id) } } diff --git a/lib/api/common-toponym/utils.spec.js b/lib/api/common-toponym/utils.spec.js index 4e68528e..1e8e2b09 100644 --- a/lib/api/common-toponym/utils.spec.js +++ b/lib/api/common-toponym/utils.spec.js @@ -103,7 +103,7 @@ describe('checkCommonToponymsRequest', () => { }) it('Some unavailable district IDs on update', async () => { - const commonToponymsValidation = await checkCommonToponymsRequest(bddCommonToponymMock.map(commonToponym => ({...commonToponym, districtID: '00000000-0000-4fff-9fff-000000000003'})), 'update') + const commonToponymsValidation = await checkCommonToponymsRequest(bddCommonToponymMock.map(({isActive, ...commonToponymRest}) => ({...commonToponymRest, districtID: '00000000-0000-4fff-9fff-000000000003'})), 'update') const testSchema = await commonToponymsValidationSchema.isValid(commonToponymsValidation, {strict: true}) expect(testSchema).toBe(true) expect(commonToponymsValidation?.isValid).toBe(false) @@ -111,7 +111,7 @@ describe('checkCommonToponymsRequest', () => { }) it('Available commonToponyms on update', async () => { - const commonToponymsValidation = await checkCommonToponymsRequest(bddCommonToponymMock.map(commonToponym => ({...commonToponym, labels: [{isoCode: 'fra', value: 'Rue de la mouette'}]})), 'update') + const commonToponymsValidation = await checkCommonToponymsRequest(bddCommonToponymMock.map(({isActive, ...commonToponymRest}) => ({...commonToponymRest, labels: [{isoCode: 'fra', value: 'Rue de la mouette'}]})), 'update') const testSchema = await commonToponymsValidationSchema.isValid(commonToponymsValidation, {strict: true}) expect(testSchema).toBe(true) expect(commonToponymsValidation?.isValid).toBe(true) diff --git a/lib/api/consumers/export-to-exploitation-db-consumer.js b/lib/api/consumers/export-to-exploitation-db-consumer.js index ed300a7d..f79ef523 100644 --- a/lib/api/consumers/export-to-exploitation-db-consumer.js +++ b/lib/api/consumers/export-to-exploitation-db-consumer.js @@ -56,7 +56,7 @@ const EXPLOITATION_DB_COLLECTION_NAMES = { const commonToponymPageQuery = ` SELECT - CT.id, CT."districtID", CT.labels, CT.geometry, CT."updateDate", CT.meta, CT.range_validity, + CT.id, CT."districtID", CT.labels, CT.geometry, CT."updateDate", CT.meta, CT.range_validity, CT."isActive", ST_Centroid(ST_Collect(ST_SetSRID(ST_GeomFromGeoJSON((A.positions[1])->'geometry'), 4326))) AS centroid, ST_Transform(ST_Buffer(ST_Transform(ST_Envelope(ST_Collect(ST_SetSRID(ST_GeomFromGeoJSON((A.positions[1])->'geometry'), 4326))), 2154), :addressBboxBuffer, 'join=mitre endcap=square'), 4326) AS "addressBbox", ST_Transform(ST_Buffer(ST_Transform(ST_Envelope(ST_SetSRID(ST_GeomFromGeoJSON(CT.geometry), 4326)), 2154), :bboxBuffer, 'join=mitre endcap=square'), 4326) AS "bbox", @@ -67,9 +67,9 @@ const commonToponymPageQuery = ` LEFT JOIN ban.address AS A ON - CT.id = A."mainCommonToponymID" - OR CT.id = ANY(A."secondaryCommonToponymIDs") - WHERE CT."districtID" = :districtID + (CT.id = A."mainCommonToponymID" + OR CT.id = ANY(A."secondaryCommonToponymIDs")) AND A."isActive" = true + WHERE CT."districtID" = :districtID AND CT."isActive" = true GROUP BY CT.id ORDER BY CT.id ASC OFFSET :offset @@ -86,7 +86,7 @@ const addressPageQuery = ` ST_Transform(ST_Buffer(ST_Transform(ST_Envelope(ST_SetSRID(ST_GeomFromGeoJSON((A.positions[1])->'geometry'), 4326)), 2154), :bboxBuffer, 'join=mitre endcap=square'), 4326) AS bbox FROM ban.address AS A - WHERE A."districtID" = :districtID + WHERE A."districtID" = :districtID AND A."isActive" = true ORDER BY A.id ASC OFFSET :offset LIMIT :limit @@ -137,7 +137,10 @@ export default async function exportToExploitationDB({data}) { // CommonToponym // Count the total number of common toponyms and pages to process const totalCommonToponymRecords = await CommonToponym.count({ - where: {districtID}, + where: { + districtID, + isActive: true + }, transaction, }) @@ -175,7 +178,10 @@ export default async function exportToExploitationDB({data}) { // Address // Count the total number of addresses and pages to process const totalAddressRecords = await Address.count({ - where: {districtID}, + where: { + districtID, + isActive: true + }, transaction, }) const totalAddressPages = Math.ceil(totalAddressRecords / PAGE_SIZE) diff --git a/lib/api/district/models.js b/lib/api/district/models.js index b65a58e9..d1364446 100644 --- a/lib/api/district/models.js +++ b/lib/api/district/models.js @@ -9,7 +9,7 @@ export const getDistrictsFromCog = cog => District.findAll({where: {meta: {insee export const setDistricts = districts => District.bulkCreate(districts) export const updateDistricts = districts => { - const promises = districts.map(district => District.update(district, {where: {id: district.id}})) + const promises = districts.map(district => District.update({...district, isActive: true}, {where: {id: district.id}})) return Promise.all(promises) } @@ -19,7 +19,7 @@ export const patchDistricts = async districts => { const {meta, ...districtRest} = district const districtID = district.id const districtDB = await District.findByPk(districtID) - districtDB.set(districtRest) + districtDB.set({...districtRest, isActive: true}) districtDB.meta = {...districtDB.meta, ...meta} return districtDB.save() }) @@ -27,6 +27,6 @@ export const patchDistricts = async districts => { return Promise.all(bulkOperations) } -export const deleteDistrict = districtID => District.destroy({where: {id: districtID}}) +export const deleteDistrict = districtID => District.update({isActive: false}, {where: {id: districtID}}) -export const deleteDistricts = districtIDs => District.destroy({where: {id: districtIDs}}) +export const deleteDistricts = districtIDs => District.update({isActive: false}, {where: {id: districtIDs}}) diff --git a/lib/util/sequelize.js b/lib/util/sequelize.js index b688ea27..b65eb6e8 100644 --- a/lib/util/sequelize.js +++ b/lib/util/sequelize.js @@ -37,6 +37,11 @@ export const District = sequelize.define('District', { type: DataTypes.RANGE(DataTypes.DATE), allowNull: false, }, + isActive: { + type: DataTypes.BOOLEAN, + allowNull: false, + defaultValue: true, + }, }, { schema: 'ban', tableName: 'district', @@ -77,12 +82,12 @@ export const CommonToponym = sequelize.define('CommonToponym', { type: DataTypes.RANGE(DataTypes.DATE), allowNull: false, }, + isActive: { + type: DataTypes.BOOLEAN, + allowNull: false, + defaultValue: true, + }, }, { - indexes: [ - { - fields: ['districtID'], - } - ], schema: 'ban', tableName: 'common_toponym', timestamps: false @@ -145,21 +150,12 @@ export const Address = sequelize.define('Address', { type: DataTypes.RANGE(DataTypes.DATE), allowNull: false, }, + isActive: { + type: DataTypes.BOOLEAN, + allowNull: false, + defaultValue: true, + }, }, { - indexes: [ - { - fields: ['mainCommonToponymID'], - }, - { - fields: ['secondaryCommonToponymIDs'], - }, - { - fields: ['districtID'], - }, - { - fields: ['certified'], - }, - ], schema: 'ban', tableName: 'address', timestamps: false