-
Notifications
You must be signed in to change notification settings - Fork 31
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
refactor(migrate_taxref): refactor all SQL files
- Loading branch information
Showing
7 changed files
with
783 additions
and
528 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
89 changes: 48 additions & 41 deletions
89
...te_taxref/data/changes_detection/0.2_taxref_detection_repercussion_disparition_cd_nom.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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 ; |
143 changes: 91 additions & 52 deletions
143
...axonomie/commands/migrate_taxref/data/changes_detection/1.1_taxref_changes_detections.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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); | ||
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) ; |
Oops, something went wrong.