From 14532afbaa152f234a37b5705f765af646ec3c2f Mon Sep 17 00:00:00 2001 From: Jean-Pascal MILCENT Date: Fri, 5 Jul 2024 15:28:06 +0200 Subject: [PATCH] refactor(migrate_taxref): refactor all SQL files --- .../0.1_generate_tmp_bib_noms_copy.sql | 59 +- ...ection_repercussion_disparition_cd_nom.sql | 89 +-- .../1.1_taxref_changes_detections.sql | 143 ++-- ..._taxref_changes_detections_cas_actions.sql | 330 +++++---- ...ges_corrections_post_detections.sql.sample | 6 +- .../0_taxref_import_data.sql | 43 +- .../3.2_alter_taxref_data.sql | 641 +++++++++++------- 7 files changed, 783 insertions(+), 528 deletions(-) diff --git a/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/0.1_generate_tmp_bib_noms_copy.sql b/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/0.1_generate_tmp_bib_noms_copy.sql index f85264f58..6b8279697 100644 --- a/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/0.1_generate_tmp_bib_noms_copy.sql +++ b/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/0.1_generate_tmp_bib_noms_copy.sql @@ -1,4 +1,6 @@ -DROP TABLE IF EXISTS taxonomie.tmp_bib_noms_copy; +-- ---------------------------------------------------------------------- +-- Create a copy of bib_noms table +DROP TABLE IF EXISTS taxonomie.tmp_bib_noms_copy ; CREATE TABLE taxonomie.tmp_bib_noms_copy ( id_nom serial PRIMARY KEY, @@ -12,12 +14,9 @@ CREATE TABLE taxonomie.tmp_bib_noms_copy ( tmp_import boolean ); -INSERT INTO taxonomie.tmp_bib_noms_copy ( - id_nom, cd_nom, cd_ref, nom_francais, comments -) -SELECT id_nom, cd_nom, cd_ref, nom_francais, comments -FROM taxonomie.bib_noms; - +INSERT INTO taxonomie.tmp_bib_noms_copy (id_nom, cd_nom, cd_ref, nom_francais, comments) + SELECT id_nom, cd_nom, cd_ref, nom_francais, comments + FROM taxonomie.bib_noms ; SELECT setval( 'taxonomie.tmp_bib_noms_copy_id_nom_seq', @@ -25,27 +24,31 @@ SELECT setval( true ); ---- ajout Nicolas Imbert -create index IF NOT EXISTS i_tmp_cdnom_disparu_cd_nom on taxonomie.cdnom_disparu (cd_nom); +-- ---------------------------------------------------------------------- +-- CASE 1 - Deleted cd_nom with replacement ---- CAS 1 - cd_nom de remplacement à utiliser. -UPDATE taxonomie.tmp_bib_noms_copy n SET deleted = true , - commentaire_disparition = raison_suppression || COALESCE(' nouveau cd_nom :' || a.cd_nom_remplacement, ''), - cd_nom_remplacement = a.cd_nom_remplacement +-- Update tmp_bib_noms_copy fields about deleted cd_nom +UPDATE taxonomie.tmp_bib_noms_copy AS nc SET + deleted = true, + commentaire_disparition = ( + a.raison_suppression || COALESCE(' nouveau cd_nom :' || a.cd_nom_remplacement, '') + ), + cd_nom_remplacement = a.cd_nom_remplacement FROM ( - SELECT d.* - FROM taxonomie.bib_noms n - JOIN taxonomie.cdnom_disparu d - ON n.cd_nom = d.cd_nom -) a -WHERE n.cd_nom = a.cd_nom; - -------------- Cas avec cd_nom de remplacement --- Ajout du cd_nom de remplacement quand il n'existait pas dans bib_noms -INSERT INTO taxonomie.tmp_bib_noms_copy(cd_nom, cd_ref, nom_francais, tmp_import) -SELECT d.cd_nom_remplacement, n.cd_ref, n.nom_francais, true -FROM taxonomie.tmp_bib_noms_copy n -JOIN taxonomie.cdnom_disparu d ON n.cd_nom = d.cd_nom -WHERE NOT n.cd_nom_remplacement IS NULL -ON CONFLICT DO NOTHING; + SELECT d.* + FROM taxonomie.bib_noms AS n + JOIN taxonomie.cdnom_disparu AS d + ON n.cd_nom = d.cd_nom +) AS a +WHERE nc.cd_nom = a.cd_nom ; + +-- Add replacement cd_nom when not already exists in tmp_bib_noms_copy +-- TODO: check if this query is mandatory and not a duplicate of previous queries ! +INSERT INTO taxonomie.tmp_bib_noms_copy (cd_nom, cd_ref, nom_francais, tmp_import) + SELECT d.cd_nom_remplacement, nc.cd_ref, nc.nom_francais, true + FROM taxonomie.tmp_bib_noms_copy AS nc + JOIN taxonomie.cdnom_disparu AS d + ON nc.cd_nom = d.cd_nom + WHERE nc.cd_nom_remplacement IS NOT NULL +ON CONFLICT DO NOTHING ; diff --git a/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/0.2_taxref_detection_repercussion_disparition_cd_nom.sql b/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/0.2_taxref_detection_repercussion_disparition_cd_nom.sql index c87780045..7f190dc91 100755 --- a/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/0.2_taxref_detection_repercussion_disparition_cd_nom.sql +++ b/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/0.2_taxref_detection_repercussion_disparition_cd_nom.sql @@ -1,48 +1,55 @@ +-- ---------------------------------------------------------------------- +-- Create temporary taxref schema CREATE SCHEMA IF NOT EXISTS tmp_taxref_changes; - +-- ---------------------------------------------------------------------- +-- Add the cd_nom dependency search function DROP FUNCTION IF EXISTS public.deps_test_fk_dependencies_cd_nom(); CREATE OR REPLACE FUNCTION public.deps_test_fk_dependencies_cd_nom() - RETURNS void AS -$BODY$ -declare - v_curr record; -begin - DROP TABLE IF EXISTS tmp_taxref_changes.dps_fk_cd_nom; - CREATE TABLE tmp_taxref_changes.dps_fk_cd_nom ( - cd_nom int, - table_name varchar(250) - ); - FOR v_curr IN ( - SELECT - 'SELECT DISTINCT d.' || kcu.column_name || ' as cd_nom, ''' || tc.table_schema || '.' || tc.table_name || ''' as table - FROM ' || tc.table_schema || '.' || tc.table_name || ' d - LEFT OUTER JOIN taxonomie.import_taxref it ON it.cd_nom = d.' || kcu.column_name || ' - WHERE it.cd_nom IS NULL AND NOT d.' || kcu.column_name || ' IS NULL' as select, - tc.table_schema, - tc.table_name - FROM information_schema.table_constraints tc - JOIN information_schema.key_column_usage kcu - ON tc.constraint_catalog = kcu.constraint_catalog - AND tc.constraint_schema = kcu.constraint_schema - AND tc.constraint_name = kcu.constraint_name - JOIN information_schema.referential_constraints rc - ON tc.constraint_catalog = rc.constraint_catalog - AND tc.constraint_schema = rc.constraint_schema - AND tc.constraint_name = rc.constraint_name - JOIN information_schema.constraint_column_usage ccu - ON rc.unique_constraint_catalog = ccu.constraint_catalog - AND rc.unique_constraint_schema = ccu.constraint_schema - AND rc.unique_constraint_name = ccu.constraint_name - WHERE lower(tc.constraint_type) in ('foreign key') - AND ccu.column_name = 'cd_nom' OR ccu.column_name = 'cd_ref' - ) - LOOP - EXECUTE 'INSERT INTO tmp_taxref_changes.dps_fk_cd_nom ' || v_curr.select; - END LOOP; -END + RETURNS void AS $BODY$ - LANGUAGE plpgsql VOLATILE - COST 100; + DECLARE + v_curr record; + BEGIN + DROP TABLE IF EXISTS tmp_taxref_changes.dps_fk_cd_nom; + CREATE TABLE tmp_taxref_changes.dps_fk_cd_nom ( + cd_nom int, + table_name varchar(250) + ); + FOR v_curr IN ( + SELECT + 'SELECT DISTINCT + d.' || kcu.column_name || ' AS cd_nom, ''' || + tc.table_schema || '.' || tc.table_name || ''' AS table + FROM ' || tc.table_schema || '.' || tc.table_name || ' AS d + LEFT JOIN taxonomie.import_taxref AS it + ON it.cd_nom = d.' || kcu.column_name || ' + WHERE it.cd_nom IS NULL + AND d.' || kcu.column_name || ' IS NOT NULL ' AS SELECT, + tc.table_schema, + tc.table_name + FROM information_schema.table_constraints tc + JOIN information_schema.key_column_usage kcu + ON tc.constraint_catalog = kcu.constraint_catalog + AND tc.constraint_schema = kcu.constraint_schema + AND tc.constraint_name = kcu.constraint_name + JOIN information_schema.referential_constraints rc + ON tc.constraint_catalog = rc.constraint_catalog + AND tc.constraint_schema = rc.constraint_schema + AND tc.constraint_name = rc.constraint_name + JOIN information_schema.constraint_column_usage ccu + ON rc.unique_constraint_catalog = ccu.constraint_catalog + AND rc.unique_constraint_schema = ccu.constraint_schema + AND rc.unique_constraint_name = ccu.constraint_name + WHERE lower(tc.constraint_type) IN ('foreign key') + AND ccu.column_name = 'cd_nom' OR ccu.column_name = 'cd_ref' + ) + LOOP + EXECUTE 'INSERT INTO tmp_taxref_changes.dps_fk_cd_nom ' || v_curr.select; + END LOOP; + END +$BODY$ +LANGUAGE plpgsql VOLATILE +COST 100 ; diff --git a/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/1.1_taxref_changes_detections.sql b/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/1.1_taxref_changes_detections.sql index 7f37eead6..6bae898bf 100755 --- a/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/1.1_taxref_changes_detections.sql +++ b/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/1.1_taxref_changes_detections.sql @@ -1,59 +1,98 @@ ----- ################################################################################# ----- ################################################################################# ----- Répercussion des changements taxonomiques ----- ################################################################################# ----- ################################################################################# - +-- ---------------------------------------------------------------------- +-- Create temporary taxref schema CREATE SCHEMA IF NOT EXISTS tmp_taxref_changes; + +-- ---------------------------------------------------------------------- +-- Intialize comp_grap table to store impacts of taxonomic changes + DROP TABLE IF EXISTS tmp_taxref_changes.comp_grap ; +-- TODO: why not used import_taxref for array_agg in "grappe_final" !? CREATE TABLE tmp_taxref_changes.comp_grap AS -WITH grappe_init AS ( - SELECT distinct b.cd_ref , array_agg(cd_nom ORDER BY cd_nom) as array_agg, count(DISTINCT cd_nom) - FROM taxonomie.tmp_bib_noms_copy b - WHERE NOT deleted = true and cd_nom is not null - GROUP BY cd_ref -), -grappe_final AS ( - SELECT distinct t.cd_ref , array_agg(b.cd_nom ORDER BY b.cd_nom) as array_agg, count(DISTINCT b.cd_nom) - FROM taxonomie.tmp_bib_noms_copy b - JOIN taxonomie.import_taxref t - ON b.cd_nom = t.cd_nom - WHERE NOT deleted = true and b.cd_nom is not null - GROUP BY t.cd_ref -), -attribs AS ( - SELECT DISTINCT a.cd_ref, array_agg(id_attribut) as att_list, count(DISTINCT id_attribut) as att_nb - FROM taxonomie.cor_taxon_attribut a - WHERE NOT valeur_attribut ='{}' AND NOT valeur_attribut ='' - GROUP BY a.cd_ref -), -media AS ( - SELECT DISTINCT cd_ref, count(id_media) as media_nb - FROM taxonomie.t_medias - GROUP BY cd_ref -), -init_cdnom as ( - select distinct t1.cd_ref, t2.cd_nom, t1.array_agg, t1.count - from grappe_init t1, taxonomie.tmp_bib_noms_copy t2 - where t1.cd_ref = t2.cd_ref and NOT t2.deleted = true and t2.cd_nom is not null - order by 1,2), -final_cdnom as ( - select distinct t3.cd_ref, t2.cd_nom, t1.array_agg, t1.count - from grappe_final t1, taxonomie.tmp_bib_noms_copy t2, taxonomie.import_taxref t3 - where t1.cd_ref = t3.cd_ref and NOT t2.deleted = true and t2.cd_nom is not null - and t2.cd_nom = t3.cd_nom - order by 1,2) -SELECT distinct i.cd_ref as i_cd_ref, i.array_agg as i_array_agg, i.count as i_count, - f.cd_ref as f_cd_ref, f.array_agg as f_array_agg, f.count as f_count, - att_list, att_nb, media_nb -FROM init_cdnom i -LEFT OUTER JOIN final_cdnom f ON i.cd_nom = f.cd_nom -LEFT OUTER JOIN attribs a ON i.cd_ref = a.cd_ref -LEFT OUTER JOIN media m ON i.cd_ref = m.cd_ref; + WITH grappe_init AS ( + SELECT DISTINCT + cd_ref, + array_agg(cd_nom ORDER BY cd_nom) AS array_agg, + count(DISTINCT cd_nom) + FROM taxonomie.tmp_bib_noms_copy + WHERE deleted != true + AND cd_nom IS NOT NULL + GROUP BY cd_ref + ), + grappe_final AS ( + SELECT DISTINCT + it.cd_ref, + array_agg(n.cd_nom ORDER BY n.cd_nom) AS array_agg, + count(DISTINCT n.cd_nom) + FROM taxonomie.tmp_bib_noms_copy AS n + JOIN taxonomie.import_taxref AS it + ON n.cd_nom = it.cd_nom + WHERE n.deleted != true + AND n.cd_nom IS NOT NULL + GROUP BY it.cd_ref + ), + attribs AS ( + SELECT DISTINCT + cd_ref, + array_agg(id_attribut) AS att_list, + count(DISTINCT id_attribut) AS att_nb + FROM taxonomie.cor_taxon_attribut + WHERE valeur_attribut !='{}' + AND valeur_attribut != '' + GROUP BY cd_ref + ), + media AS ( + SELECT DISTINCT + cd_ref, + count(id_media) AS media_nb + FROM taxonomie.t_medias + GROUP BY cd_ref + ), + init_cdnom AS ( + SELECT DISTINCT + gi.cd_ref, + n.cd_nom, + gi.array_agg, + gi.count + FROM grappe_init AS gi, taxonomie.tmp_bib_noms_copy AS n + WHERE gi.cd_ref = n.cd_ref + AND n.deleted != true + AND n.cd_nom IS NOT NULL + ORDER BY 1, 2 + ), + final_cdnom AS ( + SELECT DISTINCT + it.cd_ref, + n.cd_nom, + gf.array_agg, + gf.count + FROM grappe_final AS gf, taxonomie.tmp_bib_noms_copy AS n, taxonomie.import_taxref AS it + WHERE gf.cd_ref = it.cd_ref + AND n.deleted != true + AND n.cd_nom IS NOT NULL + AND n.cd_nom = it.cd_nom + ORDER BY 1, 2 + ) + SELECT DISTINCT + i.cd_ref AS i_cd_ref, + i.array_agg AS i_array_agg, + i.count AS i_count, + f.cd_ref AS f_cd_ref, + f.array_agg AS f_array_agg, + f.count AS f_count, + att_list, + att_nb, + media_nb + FROM init_cdnom AS i + LEFT JOIN final_cdnom AS f + ON i.cd_nom = f.cd_nom + LEFT JOIN attribs AS a + ON i.cd_ref = a.cd_ref + LEFT JOIN media AS m + ON i.cd_ref = m.cd_ref ; -ALTER TABLE tmp_taxref_changes.comp_grap ADD grappe_change varchar(250); -ALTER TABLE tmp_taxref_changes.comp_grap ADD action varchar(250); -ALTER TABLE tmp_taxref_changes.comp_grap ADD cas varchar(50); \ No newline at end of file +ALTER TABLE tmp_taxref_changes.comp_grap ADD grappe_change varchar(250) ; +ALTER TABLE tmp_taxref_changes.comp_grap ADD "action" varchar(250) ; +ALTER TABLE tmp_taxref_changes.comp_grap ADD cas varchar(50) ; \ No newline at end of file diff --git a/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/1.2_taxref_changes_detections_cas_actions.sql b/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/1.2_taxref_changes_detections_cas_actions.sql index 94e8003df..ec9523b4d 100755 --- a/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/1.2_taxref_changes_detections_cas_actions.sql +++ b/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/1.2_taxref_changes_detections_cas_actions.sql @@ -1,172 +1,252 @@ +-- ---------------------------------------------------------------------- +-- Add impacts of taxonomic changes in comp_grap table ----- Type de changements +-- ---------------------------------------------------------------------- +-- Reset cd_nom cluster change UPDATE tmp_taxref_changes.comp_grap SET grappe_change = NULL; -UPDATE tmp_taxref_changes.comp_grap SET grappe_change = 'no change' -WHERE i_array_agg = f_array_agg AND i_cd_ref = f_cd_ref; -UPDATE tmp_taxref_changes.comp_grap SET grappe_change = 'cas1' -WHERE i_array_agg = f_array_agg AND NOT i_cd_ref = f_cd_ref; +-- ---------------------------------------------------------------------- +-- Set no change +UPDATE tmp_taxref_changes.comp_grap SET + grappe_change = 'no change' +WHERE i_array_agg = f_array_agg + AND i_cd_ref = f_cd_ref; ---Cas 2 i_array_agg = f_array_agg - cd_nom(s) -UPDATE tmp_taxref_changes.comp_grap SET grappe_change = COALESCE(grappe_change|| ', ', '') || 'cas2' -WHERE i_array_agg @> f_array_agg AND NOT i_array_agg = f_array_agg ; +-- ---------------------------------------------------------------------- +-- Set "case 1" : same cd_nom clusters but different cd_ref +UPDATE tmp_taxref_changes.comp_grap SET + grappe_change = 'cas1' +WHERE i_array_agg = f_array_agg + AND i_cd_ref != f_cd_ref ; ---Cas 3 Quand 2 grappes initiales en forme une troisième +-- ---------------------------------------------------------------------- +-- Set "case 2" : the new cd_nom cluster not contains all initial cd_nom +-- Formula : i_array_agg = f_array_agg - cd_nom(s) +UPDATE tmp_taxref_changes.comp_grap SET + grappe_change = COALESCE(grappe_change || ', ', '') || 'cas2' +WHERE i_array_agg @> f_array_agg + AND i_array_agg != f_array_agg ; + + +-- ---------------------------------------------------------------------- +-- Set "case 3" : when 2 initial clusters form a third WITH comp AS ( - SELECT a.i_cd_ref ,a.f_array_agg, a.i_array_agg AS a_i_array_agg, b.i_array_agg AS b_i_array_agg, + SELECT + a.i_cd_ref, + a.f_array_agg, + a.i_array_agg AS a_i_array_agg, + b.i_array_agg AS b_i_array_agg, row_number() OVER (ORDER BY a.i_cd_ref ) AS tmp_id - FROM tmp_taxref_changes.comp_grap a, tmp_taxref_changes.comp_grap b - WHERE NOT a.i_cd_ref = b.i_cd_ref - AND a.f_array_agg = b.f_array_agg -), unnest_grap AS ( - SELECT UNNEST (a_i_array_agg) AS cd , tmp_id + FROM tmp_taxref_changes.comp_grap AS a, tmp_taxref_changes.comp_grap AS b + WHERE a.i_cd_ref != b.i_cd_ref + AND a.f_array_agg = b.f_array_agg +), +unnest_grap AS ( + SELECT unnest(a_i_array_agg) AS cd, tmp_id FROM comp UNION - SELECT UNNEST (b_i_array_agg) cd, tmp_id + SELECT unnest(b_i_array_agg) AS cd, tmp_id FROM comp -), agg_grap AS ( - SELECT array_agg(cd ORDER BY cd) AS cd_agg, tmp_id +), +agg_grap AS ( + SELECT + array_agg(cd ORDER BY cd) AS cd_agg, + tmp_id FROM unnest_grap GROUP BY tmp_id ) -UPDATE tmp_taxref_changes.comp_grap SET grappe_change = COALESCE(grappe_change|| ', ', '') || 'cas3: 2 grappes' +UPDATE tmp_taxref_changes.comp_grap SET + grappe_change = COALESCE(grappe_change || ', ', '') || 'cas3: 2 grappes' WHERE i_cd_ref IN ( SELECT i_cd_ref FROM agg_grap - JOIN comp - ON comp.tmp_id = agg_grap.tmp_id + JOIN comp + ON comp.tmp_id = agg_grap.tmp_id WHERE cd_agg = f_array_agg ); -UPDATE tmp_taxref_changes.comp_grap c SET grappe_change = COALESCE(grappe_change|| ', ', '') || 'cas3: f_cd_ref' +UPDATE tmp_taxref_changes.comp_grap AS c SET + grappe_change = COALESCE(grappe_change || ', ', '') || 'cas3: f_cd_ref' WHERE i_cd_ref IN ( - SELECT i_cd_ref - FROM tmp_taxref_changes.comp_grap - WHERE f_cd_ref IN (SELECT f_cd_ref FROM tmp_taxref_changes.comp_grap GROUP BY f_cd_ref HAVING count(*) >1 ) + SELECT i_cd_ref + FROM tmp_taxref_changes.comp_grap + WHERE f_cd_ref IN ( + SELECT f_cd_ref + FROM tmp_taxref_changes.comp_grap + GROUP BY f_cd_ref + HAVING count(*) > 1 + ) ); +UPDATE tmp_taxref_changes.comp_grap AS c SET + cas = 'update cd_ref' +WHERE grappe_change ILIKE '%cas1%' ; -UPDATE tmp_taxref_changes.comp_grap c SET cas = 'update cd_ref' -WHERE grappe_change ilike '%cas1%'; +-- ---------------------------------------------------------------------- +-- Case with 2 clusters of cd_nom which merge +UPDATE tmp_taxref_changes.comp_grap AS c SET + cas = 'merge' +WHERE grappe_change ILIKE '%cas3: 2 gr%' ; --- Cas avec 2 grappes de cd_nom qui fusionnent -UPDATE tmp_taxref_changes.comp_grap c SET cas = 'merge' -WHERE grappe_change ilike '%cas3: 2 gr%'; --- Cas des merges avec plus de 2 grappes de cd_noms +-- ---------------------------------------------------------------------- +-- Case of merges with more than 2 clusters of cd_noms WITH d AS ( - SELECT c.f_cd_ref, array_agg(DISTINCT i_array_agg) i_array_agg, array_agg(DISTINCT f_array_agg) f_array_agg + SELECT + c.f_cd_ref, + array_agg(DISTINCT i_array_agg) AS i_array_agg, + array_agg(DISTINCT f_array_agg) AS f_array_agg FROM ( - SELECT f_cd_ref, UNNEST(i_array_agg) AS i_array_agg - FROM tmp_taxref_changes.comp_grap c - WHERE grappe_change ilike '%cas3%' and cas IS NULL - ORDER BY f_cd_ref, UNNEST(i_array_agg) - ) c - JOIN ( - SELECT f_cd_ref, UNNEST(c.f_array_agg) AS f_array_agg - FROM tmp_taxref_changes.comp_grap c - WHERE grappe_change ilike '%cas3%' and cas IS NULL - ORDER BY f_cd_ref, UNNEST(c.f_array_agg) - ) f - ON c.f_cd_ref = f.f_cd_ref + SELECT + f_cd_ref, + UNNEST(i_array_agg) AS i_array_agg + FROM tmp_taxref_changes.comp_grap + WHERE grappe_change ILIKE '%cas3%' + AND cas IS NULL + ORDER BY f_cd_ref, UNNEST(i_array_agg) + ) AS c + JOIN ( + SELECT + f_cd_ref, + UNNEST(f_array_agg) AS f_array_agg + FROM tmp_taxref_changes.comp_grap + WHERE grappe_change ILIKE '%cas3%' + AND cas IS NULL + ORDER BY f_cd_ref, UNNEST(f_array_agg) + ) AS f + ON c.f_cd_ref = f.f_cd_ref GROUP BY c.f_cd_ref ) -UPDATE tmp_taxref_changes.comp_grap c SET cas = 'merge' +UPDATE tmp_taxref_changes.comp_grap AS c SET + cas = 'merge' FROM d -WHERE d.f_cd_ref = c.f_cd_ref; - - -UPDATE tmp_taxref_changes.comp_grap c SET cas = 'split' -WHERE grappe_change = 'cas2'; - -UPDATE tmp_taxref_changes.comp_grap c SET cas = 'split and merge' -WHERE grappe_change ilike '%cas3%' and cas IS NULL; - +WHERE d.f_cd_ref = c.f_cd_ref ; +UPDATE tmp_taxref_changes.comp_grap SET + cas = 'split' +WHERE grappe_change = 'cas2' ; ----- ######### Actions qui vont être réalisées lors de la mise à jour de taxref +UPDATE tmp_taxref_changes.comp_grap SET + cas = 'split and merge' +WHERE grappe_change ILIKE '%cas3%' + AND cas IS NULL ; -UPDATE tmp_taxref_changes.comp_grap c SET action = NULL; +-- ---------------------------------------------------------------------- +-- Medium & attributs: reset fields action, grappe_change and cas for analyse +UPDATE tmp_taxref_changes.comp_grap SET + action = NULL ; -UPDATE tmp_taxref_changes.comp_grap c SET action = 'no changes' -WHERE grappe_change = 'no change'; +UPDATE tmp_taxref_changes.comp_grap SET + action = 'no changes' +WHERE grappe_change = 'no change' ; -UPDATE tmp_taxref_changes.comp_grap c SET action = 'Update cd_ref no changes for attributes and medium' -WHERE cas = 'update cd_ref'; +UPDATE tmp_taxref_changes.comp_grap SET + action = 'Update cd_ref no changes for attributes and medium' +WHERE cas = 'update cd_ref' ; --- Split -UPDATE tmp_taxref_changes.comp_grap c SET action = 'Keep attributes and medium' -WHERE cas = 'split' AND i_cd_ref = f_cd_ref; +-- ---------------------------------------------------------------------- +-- Medium & attributs: case "split" +UPDATE tmp_taxref_changes.comp_grap SET + action = 'Keep attributes and medium' +WHERE cas = 'split' + AND i_cd_ref = f_cd_ref ; -UPDATE tmp_taxref_changes.comp_grap c SET action = 'Loose attributes and medium now attach to ' || COALESCE(cd_ref_attr::varchar, 'No one') +UPDATE tmp_taxref_changes.comp_grap AS c SET + action = 'Loose attributes and medium now attach to ' || COALESCE(cd_ref_attr::varchar, 'No one') FROM ( - SELECT l.*, k.i_cd_ref as cd_ref_attr - FROM ( - SELECT * - FROM tmp_taxref_changes.comp_grap - WHERE cas = 'split' AND NOT i_cd_ref = f_cd_ref - ) l - LEFT OUTER JOIN ( - SELECT * - FROM tmp_taxref_changes.comp_grap - WHERE cas = 'split' AND i_cd_ref = f_cd_ref - ) k - ON k.i_cd_ref = l.i_cd_ref -) a -WHERE a.i_cd_ref = c.i_cd_ref AND a.f_cd_ref = c.f_cd_ref; - - --- Merge detection des conflits pour les attributs + SELECT + l.*, + k.i_cd_ref AS cd_ref_attr + FROM ( + SELECT * + FROM tmp_taxref_changes.comp_grap + WHERE cas = 'split' + AND i_cd_ref != f_cd_ref + ) AS l + LEFT JOIN ( + SELECT * + FROM tmp_taxref_changes.comp_grap + WHERE cas = 'split' + AND i_cd_ref = f_cd_ref + ) AS k + ON k.i_cd_ref = l.i_cd_ref +) AS a +WHERE a.i_cd_ref = c.i_cd_ref + AND a.f_cd_ref = c.f_cd_ref ; + + +-- ---------------------------------------------------------------------- +-- Medium & attributs: case "merge", detect conflicts for attributs WITH atts AS ( - SELECT DISTINCT * - FROM taxonomie.cor_taxon_attribut a - JOIN tmp_taxref_changes.comp_grap c - ON a.cd_ref = c.i_cd_ref - WHERE NOT valeur_attribut ='{}' AND NOT valeur_attribut ='' - AND cas = 'merge' -) , conflict_atts AS ( - SELECT f_cd_ref, id_attribut, count(DISTINCT valeur_attribut) - FROM atts - GROUP BY f_cd_ref, id_attribut - HAVING count(DISTINCT valeur_attribut) >1 -) , conflict_atts_text AS ( - SELECT f_cd_ref, string_agg(nom_attribut::varchar, ', ') as atts - FROM conflict_atts c - JOIN taxonomie.bib_attributs a - ON a.id_attribut = c.id_attribut - GROUP BY f_cd_ref + SELECT DISTINCT * + FROM taxonomie.cor_taxon_attribut AS a + JOIN tmp_taxref_changes.comp_grap AS c + ON a.cd_ref = c.i_cd_ref + WHERE valeur_attribut != '{}' + AND valeur_attribut != '' + AND cas = 'merge' +), +conflict_atts AS ( + SELECT + f_cd_ref, + id_attribut, + count(DISTINCT valeur_attribut) + FROM atts + GROUP BY f_cd_ref, id_attribut + HAVING count(DISTINCT valeur_attribut) > 1 +), +conflict_atts_text AS ( + SELECT + f_cd_ref, + string_agg(nom_attribut::varchar, ', ') AS atts + FROM conflict_atts AS c + JOIN taxonomie.bib_attributs AS a + ON a.id_attribut = c.id_attribut + GROUP BY f_cd_ref ) -UPDATE tmp_taxref_changes.comp_grap c SET action = 'Conflicts with attributes : ' || atts -FROM conflict_atts_text a -WHERE a.f_cd_ref = c.f_cd_ref AND cas = 'merge'; - -UPDATE tmp_taxref_changes.comp_grap c SET action = 'Merge attributes if exists' -WHERE cas = 'merge' AND action IS NULL; - --- Split and merge - -UPDATE tmp_taxref_changes.comp_grap c SET action = 'Keep attributes and medium' -WHERE cas = 'split and merge' AND i_cd_ref = f_cd_ref; - -UPDATE tmp_taxref_changes.comp_grap c SET action = 'Loose attributes and medium now attach to ' || COALESCE(cd_ref_attr::varchar, 'No one') +UPDATE tmp_taxref_changes.comp_grap AS c SET + "action" = 'Conflicts with attributes : ' || atts +FROM conflict_atts_text AS a +WHERE a.f_cd_ref = c.f_cd_ref + AND cas = 'merge' ; + +UPDATE tmp_taxref_changes.comp_grap SET + "action" = 'Merge attributes if exists' +WHERE cas = 'merge' + AND "action" IS NULL ; + + +-- ---------------------------------------------------------------------- +-- Medium & attributs: case "split and merge" +UPDATE tmp_taxref_changes.comp_grap AS c SET + "action" = 'Keep attributes and medium' +WHERE cas = 'split and merge' + AND i_cd_ref = f_cd_ref ; + +UPDATE tmp_taxref_changes.comp_grap AS c SET + "action" = 'Loose attributes and medium now attach to ' || COALESCE(cd_ref_attr::varchar, 'No one') FROM ( - SELECT l.*, k.i_cd_ref as cd_ref_attr - FROM ( - SELECT * - FROM tmp_taxref_changes.comp_grap - WHERE cas = 'split and merge' AND NOT i_cd_ref = f_cd_ref - ) l - LEFT OUTER JOIN ( - SELECT * - FROM tmp_taxref_changes.comp_grap - WHERE cas = 'split and merge' AND i_cd_ref = f_cd_ref - ) k - ON k.i_cd_ref = l.i_cd_ref -) a -WHERE a.i_cd_ref = c.i_cd_ref AND a.f_cd_ref = c.f_cd_ref; + SELECT + l.*, + k.i_cd_ref AS cd_ref_attr + FROM ( + SELECT * + FROM tmp_taxref_changes.comp_grap + WHERE cas = 'split and merge' + AND i_cd_ref != f_cd_ref + ) AS l + LEFT JOIN ( + SELECT * + FROM tmp_taxref_changes.comp_grap + WHERE cas = 'split and merge' AND i_cd_ref = f_cd_ref + ) AS k + ON k.i_cd_ref = l.i_cd_ref +) AS a +WHERE a.i_cd_ref = c.i_cd_ref + AND a.f_cd_ref = c.f_cd_ref ; diff --git a/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/2.2_taxref_changes_corrections_post_detections.sql.sample b/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/2.2_taxref_changes_corrections_post_detections.sql.sample index 94ec8e0be..e203ea7ec 100755 --- a/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/2.2_taxref_changes_corrections_post_detections.sql.sample +++ b/apptax/taxonomie/commands/migrate_taxref/data/changes_detection/2.2_taxref_changes_corrections_post_detections.sql.sample @@ -1,4 +1,6 @@ --- Exemple pour le pnc -UPDATE tmp_taxref_changes.comp_grap SET action = 'Duplicate attibutes; Duplicate medium' -WHERE action ilike 'Loose%' AND f_cd_ref IN (608354,641669); \ No newline at end of file +UPDATE tmp_taxref_changes.comp_grap SET + action = 'Duplicate attibutes; Duplicate medium' +WHERE action ILIKE 'Loose%' + AND f_cd_ref IN (608354,641669) ; \ No newline at end of file diff --git a/apptax/taxonomie/commands/migrate_taxref/data/specific_taxref_v15_v16/0_taxref_import_data.sql b/apptax/taxonomie/commands/migrate_taxref/data/specific_taxref_v15_v16/0_taxref_import_data.sql index 63c37833d..2a470d4ea 100644 --- a/apptax/taxonomie/commands/migrate_taxref/data/specific_taxref_v15_v16/0_taxref_import_data.sql +++ b/apptax/taxonomie/commands/migrate_taxref/data/specific_taxref_v15_v16/0_taxref_import_data.sql @@ -1,16 +1,14 @@ --- Créer la table import_taxref - - +-- ---------------------------------------------------------------------- +-- Crate import_taxref table DROP TABLE IF EXISTS taxonomie.import_taxref; -CREATE TABLE taxonomie.import_taxref -( +CREATE TABLE taxonomie.import_taxref ( regne character varying(20), phylum character varying(50), classe character varying(50), ordre character varying(50), famille character varying(50), - SOUS_FAMILLE character varying(50), - TRIBU character varying(50), + sous_famille character varying(50), + tribu character varying(50), group1_inpn character varying(50), group2_inpn character varying(50), group3_inpn character varying(50), @@ -37,33 +35,38 @@ CREATE TABLE taxonomie.import_taxref may character varying(10), epa character varying(10), reu character varying(10), - SA character varying(10), - TA character varying(10), + sa character varying(10), + ta character varying(10), taaf character varying(10), pf character varying(10), nc character varying(10), wf character varying(10), cli character varying(10), - url text + "url" text ); ALTER TABLE taxonomie.import_taxref ADD CONSTRAINT pk_import_taxref PRIMARY KEY (cd_nom); --- Créer la table cdnom_disparus +-- ---------------------------------------------------------------------- +-- Create cdnom_disparus table DROP TABLE IF EXISTS taxonomie.cdnom_disparu; CREATE TABLE taxonomie.cdnom_disparu ( - CD_NOM int, - PLUS_RECENTE_DIFFUSION character varying(50), - CD_NOM_REMPLACEMENT int, - CD_RAISON_SUPPRESSION int, - RAISON_SUPPRESSION text + cd_nom int, + plus_recente_diffusion character varying(50), + cd_nom_remplacement int, + cd_raison_suppression int, + raison_suppression text ); +-- Added by Nicolas Imbert +CREATE INDEX IF NOT EXISTS i_tmp_cdnom_disparu_cd_nom ON taxonomie.cdnom_disparu (cd_nom); +-- ---------------------------------------------------------------------- +-- Create import_taxref_rangs table DROP TABLE IF EXISTS taxonomie.import_taxref_rangs; CREATE TABLE taxonomie.import_taxref_rangs ( - level int NOT NULL, - rang varchar(20) NOT NULL, - detail_fr varchar(50) NOT NULL, - detail_en varchar(50) NOT NULL + "level" int NOT NULL, + rang varchar(20) NOT NULL, + detail_fr varchar(50) NOT NULL, + detail_en varchar(50) NOT NULL ); diff --git a/apptax/taxonomie/commands/migrate_taxref/data/specific_taxref_v15_v16/3.2_alter_taxref_data.sql b/apptax/taxonomie/commands/migrate_taxref/data/specific_taxref_v15_v16/3.2_alter_taxref_data.sql index 7af7fba60..800e8d69c 100755 --- a/apptax/taxonomie/commands/migrate_taxref/data/specific_taxref_v15_v16/3.2_alter_taxref_data.sql +++ b/apptax/taxonomie/commands/migrate_taxref/data/specific_taxref_v15_v16/3.2_alter_taxref_data.sql @@ -1,335 +1,456 @@ ----- ################################################################################# ----- ################################################################################# ----- IMPORT DE TAXREF ----- ################################################################################# ----- ################################################################################# - ------------------------------------------------- ------------------------------------------------- ---Alter existing constraints ------------------------------------------------- ------------------------------------------------- -ALTER TABLE taxonomie.bib_noms DROP CONSTRAINT IF EXISTS fk_bib_nom_taxref; - -ALTER TABLE taxonomie.t_medias DROP CONSTRAINT IF EXISTS check_cd_ref_is_ref; -ALTER TABLE taxonomie.bib_noms DROP CONSTRAINT IF EXISTS check_is_valid_cd_ref; -ALTER TABLE taxonomie.cor_taxon_attribut DROP CONSTRAINT IF EXISTS check_is_cd_ref; - ------------------------------------------------- ------------------------------------------------- --- UPDATE TAXREF ------------------------------------------------- ------------------------------------------------- - --- CORRECTION -UPDATE taxonomie.import_taxref SET fr = NULL WHERE fr=''; - --- UPDATE EXISTING CD_NOM -UPDATE taxonomie.taxref t - SET id_statut = fr, id_habitat = it.habitat::int, id_rang = it.rang, regne = it.regne, phylum = it.phylum, - classe = it.classe, ordre = it.ordre, famille = it.famille, cd_taxsup = it.cd_taxsup, - cd_sup = it.cd_sup, cd_ref = it.cd_ref, - lb_nom = it.lb_nom, lb_auteur = it.lb_auteur, nom_complet = it.nom_complet, - nom_complet_html = it.nom_complet_html, nom_valide = it.nom_valide, - nom_vern = it.nom_vern, nom_vern_eng = it.nom_vern_eng, group1_inpn = it.group1_inpn, - group2_inpn = it.group2_inpn, sous_famille = it.sous_famille, - tribu = it.tribu, url = it.url, group3_inpn = it.group3_inpn -FROM taxonomie.import_taxref it -WHERE it.cd_nom = t.cd_nom; - --- ADD NEW CD_NOM +-- ---------------------------------------------------------------------- +-- TAXREF IMPORT + +-- ---------------------------------------------------------------------- +-- Alter existing constraints +ALTER TABLE taxonomie.bib_noms DROP CONSTRAINT IF EXISTS fk_bib_nom_taxref ; +ALTER TABLE taxonomie.t_medias DROP CONSTRAINT IF EXISTS check_cd_ref_is_ref ; +ALTER TABLE taxonomie.bib_noms DROP CONSTRAINT IF EXISTS check_is_valid_cd_ref ; +ALTER TABLE taxonomie.cor_taxon_attribut DROP CONSTRAINT IF EXISTS check_is_cd_ref ; + +-- ---------------------------------------------------------------------- +-- UPDATE TAXREF + +-- Fix TaxRef +UPDATE taxonomie.import_taxref SET + fr = NULL +WHERE fr = '' ; + +-- Update existing cd_nom +UPDATE taxonomie.taxref AS t SET + id_statut = fr, + id_habitat = it.habitat::int, + id_rang = it.rang, + regne = it.regne, + phylum = it.phylum, + classe = it.classe, + ordre = it.ordre, + famille = it.famille, + cd_taxsup = it.cd_taxsup, + cd_sup = it.cd_sup, + cd_ref = it.cd_ref, + lb_nom = it.lb_nom, + lb_auteur = it.lb_auteur, + nom_complet = it.nom_complet, + nom_complet_html = it.nom_complet_html, + nom_valide = it.nom_valide, + nom_vern = it.nom_vern, + nom_vern_eng = it.nom_vern_eng, + group1_inpn = it.group1_inpn, + group2_inpn = it.group2_inpn, + sous_famille = it.sous_famille, + tribu = it.tribu, url = it.url, + group3_inpn = it.group3_inpn +FROM taxonomie.import_taxref AS it +WHERE it.cd_nom = t.cd_nom ; + +-- Add new cd_nom INSERT INTO taxonomie.taxref( - cd_nom, id_statut, id_habitat, id_rang, regne, phylum, classe, - ordre, famille, cd_taxsup, cd_sup, cd_ref, lb_nom, lb_auteur, - nom_complet, nom_complet_html, nom_valide, nom_vern, nom_vern_eng, - group1_inpn, group2_inpn, sous_famille, tribu, url, group3_inpn) -SELECT it.cd_nom, it.fr, it.habitat::int, it.rang, it.regne, it.phylum, it.classe, - it.ordre, it.famille, it.cd_taxsup, it.cd_sup, it.cd_ref, it.lb_nom, it.lb_auteur, - it.nom_complet, it.nom_complet_html, it.nom_valide, it.nom_vern, it.nom_vern_eng, - it.group1_inpn, it.group2_inpn, it.sous_famille, it.tribu, it.url, it.group3_inpn -FROM taxonomie.import_taxref it -LEFT OUTER JOIN taxonomie.taxref t -ON it.cd_nom = t.cd_nom -WHERE t.cd_nom IS NULL; - --- DELETE MISSING CD_NOM if not keep_cdnom is specify + cd_nom, + id_statut, + id_habitat, + id_rang, + regne, + phylum, + classe, + ordre, + famille, + cd_taxsup, + cd_sup, + cd_ref, + lb_nom, + lb_auteur, + nom_complet, + nom_complet_html, + nom_valide, + nom_vern, + nom_vern_eng, + group1_inpn, + group2_inpn, + sous_famille, + tribu, + "url", + group3_inpn +) + SELECT + it.cd_nom, + it.fr, + it.habitat::int, + it.rang, + it.regne, + it.phylum, + it.classe, + it.ordre, + it.famille, + it.cd_taxsup, + it.cd_sup, + it.cd_ref, + it.lb_nom, + it.lb_auteur, + it.nom_complet, + it.nom_complet_html, + it.nom_valide, + it.nom_vern, + it.nom_vern_eng, + it.group1_inpn, + it.group2_inpn, + it.sous_famille, + it.tribu, + it.url, + it.group3_inpn + FROM taxonomie.import_taxref AS it + LEFT JOIN taxonomie.taxref AS t + ON it.cd_nom = t.cd_nom + WHERE t.cd_nom IS NULL ; + +-- Delete missing cd_nom if keep_cdnom is not specify DO $$ BEGIN IF :keep_cd_nom = FALSE THEN DELETE FROM taxonomie.taxref WHERE cd_nom IN ( - SELECT cd_nom - FROM taxonomie.cdnom_disparu - ); - - END IF; -END $$; - ----- ################################################################################# ----- ################################################################################# ----- REPERCUSSION des changements de taxref dans taxhub (attributs, médias) ----- ################################################################################# ----- ################################################################################# - ------------------- ---- cor_nom_liste ------------------- --- Remplacement des anciens cd_nom par leurs remplaçants dans cor_nom_liste -ALTER TABLE taxonomie.cor_nom_liste DROP CONSTRAINT cor_nom_liste_pkey; -ALTER TABLE taxonomie.cor_nom_liste ADD tmp_id serial; - -UPDATE taxonomie.cor_nom_liste l SET id_nom = repl_nom + SELECT cd_nom + FROM taxonomie.cdnom_disparu + ) ; + + END IF ; +END $$ ; + +-- ###################################################################### +-- Impact of Taxref changes bib_noms and cor_nom_liste + +-- ---------------------------------------------------------------------- +-- cor_nom_liste : + +-- Removing temporary the primary key of cor_list_name +ALTER TABLE taxonomie.cor_nom_liste DROP CONSTRAINT cor_nom_liste_pkey ; + + +-- Add a temporary column in cor_nom_liste +ALTER TABLE taxonomie.cor_nom_liste ADD tmp_id serial ; + + +-- Replacement of old cd_nom by their replacements +UPDATE taxonomie.cor_nom_liste AS l SET + id_nom = repl_nom FROM ( - SELECT l.id_liste, l.id_nom, n.cd_nom_remplacement, n.cd_nom, repl.id_nom as repl_nom - FROM taxonomie.cor_nom_liste l - JOIN ( - SELECT n.id_nom, d.* - FROM taxonomie.bib_noms n - JOIN taxonomie.cdnom_disparu d - ON n.cd_nom = d.cd_nom - ) n - ON n.id_nom = l.id_nom - JOIN taxonomie.bib_noms repl - ON repl.cd_nom = n.cd_nom_remplacement - LEFT OUTER JOIN taxonomie.cor_nom_liste li - ON li.id_liste = l.id_liste AND repl.id_nom = li.id_nom - WHERE li.id_liste IS NULL -) a -WHERE a.id_liste = l.id_liste AND a.id_nom = l.id_nom; - - ---- Suppression des doublons + SELECT + l.id_liste, + l.id_nom, + n.cd_nom_remplacement, + n.cd_nom, + repl.id_nom AS repl_nom + FROM taxonomie.cor_nom_liste AS l + JOIN ( + SELECT + n.id_nom, + d.* + FROM taxonomie.bib_noms AS n + JOIN taxonomie.cdnom_disparu AS d + ON n.cd_nom = d.cd_nom + ) AS n + ON n.id_nom = l.id_nom + JOIN taxonomie.bib_noms AS repl + ON repl.cd_nom = n.cd_nom_remplacement + LEFT OUTER JOIN taxonomie.cor_nom_liste AS li + ON (li.id_liste = l.id_liste AND repl.id_nom = li.id_nom) + WHERE li.id_liste IS NULL + ) AS a +WHERE a.id_liste = l.id_liste + AND a.id_nom = l.id_nom ; + + +--- Delete duplicates from cor_nom_liste DELETE FROM taxonomie.cor_nom_liste WHERE tmp_id IN ( - SELECT tmp_id FROM taxonomie.cor_nom_liste l - JOIN ( - SELECT id_liste, id_nom, max(tmp_id) - FROM taxonomie.cor_nom_liste - GROUP BY id_liste, id_nom - HAVING count(*) >1 - )a - ON l.id_liste = a.id_liste AND l.id_nom = a.id_nom - AND NOT tmp_id = max -); - --- supression dans les cas ou il n'y a pas de taxons de remplacements + SELECT tmp_id + FROM taxonomie.cor_nom_liste AS l + JOIN ( + SELECT + id_liste, + id_nom, + max(tmp_id) + FROM taxonomie.cor_nom_liste + GROUP BY id_liste, id_nom + HAVING count(*) > 1 + ) AS a + ON (l.id_liste = a.id_liste AND l.id_nom = a.id_nom AND tmp_id != max) +) ; + + +-- Delete from cor_nom_liste where there are not replacement taxa DELETE FROM taxonomie.cor_nom_liste WHERE id_nom IN ( - SELECT id_nom - FROM taxonomie.bib_noms bn - LEFT OUTER JOIN taxonomie.import_taxref it - ON bn.cd_nom = it.cd_nom - WHERE it.cd_nom IS NULL -); - --- Restauration de la clé primaire de cor_nom_liste -ALTER TABLE taxonomie.cor_nom_liste - ADD CONSTRAINT cor_nom_liste_pkey PRIMARY KEY(id_nom, id_liste); + SELECT bn.id_nom + FROM taxonomie.bib_noms AS bn + LEFT OUTER JOIN taxonomie.import_taxref AS it + ON bn.cd_nom = it.cd_nom + WHERE it.cd_nom IS NULL +) ; --- Suppression de la colonne temporaire cor_nom_liste -ALTER TABLE taxonomie.cor_nom_liste DROP COLUMN tmp_id ; --- Modification de la clé étrangère -ALTER TABLE taxonomie.cor_nom_liste DROP CONSTRAINT cor_nom_listes_bib_noms_fkey; +-- Restoring the primary key of cor_list_name ALTER TABLE taxonomie.cor_nom_liste - ADD CONSTRAINT cor_nom_listes_bib_noms_fkey FOREIGN KEY (id_nom) - REFERENCES taxonomie.bib_noms(id_nom) - ON UPDATE CASCADE - ON DELETE CASCADE; + ADD CONSTRAINT cor_nom_liste_pkey PRIMARY KEY(id_nom, id_liste) ; ------------------- ---- bib_noms +-- Deleting the temporary column in cor_nom_liste +ALTER TABLE taxonomie.cor_nom_liste DROP COLUMN tmp_id ; ------------------- --- Suppression des cd_nom disparus -DELETE FROM taxonomie.bib_noms WHERE cd_nom IN ( - SELECT t.cd_nom - FROM taxonomie.taxref t - LEFT OUTER JOIN taxonomie.import_taxref it - ON it.cd_nom = t.cd_nom - LEFT OUTER JOIN taxonomie.tmp_bib_noms_copy tbnc - ON tbnc.cd_nom = t.cd_nom - WHERE it.cd_nom IS NULL AND tbnc.deleted IS DISTINCT FROM FALSE -); - - - --- Ajout des noms de référence pour les cd_nom ayant changé de cd_ref +-- Changing cor_nom_liste the foreign key +ALTER TABLE taxonomie.cor_nom_liste DROP CONSTRAINT cor_nom_listes_bib_noms_fkey; +ALTER TABLE taxonomie.cor_nom_liste + ADD CONSTRAINT cor_nom_listes_bib_noms_fkey FOREIGN KEY (id_nom) + REFERENCES taxonomie.bib_noms(id_nom) + ON UPDATE CASCADE + ON DELETE CASCADE ; + + +-- ---------------------------------------------------------------------- +-- bib_noms + +-- Remove vanished cd_nom from bib_noms +DELETE FROM taxonomie.bib_noms +WHERE cd_nom IN ( + SELECT t.cd_nom + FROM taxonomie.taxref t + LEFT OUTER JOIN taxonomie.import_taxref AS it + ON it.cd_nom = t.cd_nom + LEFT OUTER JOIN taxonomie.tmp_bib_noms_copy AS tbnc + ON tbnc.cd_nom = t.cd_nom + WHERE it.cd_nom IS NULL + AND tbnc.deleted IS DISTINCT FROM FALSE +) ; + + +-- Add reference names in bib_noms for cd_nom having changed from cd_ref INSERT INTO taxonomie.bib_noms (cd_nom, cd_ref, nom_francais) -SELECT DISTINCT t.cd_nom, t.cd_ref, split_part(nom_vern, ',', 1) -FROM tmp_taxref_changes.comp_grap cg -LEFT OUTER JOIN taxonomie.bib_noms n -ON n.cd_nom = f_cd_ref -JOIN taxonomie.taxref t -ON f_cd_ref = t.cd_nom -WHERE n.cd_nom IS NULL; - -------------- Cas avec cd_nom de remplacement --- Ajout du cd_nom de remplacement quand il n'existait pas dans bib_noms -UPDATE taxonomie.bib_noms b -SET cd_nom = a.cd_nom_remplacement + SELECT DISTINCT + t.cd_nom, + t.cd_ref, + split_part(nom_vern, ',', 1) + FROM tmp_taxref_changes.comp_grap AS cg + LEFT OUTER JOIN taxonomie.bib_noms AS n + ON n.cd_nom = cg.f_cd_ref + JOIN taxonomie.taxref AS t + ON cg.f_cd_ref = t.cd_nom + WHERE n.cd_nom IS NULL ; + + +-- Set replacement cd_nom when it did not exist in bib_noms +UPDATE taxonomie.bib_noms AS b SET + cd_nom = a.cd_nom_remplacement FROM ( SELECT - n.cd_nom, - n.cd_nom_remplacement - FROM - taxonomie.tmp_bib_noms_copy n - LEFT OUTER JOIN taxonomie.bib_noms b ON n.cd_nom_remplacement = b.cd_nom - WHERE - NOT n.cd_nom_remplacement IS NULL - AND b.cd_nom IS NULL - ) a -WHERE b.cd_nom = a.cd_nom; - --- Suppression des cd_noms obsolètes -DELETE FROM taxonomie.bib_noms b -WHERE - id_nom IN ( + n.cd_nom, + n.cd_nom_remplacement + FROM taxonomie.tmp_bib_noms_copy AS n + LEFT OUTER JOIN taxonomie.bib_noms AS b + ON n.cd_nom_remplacement = b.cd_nom + WHERE n.cd_nom_remplacement IS NOT NULL + AND b.cd_nom IS NULL + ) AS a +WHERE b.cd_nom = a.cd_nom ; + +-- Remove obsolete cd_nom in bib_noms +DELETE FROM taxonomie.bib_noms +WHERE id_nom IN ( SELECT b.id_nom - FROM taxonomie.tmp_bib_noms_copy n - JOIN taxonomie.bib_noms b ON n.cd_nom = b.cd_nom + FROM taxonomie.tmp_bib_noms_copy AS n + JOIN taxonomie.bib_noms AS b + ON n.cd_nom = b.cd_nom WHERE deleted = TRUE - ); +) ; ---Mise à jour des cd_ref -UPDATE taxonomie.bib_noms n SET cd_ref = t.cd_ref -FROM taxonomie.taxref t -WHERE n.cd_nom = t.cd_nom; +-- TODO: why not used import_taxref !? +-- Update cd_ref in bib_noms +UPDATE taxonomie.bib_noms AS n SET + cd_ref = t.cd_ref +FROM taxonomie.taxref AS t +WHERE n.cd_nom = t.cd_nom ; ----- ################################################################################# ----- ################################################################################# ----- MODIFICATIONS DES ATTRIBUTS ET DES MEDIAS ----- ################################################################################# ----- ################################################################################# +-- ###################################################################### +-- Impact of Taxref changes in Taxhub attributes and media ---- Sauvegarde des données au cas ou -DROP TABLE IF EXISTS tmp_taxref_changes.t_medias; +-- Backup t_medias and cor_taxon_attribut tables +DROP TABLE IF EXISTS tmp_taxref_changes.t_medias ; + CREATE TABLE tmp_taxref_changes.t_medias AS -SELECT * FROM taxonomie.t_medias; + SELECT * FROM taxonomie.t_medias ; + +DROP TABLE IF EXISTS tmp_taxref_changes.cor_taxon_attribut ; -DROP TABLE IF EXISTS tmp_taxref_changes.cor_taxon_attribut; CREATE TABLE tmp_taxref_changes.cor_taxon_attribut AS -SELECT * FROM taxonomie.cor_taxon_attribut; + SELECT * FROM taxonomie.cor_taxon_attribut ; ---- Action : Update cd_ref no changes for attributes and medium -ALTER TABLE taxonomie.t_medias DISABLE TRIGGER USER; -UPDATE taxonomie.t_medias SET cd_ref = f_cd_ref +-- Action: update cd_ref no changes for attributes and media +ALTER TABLE taxonomie.t_medias DISABLE TRIGGER USER ; + +UPDATE taxonomie.t_medias SET + cd_ref = f_cd_ref FROM tmp_taxref_changes.comp_grap -WHERE cas = 'update cd_ref' AND cd_ref = i_cd_ref; +WHERE cas = 'update cd_ref' + AND cd_ref = i_cd_ref ; + ALTER TABLE taxonomie.t_medias ENABLE TRIGGER USER; -UPDATE taxonomie.cor_taxon_attribut SET cd_ref = f_cd_ref +UPDATE taxonomie.cor_taxon_attribut SET + cd_ref = f_cd_ref FROM tmp_taxref_changes.comp_grap -WHERE cas = 'update cd_ref' AND cd_ref = i_cd_ref; +WHERE cas = 'update cd_ref' + AND cd_ref = i_cd_ref ; ---- Action : Keep attributes and medium + +--- Action: keep attributes and media ALTER TABLE taxonomie.t_medias DISABLE TRIGGER USER; -UPDATE taxonomie.t_medias SET cd_ref = f_cd_ref + +UPDATE taxonomie.t_medias SET + cd_ref = f_cd_ref FROM tmp_taxref_changes.comp_grap -WHERE action = 'Keep attributes and medium' aND cd_ref = i_cd_ref AND not i_cd_ref = f_cd_ref; +WHERE action = 'Keep attributes and medium' + AND cd_ref = i_cd_ref + AND i_cd_ref != f_cd_ref; + ALTER TABLE taxonomie.t_medias ENABLE TRIGGER USER; -UPDATE taxonomie.cor_taxon_attribut SET cd_ref = f_cd_ref +UPDATE taxonomie.cor_taxon_attribut SET + cd_ref = f_cd_ref FROM tmp_taxref_changes.comp_grap -WHERE action = 'Keep attributes and medium' aND cd_ref = i_cd_ref AND not i_cd_ref = f_cd_ref; +WHERE action = 'Keep attributes and medium' + AND cd_ref = i_cd_ref + AND i_cd_ref != f_cd_ref ; ---- Action : Loose attributes and medium - --- => Nothing to do + +-- Action: Loose attributes and medium +-- => Nothing to do /* SELECT * FROM tmp_taxref_changes.comp_grap -WHERE action ilike 'loo%' +WHERE action ILIKE 'loo%' ; */ ---- Action : duplicate -INSERT INTO taxonomie.cor_taxon_attribut( - id_attribut, valeur_attribut, cd_ref) -SELECT a.id_attribut, a.valeur_attribut, f_cd_ref -FROM tmp_taxref_changes.comp_grap cg -JOIN taxonomie.cor_taxon_attribut a -ON cg.i_cd_ref = a.cd_ref -WHERE action ilike '%Duplicate attibutes%' -ON CONFLICT DO NOTHING; - - - -ALTER TABLE taxonomie.t_medias DISABLE TRIGGER USER; - -INSERT INTO taxonomie.t_medias(cd_ref, titre, url, chemin, auteur, desc_media, date_media, is_public, supprime, id_type, source, licence) -SELECT f_cd_ref, titre, url, chemin, auteur, desc_media, date_media, is_public, supprime, id_type, source, licence -FROM tmp_taxref_changes.comp_grap cg -JOIN taxonomie.t_medias a -ON cg.i_cd_ref = a.cd_ref -WHERE action ilike '%Duplicate medium%'; - -ALTER TABLE taxonomie.t_medias ENABLE TRIGGER USER; - ---- Action : Merge attributes if exists -ALTER TABLE taxonomie.t_medias DISABLE TRIGGER USER; -UPDATE taxonomie.t_medias SET cd_ref = f_cd_ref +-- Action: duplicate +INSERT INTO taxonomie.cor_taxon_attribut (id_attribut, valeur_attribut, cd_ref) + SELECT a.id_attribut, a.valeur_attribut, f_cd_ref + FROM tmp_taxref_changes.comp_grap AS cg + JOIN taxonomie.cor_taxon_attribut AS a + ON cg.i_cd_ref = a.cd_ref + WHERE action ILIKE '%Duplicate attibutes%' +ON CONFLICT DO NOTHING ; + + +ALTER TABLE taxonomie.t_medias DISABLE TRIGGER USER ; + +INSERT INTO taxonomie.t_medias( + cd_ref, + titre, + "url", + chemin, + auteur, + desc_media, + date_media, + is_public, + supprime, + id_type, + source, + licence +) +SELECT + f_cd_ref, + titre, + "url", + chemin, + auteur, + desc_media, + date_media, + is_public, + supprime, + id_type, + source, + licence +FROM tmp_taxref_changes.comp_grap AS cg + JOIN taxonomie.t_medias AS a + ON cg.i_cd_ref = a.cd_ref +WHERE action ILIKE '%Duplicate medium%' ; + +ALTER TABLE taxonomie.t_medias ENABLE TRIGGER USER ; + + +--- Action : merge attributes if exists +ALTER TABLE taxonomie.t_medias DISABLE TRIGGER USER ; + +UPDATE taxonomie.t_medias SET + cd_ref = f_cd_ref FROM tmp_taxref_changes.comp_grap -WHERE action ilike '%Merge attributes%' AND cd_ref = i_cd_ref; -ALTER TABLE taxonomie.t_medias ENABLE TRIGGER USER; +WHERE action ILIKE '%Merge attributes%' + AND cd_ref = i_cd_ref ; +ALTER TABLE taxonomie.t_medias ENABLE TRIGGER USER ; --- Suppression des potentiels doublons puis modification + +-- Delete duplicates if exists and update attributs WITH grp_del AS ( - SELECT f_cd_ref, id_attribut, count(*), array_agg( DISTINCT i_cd_ref) cd_refs, array_agg( DISTINCT valeur_attribut) AS valeur_attribut - FROM taxonomie.cor_taxon_attribut ia - JOIN tmp_taxref_changes.comp_grap cg - ON -- action ilike '%Merge attributes%' AND - cd_ref = i_cd_ref + SELECT + f_cd_ref, + id_attribut, + count(*), + array_agg(DISTINCT i_cd_ref) AS cd_refs, + array_agg(DISTINCT valeur_attribut) AS valeur_attribut + FROM taxonomie.cor_taxon_attribut AS ia + JOIN tmp_taxref_changes.comp_grap AS cg + ON cd_ref = i_cd_ref GROUP BY f_cd_ref, id_attribut HAVING count(*) > 1 -) , del AS ( - SELECT id_attribut as at, unnest(cd_refs[2:]) +), +del AS ( + SELECT + id_attribut AS "at", + unnest(cd_refs[2:]) FROM grp_del WHERE array_length(valeur_attribut, 1) = 1 ) DELETE FROM taxonomie.cor_taxon_attribut USING del -WHERE cd_ref = unnest AND id_attribut = at; +WHERE cd_ref = unnest + AND id_attribut = "at" ; -UPDATE taxonomie.cor_taxon_attribut SET cd_ref = f_cd_ref +UPDATE taxonomie.cor_taxon_attribut SET + cd_ref = f_cd_ref FROM tmp_taxref_changes.comp_grap -WHERE action ilike '%Merge attributes%' AND cd_ref = i_cd_ref; +WHERE action ILIKE '%Merge attributes%' + AND cd_ref = i_cd_ref ; ------------------------------------------------- ------------------------------------------------- --- REBUILD CONSTAINTS ------------------------------------------------- ------------------------------------------------- -UPDATE taxonomie.t_medias m SET cd_ref = t.cd_ref -FROM taxonomie.taxref t -WHERE m.cd_ref = t.cd_nom AND NOT t.cd_nom = t.cd_ref; +-- ###################################################################### +-- Rebuild constraints +UPDATE taxonomie.t_medias AS m SET + cd_ref = t.cd_ref +FROM taxonomie.taxref AS t +WHERE m.cd_ref = t.cd_nom + AND t.cd_nom != t.cd_ref ; -UPDATE taxonomie.cor_taxon_attribut m SET cd_ref = t.cd_ref -FROM taxonomie.taxref t +UPDATE taxonomie.cor_taxon_attribut AS m SET + cd_ref = t.cd_ref +FROM taxonomie.taxref AS t WHERE m.cd_ref = t.cd_nom - AND NOT t.cd_ref = t.cd_nom; + AND t.cd_ref != t.cd_nom; ALTER TABLE taxonomie.bib_noms - ADD CONSTRAINT fk_bib_nom_taxref FOREIGN KEY (cd_nom) - REFERENCES taxonomie.taxref (cd_nom) MATCH SIMPLE - ON UPDATE NO ACTION ON DELETE NO ACTION; - + ADD CONSTRAINT fk_bib_nom_taxref FOREIGN KEY (cd_nom) + REFERENCES taxonomie.taxref (cd_nom) MATCH SIMPLE + ON UPDATE NO ACTION ON DELETE NO ACTION ; ALTER TABLE taxonomie.t_medias - DROP CONSTRAINT IF EXISTS check_is_cd_ref, - ADD CONSTRAINT check_is_cd_ref CHECK (cd_ref = taxonomie.find_cdref(cd_ref)); + DROP CONSTRAINT IF EXISTS check_is_cd_ref, + ADD CONSTRAINT check_is_cd_ref CHECK (cd_ref = taxonomie.find_cdref(cd_ref)) ; ALTER TABLE taxonomie.cor_taxon_attribut - DROP CONSTRAINT IF EXISTS check_is_cd_ref, - ADD CONSTRAINT check_is_cd_ref CHECK (cd_ref = taxonomie.find_cdref(cd_ref)); - - - + DROP CONSTRAINT IF EXISTS check_is_cd_ref, + ADD CONSTRAINT check_is_cd_ref CHECK (cd_ref = taxonomie.find_cdref(cd_ref)) ;