diff --git a/config/mv_c_cor_vn_taxref.sql b/config/mv_c_cor_vn_taxref.sql index c70f0aa..b6a90c6 100644 --- a/config/mv_c_cor_vn_taxref.sql +++ b/config/mv_c_cor_vn_taxref.sql @@ -6,7 +6,7 @@ CREATE MATERIALIZED VIEW taxonomie.mv_c_cor_vn_taxref TABLESPACE pg_default -AS WITH prep AS ( +AS WITH prep_vn AS ( SELECT DISTINCT sp.id AS vn_id, tg.item ->> 'name'::text AS groupe_taxo_fr, tg.item ->> 'latin_name'::text AS groupe_taxo_sci, @@ -14,51 +14,85 @@ AS WITH prep AS ( sp.item ->> 'latin_name'::text AS latin_name FROM src_vn_json.species_json sp LEFT JOIN src_vn_json.taxo_groups_json tg ON ((sp.item ->> 'id_taxo_group'::text)::integer) = tg.id AND sp.site::text = tg.site::text - GROUP BY sp.id, (tg.item ->> 'name'::text), (tg.item ->> 'latin_name'::text), (sp.item ->> 'french_name'::text), (sp.item ->> 'latin_name'::text) + GROUP BY sp.id, (tg.item ->> 'name'::text), (tg.item ->> 'latin_name'::text), (sp.item ->> 'french_name'::text), (sp.item ->> 'latin_name'::text) + ), prep_tx AS ( + SELECT tx.cd_nom, + tx.cd_ref, + tx.group1_inpn AS tx_group1_inpn, + tx.group2_inpn AS tx_group2_inpn, + tx.id_rang AS tx_id_rang, + tx.ordre AS tx_ordre, + tx.classe AS tx_classe, + tx.famille AS tx_famille, + tx.nom_vern AS tx_nom_fr, + tx.lb_nom AS tx_nom_sci + FROM taxonomie.taxref tx + WHERE tx.cd_nom = tx.cd_ref + ), prep_synth AS ( + SELECT prep_vn.vn_id, + string_agg(DISTINCT prep_vn.groupe_taxo_fr, ', '::text) AS groupe_taxo_fr, + string_agg(DISTINCT prep_vn.groupe_taxo_sci, ', '::text) AS groupe_taxo_sci, + COALESCE(string_agg(DISTINCT prep_vn.french_name, ','::text), string_agg(DISTINCT prep_tx.tx_nom_fr::text, ','::text)) AS vn_nom_fr, + COALESCE(string_agg(DISTINCT prep_vn.latin_name, ','::text), string_agg(DISTINCT prep_tx.tx_nom_sci::text, ', '::text)) AS vn_nom_sci, + prep_tx.cd_nom, + prep_tx.cd_ref, + string_agg(DISTINCT prep_tx.tx_group1_inpn::text, ', '::text) AS tx_group1_inpn, + string_agg(DISTINCT prep_tx.tx_group2_inpn::text, ', '::text) AS tx_group2_inpn, + string_agg(DISTINCT prep_tx.tx_id_rang::text, ', '::text) AS tx_id_rang, + string_agg(DISTINCT prep_tx.tx_ordre::text, ', '::text) AS tx_ordre, + string_agg(DISTINCT prep_tx.tx_classe::text, ', '::text) AS tx_classe, + string_agg(DISTINCT prep_tx.tx_famille::text, ', '::text) AS tx_famille, + string_agg(DISTINCT prep_tx.tx_nom_fr::text, ', '::text) AS tx_nom_fr, + string_agg(DISTINCT prep_tx.tx_nom_sci::text, ', '::text) AS tx_nom_sci + FROM prep_tx + LEFT JOIN taxonomie.cor_c_vn_taxref cor ON cor.cd_nom = prep_tx.cd_nom + LEFT JOIN prep_vn ON prep_vn.vn_id = cor.vn_id + GROUP BY prep_vn.vn_id, prep_tx.cd_nom, prep_tx.cd_ref ) - SELECT vn.vn_id, - vn.groupe_taxo_fr, - vn.groupe_taxo_sci, - vn.french_name AS vn_nom_fr, - vn.latin_name AS vn_nom_sci, - tx.cd_nom, - tx.cd_ref, - tx.group1_inpn AS tx_group1_inpn, - tx.group2_inpn AS tx_group2_inpn, - tx.classe AS tx_classe, - tx.famille AS tx_famille, - tx.nom_vern AS tx_nom_fr, - tx.lb_nom AS tx_nom_sci, + SELECT array_agg(DISTINCT ps1.vn_id) AS vn_id, + ps1.groupe_taxo_fr, + ps1.groupe_taxo_sci, CASE - WHEN id_sp_vn.id_sp_source IS NOT NULL THEN true - ELSE false - END AS vn_utilisation - FROM prep vn - LEFT JOIN taxonomie.cor_c_vn_taxref corr ON vn.vn_id = corr.vn_id - LEFT JOIN taxonomie.taxref tx ON corr.cd_nom = tx.cd_nom - LEFT JOIN ( SELECT DISTINCT tcse.id_sp_source - FROM src_lpodatas.t_c_synthese_extended tcse - JOIN gn_synthese.synthese s ON s.id_synthese = tcse.id_synthese - WHERE (s.id_source IN ( SELECT ts.id_source - FROM gn_synthese.t_sources ts - WHERE ts.name_source::text = 'faune-aura'::text))) id_sp_vn ON id_sp_vn.id_sp_source = vn.vn_id + WHEN ps1.cd_nom = ps1.cd_ref THEN ps1.vn_nom_fr + WHEN ps2.cd_nom = ps1.cd_ref THEN ps2.vn_nom_fr + ELSE ps1.vn_nom_fr + END AS vn_nom_fr, + CASE + WHEN ps1.cd_nom = ps1.cd_ref THEN ps1.vn_nom_sci + WHEN ps2.cd_nom = ps1.cd_ref THEN ps2.vn_nom_sci + ELSE ps1.vn_nom_fr + END AS vn_nom_sci, + ps1.cd_ref AS cd_nom, + ps1.cd_ref, + ps1.tx_group1_inpn, + ps1.tx_group2_inpn, + ps1.tx_id_rang, + ps1.tx_ordre, + ps1.tx_classe, + ps1.tx_famille, + ps1.tx_nom_fr, + ps1.tx_nom_sci + FROM prep_synth ps1 + LEFT JOIN prep_synth ps2 ON ps1.cd_ref = ps2.cd_ref + GROUP BY ps1.groupe_taxo_fr, ps1.groupe_taxo_sci, ( + CASE + WHEN ps1.cd_nom = ps1.cd_ref THEN ps1.vn_nom_fr + WHEN ps2.cd_nom = ps1.cd_ref THEN ps2.vn_nom_fr + ELSE ps1.vn_nom_fr + END), ( + CASE + WHEN ps1.cd_nom = ps1.cd_ref THEN ps1.vn_nom_sci + WHEN ps2.cd_nom = ps1.cd_ref THEN ps2.vn_nom_sci + ELSE ps1.vn_nom_fr + END), ps1.cd_ref, ps1.tx_group1_inpn, ps1.tx_group2_inpn, ps1.tx_id_rang, ps1.tx_ordre, ps1.tx_classe, ps1.tx_famille, ps1.tx_nom_fr, ps1.tx_nom_sci WITH DATA; -- View indexes: CREATE INDEX mv_c_cor_vn_taxref_cd_nom_idx1 ON taxonomie.mv_c_cor_vn_taxref USING btree (cd_nom); +CREATE INDEX mv_c_cor_vn_taxref_cd_ref_idx1 ON taxonomie.mv_c_cor_vn_taxref USING btree (cd_ref); CREATE INDEX mv_c_cor_vn_taxref_groupe_taxo_fr_idx1 ON taxonomie.mv_c_cor_vn_taxref USING btree (groupe_taxo_fr); CREATE INDEX mv_c_cor_vn_taxref_tx_group2_inpn_idx1 ON taxonomie.mv_c_cor_vn_taxref USING btree (tx_group2_inpn); CREATE INDEX mv_c_cor_vn_taxref_tx_nom_fr_idx1 ON taxonomie.mv_c_cor_vn_taxref USING btree (tx_nom_fr); CREATE INDEX mv_c_cor_vn_taxref_tx_nom_sci_idx1 ON taxonomie.mv_c_cor_vn_taxref USING btree (tx_nom_sci); CREATE INDEX mv_c_cor_vn_taxref_vn_nom_fr_idx1 ON taxonomie.mv_c_cor_vn_taxref USING btree (vn_nom_fr); CREATE INDEX mv_c_cor_vn_taxref_vn_nom_sci_idx1 ON taxonomie.mv_c_cor_vn_taxref USING btree (vn_nom_sci); -CREATE INDEX mv_c_cor_vn_taxref_vn_utilisation_idx1 ON taxonomie.mv_c_cor_vn_taxref USING btree (vn_utilisation); - - --- Permissions - -ALTER TABLE taxonomie.mv_c_cor_vn_taxref OWNER TO dbadmin; -GRANT ALL ON TABLE taxonomie.mv_c_cor_vn_taxref TO postgres; -GRANT ALL ON TABLE taxonomie.mv_c_cor_vn_taxref TO dbadmin; -GRANT SELECT ON TABLE taxonomie.mv_c_cor_vn_taxref TO dt; -GRANT ALL ON TABLE taxonomie.mv_c_cor_vn_taxref TO advanced_user; diff --git a/config/mv_statuts.sql b/config/mv_statuts.sql index b54749a..c7262fb 100644 --- a/config/mv_statuts.sql +++ b/config/mv_statuts.sql @@ -27,14 +27,11 @@ * */ - -drop materialized view taxonomie.mv_c_statut; -create materialized view taxonomie.mv_c_statut as ( -with -prep_lrra as ( - SELECT DISTINCT - tx.classe, - sp.id_redlist, +CREATE MATERIALIZED VIEW taxonomie.mv_c_statut +TABLESPACE pg_default +AS WITH prep_lrra AS ( + SELECT DISTINCT tx.classe, + sp.id_redlist, sp.status_order, tx.cd_ref, sp.category, @@ -42,18 +39,15 @@ prep_lrra as ( sp.id_source FROM taxonomie.t_c_redlist sp LEFT JOIN taxonomie.taxref tx ON sp.cd_nom = tx.cd_nom - inner join taxonomie.bib_c_redlist_source art ON sp.id_source = art.id_source - where (classe='Aves' or (classe ='Mammalia' and ordre <>'Chiroptera')) and art.area_name ='Rhône-Alpes' -) -, -prep_statut_lrra as -(select distinct -sp.cd_ref , -CASE - WHEN classe!~~*'Aves' AND (id_source <> ALL (ARRAY[18, 19, 20])) THEN sp.category - WHEN classe='Aves' AND id_source = 18 THEN sp.category - WHEN classe='Aves' AND id_source = 19 THEN (sp.category::text || 'w'::text)::character varying - WHEN classe='Aves' AND id_source = 20 THEN (sp.category::text || 'm'::text)::character varying + JOIN taxonomie.bib_c_redlist_source art ON sp.id_source = art.id_source + WHERE (tx.classe::text = 'Aves'::text OR tx.classe::text = 'Mammalia'::text AND tx.ordre::text <> 'Chiroptera'::text) AND art.area_name::text = 'Rhône-Alpes'::text + ), prep_statut_lrra AS ( + SELECT DISTINCT sp.cd_ref, + CASE + WHEN sp.classe::text !~~* 'Aves'::text AND (sp.id_source <> ALL (ARRAY[18, 19, 20])) THEN sp.category + WHEN sp.classe::text = 'Aves'::text AND sp.id_source = 18 THEN sp.category + WHEN sp.classe::text = 'Aves'::text AND sp.id_source = 19 THEN (sp.category::text || 'w'::text)::character varying + WHEN sp.classe::text = 'Aves'::text AND sp.id_source = 20 THEN (sp.category::text || 'm'::text)::character varying ELSE NULL::character varying END AS lrra, CASE @@ -68,44 +62,40 @@ CASE WHEN sp.id_source = 20 THEN sp.category ELSE NULL::character varying END AS lrra_migr -from prep_lrra sp), -prep_lrra_ok as( -select - cd_ref - , string_agg(distinct lrra,', ') lrra - , string_agg(distinct lrra_nich,', ') lrra_nich - , string_agg(distinct lrra_hiv,', ') lrra_hiv - , string_agg(distinct lrra_migr,', ') lrra_migr -from prep_statut_lrra -group by cd_ref) -, -prep_t_redlist_fr AS ( + FROM prep_lrra sp + ), prep_lrra_ok AS ( + SELECT prep_statut_lrra.cd_ref, + string_agg(DISTINCT prep_statut_lrra.lrra::text, ', '::text) AS lrra, + string_agg(DISTINCT prep_statut_lrra.lrra_nich::text, ', '::text) AS lrra_nich, + string_agg(DISTINCT prep_statut_lrra.lrra_hiv::text, ', '::text) AS lrra_hiv, + string_agg(DISTINCT prep_statut_lrra.lrra_migr::text, ', '::text) AS lrra_migr + FROM prep_statut_lrra + GROUP BY prep_statut_lrra.cd_ref + ), prep_t_redlist_fr AS ( SELECT DISTINCT sp.id_redlist, sp.status_order, tx.cd_ref, sp.category, sp.criteria, sp.id_source, - groupe_taxo_fr, - vn_nom_fr, - vn_nom_sci - FROM taxonomie.t_redlist sp + ctx.groupe_taxo_fr, + ctx.vn_nom_fr, + ctx.vn_nom_sci + FROM taxonomie.t_c_redlist sp JOIN taxonomie.taxref tx ON sp.cd_nom = tx.cd_nom - join taxonomie.mv_c_cor_vn_taxref ctx on sp.cd_ref=ctx.cd_ref - where groupe_taxo_fr='Oiseaux' + JOIN taxonomie.mv_c_cor_vn_taxref_bkp ctx ON sp.cd_ref = ctx.cd_ref + WHERE ctx.groupe_taxo_fr = 'Oiseaux'::text ), prep2 AS ( - SELECT DISTINCT - ptlr.cd_ref, - groupe_taxo_fr, - vn_nom_fr, - vn_nom_sci, + SELECT DISTINCT ptlr.cd_ref, + ptlr.groupe_taxo_fr, + ptlr.vn_nom_fr, + ptlr.vn_nom_sci, CASE - WHEN groupe_taxo_fr ~~* 'Oiseaux'::text AND ptlr.id_source = 5 THEN ptlr.category - WHEN groupe_taxo_fr ~~* 'Oiseaux'::text AND ptlr.id_source = 4 THEN (ptlr.category::text || 'w'::text)::character varying - WHEN groupe_taxo_fr ~~* 'Oiseaux'::text AND ptlr.id_source = 3 THEN (ptlr.category::text || 'm'::text)::character varying + WHEN ptlr.groupe_taxo_fr ~~* 'Oiseaux'::text AND ptlr.id_source = 5 THEN ptlr.category + WHEN ptlr.groupe_taxo_fr ~~* 'Oiseaux'::text AND ptlr.id_source = 4 THEN (ptlr.category::text || 'w'::text)::character varying + WHEN ptlr.groupe_taxo_fr ~~* 'Oiseaux'::text AND ptlr.id_source = 3 THEN (ptlr.category::text || 'm'::text)::character varying ELSE NULL::character varying - END AS lr_france - , + END AS lr_france, CASE WHEN ptlr.id_source = 5 THEN ptlr.category ELSE NULL::character varying @@ -120,349 +110,178 @@ prep_t_redlist_fr AS ( END AS lr_fr_migr FROM prep_t_redlist_fr ptlr LEFT JOIN taxonomie.taxref tr ON ptlr.cd_ref = tr.cd_nom - LEFT JOIN taxonomie.bib_redlist_source art ON ptlr.id_source = art.id_source + LEFT JOIN taxonomie.bib_c_redlist_source art ON ptlr.id_source = art.id_source + ), prep_lrf_ok AS ( + SELECT prep2.cd_ref, + prep2.groupe_taxo_fr, + prep2.vn_nom_fr, + prep2.vn_nom_sci, + string_agg(DISTINCT prep2.lr_france::text, ', '::text) AS lr_france, + string_agg(DISTINCT prep2.lr_fr_nich::text, ', '::text) AS lr_fr_nich, + string_agg(DISTINCT prep2.lr_fr_hiv::text, ', '::text) AS lr_fr_hiv, + string_agg(DISTINCT prep2.lr_fr_migr::text, ', '::text) AS lr_fr_migr + FROM prep2 + GROUP BY prep2.groupe_taxo_fr, prep2.vn_nom_fr, prep2.vn_nom_sci, prep2.cd_ref + ), lr_auv AS ( + SELECT bs.cd_ref, + bs.code_statut, + bs.label_statut + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'LRR'::text AND bs.lb_adm_tr::text = 'Auvergne'::text + ), lr_ra AS ( + SELECT bs.cd_ref, + bs.code_statut, + NULL::text AS lrra_nich, + NULL::text AS lrra_hiv, + NULL::text AS lrra_migr + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'LRR'::text AND bs.lb_adm_tr::text = 'Rhône-Alpes'::text + UNION + SELECT prep_lrra_ok.cd_ref, + prep_lrra_ok.lrra, + prep_lrra_ok.lrra_nich, + prep_lrra_ok.lrra_hiv, + prep_lrra_ok.lrra_migr + FROM prep_lrra_ok + ), lr_aura AS ( + SELECT bs.cd_ref, + bs.code_statut, + bs.label_statut + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'LRR'::text AND bs.lb_adm_tr::text = 'Auvergne-Rhône-Alpes'::text + ), lr_fr AS ( + SELECT bs.cd_ref, + bs.code_statut AS lr_france, + NULL::text AS lr_fr_nich, + NULL::text AS lr_fr_hiv, + NULL::text AS lr_fr_migr + FROM taxonomie.bdc_statut bs + JOIN taxonomie.taxref ON bs.cd_nom = taxref.cd_nom + WHERE bs.cd_type_statut::text = 'LRN'::text AND bs.lb_adm_tr::text = 'France métropolitaine'::text AND (taxref.classe IS NULL OR taxref.classe::text <> 'Aves'::text) + UNION + SELECT prep_lrf_ok.cd_ref, + prep_lrf_ok.lr_france, + prep_lrf_ok.lr_fr_nich, + prep_lrf_ok.lr_fr_hiv, + prep_lrf_ok.lr_fr_migr + FROM prep_lrf_ok + ), lr_euro AS ( + SELECT bs.cd_ref, + bs.cd_nom, + bs.code_statut, + bs.label_statut + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'LRE'::text + ), lr_monde AS ( + SELECT bs.cd_ref, + bs.cd_nom, + bs.code_statut, + bs.label_statut + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'LRM'::text + ), prot_nat AS ( + SELECT bs.cd_ref, + CASE + WHEN bs.code_statut::text ~~* 'FRAR%'::text THEN string_agg(DISTINCT split_part(bs.code_statut::text, 'FRAR'::text, 2), ', '::text) + ELSE string_agg(DISTINCT split_part(bs.label_statut::text, ' : '::text, 2), ', '::text) + END AS article, + string_agg(DISTINCT bs.code_statut::text, ', '::text) AS code_statut, + string_agg(DISTINCT bs.label_statut::text, ', '::text) AS label_statut + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'PN'::text AND bs.lb_adm_tr::text = 'France métropolitaine'::text + GROUP BY bs.cd_ref, bs.code_statut + ), n2k AS ( + SELECT bs.cd_ref, + string_agg(DISTINCT split_part(bs.label_statut::text, ' : '::text, 2), ', '::text) AS annexe + FROM taxonomie.bdc_statut bs + WHERE (bs.cd_type_statut::text = ANY (ARRAY['DH'::character varying::text, 'DO'::character varying::text])) AND bs.lb_adm_tr::text = 'France métropolitaine'::text + GROUP BY bs.cd_ref + ), berne AS ( + SELECT bs.cd_ref, + split_part(bs.label_statut::text, ' : '::text, 2) AS annexe, + bs.code_statut, + bs.label_statut + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'BERN'::text AND bs.lb_adm_tr::text = 'France métropolitaine'::text + ), bonn AS ( + SELECT bs.cd_ref, + string_agg(DISTINCT split_part(bs.label_statut::text, ' : '::text, 2), ', '::text) AS annexe + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'BONN'::text + GROUP BY bs.cd_ref + ), pna_en_cours AS ( + SELECT bs.cd_ref, + CASE + WHEN bs.code_statut::text = 'true'::text THEN 'Oui'::text + ELSE NULL::text + END AS statut, + bs.label_statut + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'PNA'::text + ), pna_ex AS ( + SELECT bs.cd_ref, + CASE + WHEN bs.code_statut::text = 'true'::text THEN 'Oui'::text + ELSE NULL::text + END AS statut, + bs.code_statut, + bs.label_statut + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'exPNA'::text + ), sc38 AS ( + SELECT tb.cdnom_taxref AS cd_ref, + tb.sc38_2015 + FROM partage.lpo38_tabesp1806 tb + LEFT JOIN taxonomie.mv_c_cor_vn_taxref_bkp ccvt ON ccvt.cd_nom = tb.cdnom_taxref::integer + WHERE tb.sc38_2015 IS NOT NULL ) -, prep_lrf_ok as (SELECT - prep2.cd_ref, - prep2.groupe_taxo_fr, - prep2.vn_nom_fr, - prep2.vn_nom_sci, - string_agg(DISTINCT prep2.lr_france::text, ', '::text) AS lr_france, - string_agg(DISTINCT prep2.lr_fr_nich::text, ', '::text) AS lr_fr_nich, - string_agg(DISTINCT prep2.lr_fr_hiv::text, ', '::text) AS lr_fr_hiv, - string_agg(DISTINCT prep2.lr_fr_migr::text, ', '::text) AS lr_fr_migr - FROM prep2 - GROUP BY prep2.groupe_taxo_fr, prep2.vn_nom_fr, prep2.vn_nom_sci, prep2.cd_ref - ) -,lr_auv as ( -select - bs.cd_ref - , bs.code_statut - , bs.label_statut -FROM taxonomie.bdc_statut bs -where bs.cd_type_statut='LRR' and bs.lb_adm_tr='Auvergne' -), -lr_ra as ( -select --- bs.cd_nom - bs.cd_ref - , bs.code_statut --- , bs.label_statut - , null::text as lrra_nich - , null::text as lrra_hiv - , null::text as lrra_migr -FROM taxonomie.bdc_statut bs -where bs.cd_type_statut='LRR' and bs.lb_adm_tr='Rhône-Alpes' -union - select cd_ref - , lrra -/* , case when lrra_nich='CR' then 'En danger critique' - when lrra_nich='EN' then 'En danger' - when lrra_nich='VU' then 'Vulnérable' - when lrra_nich='NT' then 'Quasi menacée' - when lrra_nich='DD' then 'Données insuffisantes' - when lrra_nich='LC' then 'Préoccupation mineure' - else null end label_statut*/ - , lrra_nich - , lrra_hiv - , lrra_migr -from prep_lrra_ok -), -lr_aura as ( -select - bs.cd_ref - , bs.code_statut - , bs.label_statut -FROM taxonomie.bdc_statut bs -where bs.cd_type_statut='LRR' and bs.lb_adm_tr='Auvergne-Rhône-Alpes' -), -lr_fr as ( -select - bs.cd_ref - , bs.code_statut lr_france - , null::text as lr_fr_nich - , null::text as lr_fr_hiv - , null::text as lr_fr_migr -FROM taxonomie.bdc_statut bs - join taxonomie.taxref on bs.cd_nom =taxref.cd_nom - where bs.cd_type_statut='LRN' and bs.lb_adm_tr='France métropolitaine' and taxref.classe <>'Aves' -union -select - cd_ref, - lr_france, - lr_fr_nich, - lr_fr_hiv, - lr_fr_migr -from prep_lrf_ok -), -lr_euro as ( -select - bs.cd_ref - ,bs.cd_nom - , bs.code_statut - , bs.label_statut -FROM taxonomie.bdc_statut bs -where bs.cd_type_statut='LRE' -), -lr_monde as ( -select - bs.cd_ref - , bs.cd_nom - , bs.code_statut - , bs.label_statut -FROM taxonomie.bdc_statut bs -where bs.cd_type_statut ='LRM' -) -, -prot_nat as ( -select - bs.cd_ref - , string_agg(distinct split_part(label_statut,' : ',2),', ') article - , string_agg(distinct bs.code_statut,', ') code_statut - , string_agg(distinct bs.label_statut,', ') label_statut -FROM taxonomie.bdc_statut bs -where bs.cd_type_statut ='PN' and bs.lb_adm_tr='France métropolitaine' -group by cd_ref -) -, -n2k as ( -select - bs.cd_ref - , string_agg(distinct split_part(label_statut,' : ',2),', ') annexe -/* , bs.code_statut - , bs.label_statut */ -FROM taxonomie.bdc_statut bs -where bs.cd_type_statut in ('DH','DO') and bs.lb_adm_tr='France métropolitaine' -group by 1 -) -, -berne as ( -select - bs.cd_ref - , split_part(label_statut,' : ',2) annexe - , bs.code_statut - , bs.label_statut -FROM taxonomie.bdc_statut bs -where bs.cd_type_statut ='BERN' and bs.lb_adm_tr='France métropolitaine' -) -, -bonn as ( -select - bs.cd_ref - , string_agg(distinct split_part(label_statut,' : ',2),', ') annexe -/* , bs.code_statut - , bs.label_statut */ -FROM taxonomie.bdc_statut bs -where bs.cd_type_statut ='BONN' -group by cd_ref -) -, -pna_en_cours as ( -select - bs.cd_ref - , case when bs.code_statut ='true' then 'Oui' else null end statut - , bs.label_statut -FROM taxonomie.bdc_statut bs -where bs.cd_type_statut ='PNA' -) -, -pna_ex as ( -select - bs.cd_ref - , case when bs.code_statut ='true' then 'Oui' else null end statut - , bs.code_statut - , bs.label_statut -FROM taxonomie.bdc_statut bs -where bs.cd_type_statut ='exPNA' -) -, -sc38 as -(select tb.cdnom_taxref cd_ref, sc38_2015 -from lpo38_aat.tabesp1806 tb - left join taxonomie.mv_c_cor_vn_taxref ccvt on ccvt.cd_nom =tb.cdnom_taxref -where sc38_2015 is not null -) -select distinct - cor.groupe_taxo_fr, + SELECT DISTINCT row_number() OVER () AS id, + cor.groupe_taxo_fr, cor.vn_nom_fr, cor.vn_nom_sci, cor.cd_ref, - lr_auv.code_statut lr_auv, - lr_ra.code_statut lr_ra - ,lrra_nich - , lrra_hiv - , lrra_migr - , lr_aura.code_statut lr_aura - , lr_fr.lr_france - , lr_fr.lr_fr_nich - , lr_fr.lr_fr_hiv - , lr_fr.lr_fr_migr - , lr_euro.code_statut lr_euro - , lr_monde.code_statut lr_monde - , prot_nat.article prot_nat - , case when n2k.annexe in ('Annexe II, Annexe IV','Annexe IV, Annexe II') then 'Annexes II, IV' else n2k.annexe end n2k - , berne.annexe conv_berne - , bonn.annexe conv_bonn - , pna_en_cours.statut pna_en_cours - , pna_ex.statut pna_ex - ,sc38.sc38_2015 -from taxonomie.taxref t - left join (select * from taxonomie.mv_c_cor_vn_taxref mccvtd where vn_utilisation) cor on cor.cd_ref=t.cd_nom - left join lr_auv on lr_auv.cd_ref=cor.cd_ref - left join lr_ra on lr_ra.cd_ref=cor.cd_ref - left join lr_aura on lr_aura.cd_ref=cor.cd_ref - left join lr_fr on lr_fr.cd_ref=cor.cd_ref - left join lr_euro on lr_euro.cd_nom=cor.cd_ref - left join lr_monde on lr_monde.cd_nom=cor.cd_ref - left join prot_nat on prot_nat.cd_ref=cor.cd_ref - left join n2k on n2k.cd_ref=cor.cd_ref - left join berne on berne.cd_ref=cor.cd_ref - left join bonn on bonn.cd_ref=cor.cd_ref - left join pna_en_cours on pna_en_cours.cd_ref=cor.cd_ref - left join pna_ex on pna_ex.cd_ref=cor.cd_ref - left join sc38 on sc38.cd_ref=cor.cd_ref -where t.cd_nom =t.cd_ref - order by groupe_taxo_fr, vn_nom_fr - ); - - - -create index on taxonomie.mv_c_statut (groupe_taxo_fr); -create index on taxonomie.mv_c_statut (vn_nom_fr); -create index on taxonomie.mv_c_statut (vn_nom_sci); -create index on taxonomie.mv_c_statut (cd_ref); - - - - - - - - - - - - - - - - - - -select * from taxonomie.mv_c_cor_vn_taxref_dev mccvtd where vn_utilisation and cd_nom =65076; - - -select * from taxonomie.mv_statut ms where cd_ref =65076; -select * from taxonomie.mv_statut ms where vn_nom_sci ilike 'columbia liv%'; -select -tx_nom_sci -, vn_id -, count(vcod.*) -from taxonomie.mv_c_cor_vn_taxref_dev mccvtd -join src_lpodatas.v_c_observations_dev vcod on mccvtd.vn_id =vcod.source_id_sp -where vn_utilisation is false -group by 1,2; - -select * from taxonomie.mv_c_cor_vn_taxref_dev mccvtd where vn_nom_sci ilike 'mustela ni%'; -select * from taxonomie.mv_c_cor_vn_taxref_dev mccvtd where cd_ref = 61281; - - --- intégration de l'ensemble des tables sur bdc_statut - select distinct - * -FROM taxonomie.bdc_statut bs - join taxonomie.bdc_statut_text bst on (bst.cd_doc =bs.cd_doc and bst.cd_sig =bs.cd_sig ) - join taxonomie.bdc_statut_type bsty on bsty.cd_type_statut =bst.cd_type_statut - join taxonomie.bdc_statut_cor_text_values bsctv2 on bsctv2.id_text =bst.id_text - join taxonomie.bdc_statut_taxons bst2 on bst2.id_value_text =bsctv2.id_value_text and bst2.cd_nom =bs.cd_nom - join taxonomie.bdc_statut_values bsv on bsv.id_value =bsctv2.id_value and bsv.code_statut =bs.code_statut -where bst.cd_type_statut='LRN' and bst.lb_adm_tr='France métropolitaine' and bs.cd_ref =54265 /*and bs.cd_type_statut='ZDET' and bs.lb_adm_tr ilike '%rhôn%'*/ - - - --- contrôle de coérence - -select cd_ref, count(*) -from taxonomie.mv_statut ms -where lr_ra is not null or lr_auv is not null and vn_nom_fr is not null -group by 1 -having count(*)>1; - - - - --- bac à sable - -select * from taxonomie.mv_statut ms where cd_ref=61281 ; - - -select * -from lpo38_aat.tabesp1806 tb - left join taxonomie.mv_c_cor_vn_taxref_dev ccvt on ccvt.cd_nom =tb.cdnom_taxref --- left join taxonomie.taxref t on ccvt.cd_nom =t.cd_nom -where ccvt.cd_nom =699157 ; - -select * from taxonomie.mv_c_cor_vn_taxref_dev where cd_nom =699157; -select * from lpo38_aat.tabesp1806 t where id_species in (8640,15086); - - -select * from taxonomie.taxref t where cd_nom in (219768,608318); -select * from taxonomie.taxref t where lb_nom ilike 'phyllo%abietinus%'; -select * from taxonomie.bdc_statut_type; -select * from taxonomie.bdc_statut_text bst ; -select * from taxonomie.bdc_statut_values bsv ; -select * from taxonomie.bdc_statut_type; -select * from taxonomie.bdc_statut where lb_adm_tr ilike '%rh%ne-alpes'; -select distinct lb_adm_tr from taxonomie.bdc_statut where cd_type_statut ='PN'; -select * from taxonomie.bdc_statut where cd_nom =2489 and lb_adm_tr ilike 'auvergne'; -select * from taxonomie.bdc_statut where cd_nom =2489 and lb_adm_tr ilike 'france'; -select * from taxonomie.bdc_statut_values where code_statut ='NO3' -select * from taxonomie.taxref t where nom_vern ilike '%barge à que%' -select * from taxonomie.taxref t where cd_nom =2492; -select * from taxonomie.taxref t where nom_vern ilike '%héron g%'; -select * from taxonomie.mv_statut ms where vn_nom_sci ilike 'boloria%'; - -select - bs.cd_ref - , bs.code_statut - , bs.label_statut -FROM taxonomie.bdc_statut bs -where bs.cd_type_statut ='LRM' and cd_nom =69182 - -select * from taxonomie.mv_c_cor_vn_taxref_dev mccvtd where vn_utilisation and cd_ref =69182; -select * from taxonomie.mv_statut ms where cd_ref =69182; - - --- -with -lr_monde as ( -select - bs.cd_nom - , bs.code_statut - , bs.label_statut -FROM taxonomie.bdc_statut bs -where bs.cd_type_statut ='LRM' -) -select distinct -/* cor.groupe_taxo_fr, - cor.vn_nom_fr, - cor.vn_nom_sci, - cor.cd_ref - , lr_monde.* */ - lr_monde.* -from taxonomie.taxref t - /*left join (SELECT cor.vn_id, t.cd_ref AS cd_ref - FROM taxonomie.mv_c_cor_vn_taxref_dev cor - LEFT JOIN taxonomie.taxref t ON cor.cd_ref = t.cd_nom) cor ON t.cd_nom =cor.cd_ref*/ - left join (select * from taxonomie.mv_c_cor_vn_taxref_dev mccvtd where vn_utilisation) cor on cor.cd_nom=t.cd_nom - left join lr_monde on lr_monde.cd_nom=cor.cd_ref -where t.cd_nom =t.cd_ref and t.cd_nom =69182 - --order by groupe_taxo_fr, vn_nom_fr -; - - + string_agg(DISTINCT lr_auv.code_statut::text, ', '::text) AS lr_auv, + lr_ra.code_statut AS lr_ra, + lr_ra.lrra_nich, + lr_ra.lrra_hiv, + lr_ra.lrra_migr, + lr_aura.code_statut AS lr_aura, + string_agg(DISTINCT lr_fr.lr_france::text, ', '::text) AS lr_france, + lr_fr.lr_fr_nich, + lr_fr.lr_fr_hiv, + lr_fr.lr_fr_migr, + lr_euro.code_statut AS lr_euro, + lr_monde.code_statut AS lr_monde, + string_agg(DISTINCT 'Article '::text || prot_nat.article, ', '::text) AS prot_nat, + CASE + WHEN n2k.annexe = ANY (ARRAY['Annexe II, Annexe IV'::text, 'Annexe IV, Annexe II'::text]) THEN 'Annexes II, IV'::text + ELSE n2k.annexe + END AS n2k, + berne.annexe AS conv_berne, + bonn.annexe AS conv_bonn, + pna_en_cours.statut AS pna_en_cours, + pna_ex.statut AS pna_ex, + sc38.sc38_2015 + FROM taxonomie.taxref t + LEFT JOIN taxonomie.mv_c_cor_vn_taxref_bkp cor ON cor.cd_ref = t.cd_nom + LEFT JOIN lr_auv ON lr_auv.cd_ref = cor.cd_ref + LEFT JOIN lr_ra ON lr_ra.cd_ref = cor.cd_ref + LEFT JOIN lr_aura ON lr_aura.cd_ref = cor.cd_ref + LEFT JOIN lr_fr ON lr_fr.cd_ref = cor.cd_ref + LEFT JOIN lr_euro ON lr_euro.cd_nom = cor.cd_ref + LEFT JOIN lr_monde ON lr_monde.cd_nom = cor.cd_ref + LEFT JOIN prot_nat ON prot_nat.cd_ref = cor.cd_ref + LEFT JOIN n2k ON n2k.cd_ref = cor.cd_ref + LEFT JOIN berne ON berne.cd_ref = cor.cd_ref + LEFT JOIN bonn ON bonn.cd_ref = cor.cd_ref + LEFT JOIN pna_en_cours ON pna_en_cours.cd_ref = cor.cd_ref + LEFT JOIN pna_ex ON pna_ex.cd_ref = cor.cd_ref + LEFT JOIN sc38 ON sc38.cd_ref::integer = cor.cd_ref + WHERE t.cd_nom = t.cd_ref + GROUP BY cor.vn_nom_fr, cor.vn_nom_sci, cor.cd_ref, lr_ra.code_statut, lr_ra.lrra_nich, lr_ra.lrra_hiv, lr_ra.lrra_migr, lr_aura.code_statut, lr_fr.lr_fr_nich, lr_fr.lr_fr_hiv, lr_fr.lr_fr_migr, lr_euro.code_statut, lr_monde.code_statut, n2k.annexe, berne.annexe, bonn.annexe, pna_en_cours.statut, pna_ex.statut, sc38.sc38_2015, cor.groupe_taxo_fr + ORDER BY cor.groupe_taxo_fr, cor.vn_nom_fr +WITH DATA; + +-- View indexes: +CREATE INDEX mv_c_statut_cd_ref_idx ON taxonomie.mv_c_statut USING btree (cd_ref); -select - * -FROM taxonomie.bdc_statut bs -where bs.cd_type_statut ='LRM' and cd_ref =69182 diff --git a/config/v_c_observations.sql b/config/v_c_observations.sql index 0edd0e5..6393764 100644 --- a/config/v_c_observations.sql +++ b/config/v_c_observations.sql @@ -8,68 +8,260 @@ -- src_lpodatas.v_c_observations source -drop view if exists src_lpodatas.v_c_observations; -CREATE OR REPLACE VIEW src_lpodatas.v_c_observations -AS SELECT s.id_synthese, - s.unique_id_sinp AS uuid, - ts.name_source AS source, - ts.desc_source, - s.entity_source_pk_value AS source_id_data, - se.id_sp_source AS source_id_sp, - s.cd_nom AS taxref_cdnom, - s.cd_nom, - t.cd_ref, - se.taxo_group AS groupe_taxo, - t.group1_inpn, - t.group2_inpn, - se.taxo_real AS taxon_vrai, - cor.vn_nom_fr AS nom_vern, - t.lb_nom AS nom_sci, - s.observers AS observateur, - se.pseudo_observer_uid, - se.bird_breed_code AS oiso_code_nidif, - se.breed_status AS statut_repro, - se.bat_breed_colo AS cs_colo_repro, - se.bat_is_gite AS cs_is_gite, - se.bat_period AS cs_periode, - s.count_max AS nombre_total, - se.estimation_code AS code_estimation, - s.date_min AS date, - s.date_min::date AS date_jour, - s.date_min::time AS heure, - EXTRACT(year FROM s.date_min)::integer AS date_an, - s.altitude_max AS altitude, - se.mortality AS mortalite, - se.mortality_cause AS mortalite_cause, - s.the_geom_local AS geom, - se.export_excluded AS exp_excl, - se.project_code AS code_etude, - s.comment_description AS comment, - se.private_comment AS comment_priv, - fj.item ->> 'comment'::text AS comment_forms, - se.juridical_person AS pers_morale, - se.behaviour::text AS comportement, - se.geo_accuracy AS "precision", - se.details::text AS details, - se.place, - se.id_form AS id_formulaire, - s.meta_update_date AS derniere_maj, - s.id_nomenclature_valid_status = ANY (ARRAY[ref_nomenclatures.get_id_nomenclature('STATUT_VALID'::character varying, '2'::character varying), ref_nomenclatures.get_id_nomenclature('STATUT_VALID'::character varying, '1'::character varying)]) AS is_valid, - se.is_hidden AS donnee_cachee, - s.id_nomenclature_observation_status = ref_nomenclatures.get_id_nomenclature('STATUT_OBS'::character varying, 'Pr'::character varying) AS is_present, - s.reference_biblio, - st_asewkt(s.the_geom_local) AS geom_ekt - FROM gn_synthese.synthese s - LEFT JOIN src_lpodatas.t_c_synthese_extended se ON s.id_synthese = se.id_synthese - JOIN gn_synthese.t_sources ts ON s.id_source = ts.id_source - JOIN taxonomie.taxref t ON s.cd_nom = t.cd_nom - LEFT JOIN src_vn_json.forms_json fj ON (fj.item ->> 'id_form_universal'::text) = se.id_form::text AND fj.site::text = ts.name_source::text - LEFT JOIN taxonomie.mv_c_cor_vn_taxref cor ON cor.cd_nom = s.cd_nom; +CREATE MATERIALIZED VIEW taxonomie.mv_c_statut +TABLESPACE pg_default +AS WITH prep_lrra AS ( + SELECT DISTINCT tx.classe, + sp.id_redlist, + sp.status_order, + tx.cd_ref, + sp.category, + sp.criteria, + sp.id_source + FROM taxonomie.t_c_redlist sp + LEFT JOIN taxonomie.taxref tx ON sp.cd_nom = tx.cd_nom + JOIN taxonomie.bib_c_redlist_source art ON sp.id_source = art.id_source + WHERE (tx.classe::text = 'Aves'::text OR tx.classe::text = 'Mammalia'::text AND tx.ordre::text <> 'Chiroptera'::text) AND art.area_name::text = 'Rhône-Alpes'::text + ), prep_statut_lrra AS ( + SELECT DISTINCT sp.cd_ref, + CASE + WHEN sp.classe::text !~~* 'Aves'::text AND (sp.id_source <> ALL (ARRAY[18, 19, 20])) THEN sp.category + WHEN sp.classe::text = 'Aves'::text AND sp.id_source = 18 THEN sp.category + WHEN sp.classe::text = 'Aves'::text AND sp.id_source = 19 THEN (sp.category::text || 'w'::text)::character varying + WHEN sp.classe::text = 'Aves'::text AND sp.id_source = 20 THEN (sp.category::text || 'm'::text)::character varying + ELSE NULL::character varying + END AS lrra, + CASE + WHEN sp.id_source = 18 THEN sp.category + ELSE NULL::character varying + END AS lrra_nich, + CASE + WHEN sp.id_source = 19 THEN sp.category + ELSE NULL::character varying + END AS lrra_hiv, + CASE + WHEN sp.id_source = 20 THEN sp.category + ELSE NULL::character varying + END AS lrra_migr + FROM prep_lrra sp + ), prep_lrra_ok AS ( + SELECT prep_statut_lrra.cd_ref, + string_agg(DISTINCT prep_statut_lrra.lrra::text, ', '::text) AS lrra, + string_agg(DISTINCT prep_statut_lrra.lrra_nich::text, ', '::text) AS lrra_nich, + string_agg(DISTINCT prep_statut_lrra.lrra_hiv::text, ', '::text) AS lrra_hiv, + string_agg(DISTINCT prep_statut_lrra.lrra_migr::text, ', '::text) AS lrra_migr + FROM prep_statut_lrra + GROUP BY prep_statut_lrra.cd_ref + ), prep_t_redlist_fr AS ( + SELECT DISTINCT sp.id_redlist, + sp.status_order, + tx.cd_ref, + sp.category, + sp.criteria, + sp.id_source, + ctx.groupe_taxo_fr, + ctx.vn_nom_fr, + ctx.vn_nom_sci + FROM taxonomie.t_c_redlist sp + JOIN taxonomie.taxref tx ON sp.cd_nom = tx.cd_nom + JOIN taxonomie.mv_c_cor_vn_taxref_bkp ctx ON sp.cd_ref = ctx.cd_ref + WHERE ctx.groupe_taxo_fr = 'Oiseaux'::text + ), prep2 AS ( + SELECT DISTINCT ptlr.cd_ref, + ptlr.groupe_taxo_fr, + ptlr.vn_nom_fr, + ptlr.vn_nom_sci, + CASE + WHEN ptlr.groupe_taxo_fr ~~* 'Oiseaux'::text AND ptlr.id_source = 5 THEN ptlr.category + WHEN ptlr.groupe_taxo_fr ~~* 'Oiseaux'::text AND ptlr.id_source = 4 THEN (ptlr.category::text || 'w'::text)::character varying + WHEN ptlr.groupe_taxo_fr ~~* 'Oiseaux'::text AND ptlr.id_source = 3 THEN (ptlr.category::text || 'm'::text)::character varying + ELSE NULL::character varying + END AS lr_france, + CASE + WHEN ptlr.id_source = 5 THEN ptlr.category + ELSE NULL::character varying + END AS lr_fr_nich, + CASE + WHEN ptlr.id_source = 4 THEN ptlr.category + ELSE NULL::character varying + END AS lr_fr_hiv, + CASE + WHEN ptlr.id_source = 3 THEN ptlr.category + ELSE NULL::character varying + END AS lr_fr_migr + FROM prep_t_redlist_fr ptlr + LEFT JOIN taxonomie.taxref tr ON ptlr.cd_ref = tr.cd_nom + LEFT JOIN taxonomie.bib_c_redlist_source art ON ptlr.id_source = art.id_source + ), prep_lrf_ok AS ( + SELECT prep2.cd_ref, + prep2.groupe_taxo_fr, + prep2.vn_nom_fr, + prep2.vn_nom_sci, + string_agg(DISTINCT prep2.lr_france::text, ', '::text) AS lr_france, + string_agg(DISTINCT prep2.lr_fr_nich::text, ', '::text) AS lr_fr_nich, + string_agg(DISTINCT prep2.lr_fr_hiv::text, ', '::text) AS lr_fr_hiv, + string_agg(DISTINCT prep2.lr_fr_migr::text, ', '::text) AS lr_fr_migr + FROM prep2 + GROUP BY prep2.groupe_taxo_fr, prep2.vn_nom_fr, prep2.vn_nom_sci, prep2.cd_ref + ), lr_auv AS ( + SELECT bs.cd_ref, + bs.code_statut, + bs.label_statut + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'LRR'::text AND bs.lb_adm_tr::text = 'Auvergne'::text + ), lr_ra AS ( + SELECT bs.cd_ref, + bs.code_statut, + NULL::text AS lrra_nich, + NULL::text AS lrra_hiv, + NULL::text AS lrra_migr + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'LRR'::text AND bs.lb_adm_tr::text = 'Rhône-Alpes'::text + UNION + SELECT prep_lrra_ok.cd_ref, + prep_lrra_ok.lrra, + prep_lrra_ok.lrra_nich, + prep_lrra_ok.lrra_hiv, + prep_lrra_ok.lrra_migr + FROM prep_lrra_ok + ), lr_aura AS ( + SELECT bs.cd_ref, + bs.code_statut, + bs.label_statut + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'LRR'::text AND bs.lb_adm_tr::text = 'Auvergne-Rhône-Alpes'::text + ), lr_fr AS ( + SELECT bs.cd_ref, + bs.code_statut AS lr_france, + NULL::text AS lr_fr_nich, + NULL::text AS lr_fr_hiv, + NULL::text AS lr_fr_migr + FROM taxonomie.bdc_statut bs + JOIN taxonomie.taxref ON bs.cd_nom = taxref.cd_nom + WHERE bs.cd_type_statut::text = 'LRN'::text AND bs.lb_adm_tr::text = 'France métropolitaine'::text AND (taxref.classe IS NULL OR taxref.classe::text <> 'Aves'::text) + UNION + SELECT prep_lrf_ok.cd_ref, + prep_lrf_ok.lr_france, + prep_lrf_ok.lr_fr_nich, + prep_lrf_ok.lr_fr_hiv, + prep_lrf_ok.lr_fr_migr + FROM prep_lrf_ok + ), lr_euro AS ( + SELECT bs.cd_ref, + bs.cd_nom, + bs.code_statut, + bs.label_statut + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'LRE'::text + ), lr_monde AS ( + SELECT bs.cd_ref, + bs.cd_nom, + bs.code_statut, + bs.label_statut + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'LRM'::text + ), prot_nat AS ( + SELECT bs.cd_ref, + CASE + WHEN bs.code_statut::text ~~* 'FRAR%'::text THEN string_agg(DISTINCT split_part(bs.code_statut::text, 'FRAR'::text, 2), ', '::text) + ELSE string_agg(DISTINCT split_part(bs.label_statut::text, ' : '::text, 2), ', '::text) + END AS article, + string_agg(DISTINCT bs.code_statut::text, ', '::text) AS code_statut, + string_agg(DISTINCT bs.label_statut::text, ', '::text) AS label_statut + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'PN'::text AND bs.lb_adm_tr::text = 'France métropolitaine'::text + GROUP BY bs.cd_ref, bs.code_statut + ), n2k AS ( + SELECT bs.cd_ref, + string_agg(DISTINCT split_part(bs.label_statut::text, ' : '::text, 2), ', '::text) AS annexe + FROM taxonomie.bdc_statut bs + WHERE (bs.cd_type_statut::text = ANY (ARRAY['DH'::character varying::text, 'DO'::character varying::text])) AND bs.lb_adm_tr::text = 'France métropolitaine'::text + GROUP BY bs.cd_ref + ), berne AS ( + SELECT bs.cd_ref, + split_part(bs.label_statut::text, ' : '::text, 2) AS annexe, + bs.code_statut, + bs.label_statut + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'BERN'::text AND bs.lb_adm_tr::text = 'France métropolitaine'::text + ), bonn AS ( + SELECT bs.cd_ref, + string_agg(DISTINCT split_part(bs.label_statut::text, ' : '::text, 2), ', '::text) AS annexe + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'BONN'::text + GROUP BY bs.cd_ref + ), pna_en_cours AS ( + SELECT bs.cd_ref, + CASE + WHEN bs.code_statut::text = 'true'::text THEN 'Oui'::text + ELSE NULL::text + END AS statut, + bs.label_statut + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'PNA'::text + ), pna_ex AS ( + SELECT bs.cd_ref, + CASE + WHEN bs.code_statut::text = 'true'::text THEN 'Oui'::text + ELSE NULL::text + END AS statut, + bs.code_statut, + bs.label_statut + FROM taxonomie.bdc_statut bs + WHERE bs.cd_type_statut::text = 'exPNA'::text + ), sc38 AS ( + SELECT tb.cdnom_taxref AS cd_ref, + tb.sc38_2015 + FROM partage.lpo38_tabesp1806 tb + LEFT JOIN taxonomie.mv_c_cor_vn_taxref_bkp ccvt ON ccvt.cd_nom = tb.cdnom_taxref::integer + WHERE tb.sc38_2015 IS NOT NULL + ) + SELECT DISTINCT row_number() OVER () AS id, + cor.groupe_taxo_fr, + cor.vn_nom_fr, + cor.vn_nom_sci, + cor.cd_ref, + string_agg(DISTINCT lr_auv.code_statut::text, ', '::text) AS lr_auv, + lr_ra.code_statut AS lr_ra, + lr_ra.lrra_nich, + lr_ra.lrra_hiv, + lr_ra.lrra_migr, + lr_aura.code_statut AS lr_aura, + string_agg(DISTINCT lr_fr.lr_france::text, ', '::text) AS lr_france, + lr_fr.lr_fr_nich, + lr_fr.lr_fr_hiv, + lr_fr.lr_fr_migr, + lr_euro.code_statut AS lr_euro, + lr_monde.code_statut AS lr_monde, + string_agg(DISTINCT 'Article '::text || prot_nat.article, ', '::text) AS prot_nat, + CASE + WHEN n2k.annexe = ANY (ARRAY['Annexe II, Annexe IV'::text, 'Annexe IV, Annexe II'::text]) THEN 'Annexes II, IV'::text + ELSE n2k.annexe + END AS n2k, + berne.annexe AS conv_berne, + bonn.annexe AS conv_bonn, + pna_en_cours.statut AS pna_en_cours, + pna_ex.statut AS pna_ex, + sc38.sc38_2015 + FROM taxonomie.taxref t + LEFT JOIN taxonomie.mv_c_cor_vn_taxref_bkp cor ON cor.cd_ref = t.cd_nom + LEFT JOIN lr_auv ON lr_auv.cd_ref = cor.cd_ref + LEFT JOIN lr_ra ON lr_ra.cd_ref = cor.cd_ref + LEFT JOIN lr_aura ON lr_aura.cd_ref = cor.cd_ref + LEFT JOIN lr_fr ON lr_fr.cd_ref = cor.cd_ref + LEFT JOIN lr_euro ON lr_euro.cd_nom = cor.cd_ref + LEFT JOIN lr_monde ON lr_monde.cd_nom = cor.cd_ref + LEFT JOIN prot_nat ON prot_nat.cd_ref = cor.cd_ref + LEFT JOIN n2k ON n2k.cd_ref = cor.cd_ref + LEFT JOIN berne ON berne.cd_ref = cor.cd_ref + LEFT JOIN bonn ON bonn.cd_ref = cor.cd_ref + LEFT JOIN pna_en_cours ON pna_en_cours.cd_ref = cor.cd_ref + LEFT JOIN pna_ex ON pna_ex.cd_ref = cor.cd_ref + LEFT JOIN sc38 ON sc38.cd_ref::integer = cor.cd_ref + WHERE t.cd_nom = t.cd_ref + GROUP BY cor.vn_nom_fr, cor.vn_nom_sci, cor.cd_ref, lr_ra.code_statut, lr_ra.lrra_nich, lr_ra.lrra_hiv, lr_ra.lrra_migr, lr_aura.code_statut, lr_fr.lr_fr_nich, lr_fr.lr_fr_hiv, lr_fr.lr_fr_migr, lr_euro.code_statut, lr_monde.code_statut, n2k.annexe, berne.annexe, bonn.annexe, pna_en_cours.statut, pna_ex.statut, sc38.sc38_2015, cor.groupe_taxo_fr + ORDER BY cor.groupe_taxo_fr, cor.vn_nom_fr +WITH DATA; --- Permissions - -ALTER TABLE src_lpodatas.v_c_observations OWNER TO dbadmin; -GRANT ALL ON TABLE src_lpodatas.v_c_observations TO postgres; -GRANT ALL ON TABLE src_lpodatas.v_c_observations TO dbadmin; -GRANT SELECT ON TABLE src_lpodatas.v_c_observations TO dt; -GRANT ALL ON TABLE src_lpodatas.v_c_observations TO advanced_user; +-- View indexes: +CREATE INDEX mv_c_statut_cd_ref_idx ON taxonomie.mv_c_statut USING btree (cd_ref); diff --git a/config/v_c_observations_light.sql b/config/v_c_observations_light.sql index 729169d..4647b84 100644 --- a/config/v_c_observations_light.sql +++ b/config/v_c_observations_light.sql @@ -7,17 +7,17 @@ AS SELECT s.id_synthese, ts.desc_source, s.entity_source_pk_value AS source_id_data, se.id_sp_source AS source_id_sp, - s.cd_nom AS taxref_cdnom, s.cd_nom, cor.cd_ref, - se.taxo_group AS groupe_taxo, - cor.tx_group1_inpn AS group1_inpn, - cor.tx_group2_inpn AS group2_inpn, - cor.tx_id_rang AS id_rang, - cor.tx_classe as classe, + cor.vn_id, + cor.groupe_taxo_fr::character varying(50) AS groupe_taxo, + cor.tx_group1_inpn::character varying(255) AS group1_inpn, + cor.tx_group2_inpn::character varying(255) AS group2_inpn, + cor.tx_classe::character varying(50) AS classe, + cor.tx_id_rang::character varying(10) AS id_rang, se.taxo_real AS taxon_vrai, - COALESCE(cor.vn_nom_fr, cor.tx_nom_fr::text) AS nom_vern, - COALESCE(cor.vn_nom_sci, cor.tx_nom_sci::text) AS nom_sci, + COALESCE(cor.vn_nom_fr, cor.tx_nom_fr) AS nom_vern, + COALESCE(cor.vn_nom_sci, cor.tx_nom_sci) AS nom_sci, s.observers AS observateur, se.pseudo_observer_uid, se.bird_breed_code AS oiso_code_nidif, @@ -55,4 +55,5 @@ AS SELECT s.id_synthese, FROM gn_synthese.synthese s LEFT JOIN src_lpodatas.t_c_synthese_extended se ON s.id_synthese = se.id_synthese JOIN gn_synthese.t_sources ts ON s.id_source = ts.id_source - LEFT JOIN taxonomie.mv_c_cor_vn_taxref cor ON cor.cd_nom = s.cd_nom AND cor.cd_nom IS NOT NULL; + LEFT JOIN taxonomie.taxref t ON s.cd_nom = t.cd_nom + LEFT JOIN taxonomie.mv_c_cor_vn_taxref cor ON cor.cd_nom = t.cd_ref AND cor.cd_nom IS NOT NULL;