add rb, instrument, urba, actions, commune, departement, inventaire
This commit is contained in:
parent
70b17f9495
commit
04554a071a
@ -7,21 +7,21 @@ CREATE VIEW gn_exports.v_synthese_zones_humides AS
|
|||||||
with habitats as (
|
with habitats as (
|
||||||
SELECT
|
SELECT
|
||||||
zh_uuid,
|
zh_uuid,
|
||||||
array_agg(lb_code) AS habitats
|
json_agg(lb_code) AS habitats
|
||||||
FROM pr_zh.t_zh
|
FROM pr_zh.t_zh
|
||||||
LEFT JOIN pr_zh.cor_zh_cb USING (id_zh)
|
LEFT JOIN pr_zh.cor_zh_cb USING (id_zh)
|
||||||
group by 1 order by 1
|
group by 1 order by 1
|
||||||
), crit_delim as (
|
), crit_delim as (
|
||||||
SELECT
|
SELECT
|
||||||
zh_uuid,
|
zh_uuid,
|
||||||
array_agg(ref_nomenclatures.get_nomenclature_label(cor_lim_list.id_lim)) AS crit_delim
|
json_agg(ref_nomenclatures.get_nomenclature_label(cor_lim_list.id_lim)) AS crit_delim
|
||||||
FROM pr_zh.t_zh
|
FROM pr_zh.t_zh
|
||||||
LEFT JOIN pr_zh.cor_lim_list USING (id_lim_list)
|
LEFT JOIN pr_zh.cor_lim_list USING (id_lim_list)
|
||||||
group by 1 order by 1
|
group by 1 order by 1
|
||||||
), esp_fs as (
|
), esp_fs as (
|
||||||
SELECT
|
SELECT
|
||||||
zh_uuid,
|
zh_uuid,
|
||||||
array_agg(ref_nomenclatures.get_nomenclature_label(cor_zh_lim_fs.id_lim_fs)) AS crit_esp_fs
|
json_agg(ref_nomenclatures.get_nomenclature_label(cor_zh_lim_fs.id_lim_fs)) AS crit_esp_fs
|
||||||
FROM pr_zh.t_zh
|
FROM pr_zh.t_zh
|
||||||
LEFT JOIN pr_zh.cor_zh_lim_fs USING (id_zh)
|
LEFT JOIN pr_zh.cor_zh_lim_fs USING (id_zh)
|
||||||
group by 1 order by 1
|
group by 1 order by 1
|
||||||
@ -29,7 +29,7 @@ with habitats as (
|
|||||||
WITH v_activity AS (
|
WITH v_activity AS (
|
||||||
SELECT
|
SELECT
|
||||||
id_zh,
|
id_zh,
|
||||||
array_agg(ref_nomenclatures.get_nomenclature_label(cor_impact_types.id_impact)) impacts
|
json_agg(ref_nomenclatures.get_nomenclature_label(cor_impact_types.id_impact)) impacts
|
||||||
FROM pr_zh.t_activity
|
FROM pr_zh.t_activity
|
||||||
LEFT JOIN pr_zh.cor_impact_list USING (id_impact_list)
|
LEFT JOIN pr_zh.cor_impact_list USING (id_impact_list)
|
||||||
LEFT JOIN pr_zh.cor_impact_types USING (id_cor_impact_types)
|
LEFT JOIN pr_zh.cor_impact_types USING (id_cor_impact_types)
|
||||||
@ -165,6 +165,83 @@ with habitats as (
|
|||||||
--count(vm_invertebrates.cd_nom) nb_invertebrates
|
--count(vm_invertebrates.cd_nom) nb_invertebrates
|
||||||
FROM pr_zh.t_zh t
|
FROM pr_zh.t_zh t
|
||||||
--GROUP BY zh_uuid
|
--GROUP BY zh_uuid
|
||||||
|
), rb as (
|
||||||
|
SELECT
|
||||||
|
id_zh,
|
||||||
|
json_agg(name) river_bassin
|
||||||
|
FROM pr_zh.cor_zh_rb
|
||||||
|
JOIN pr_zh.t_river_basin USING (id_rb)
|
||||||
|
GROUP BY id_zh
|
||||||
|
), instrument as (
|
||||||
|
SELECT
|
||||||
|
id_zh,
|
||||||
|
json_agg(ref_nomenclatures.get_nomenclature_label(t_instruments.id_instrument)) instrument
|
||||||
|
FROM pr_zh.t_instruments
|
||||||
|
GROUP BY id_zh
|
||||||
|
), urba as (
|
||||||
|
WITH urban_type as (
|
||||||
|
SELECT
|
||||||
|
id_doc,
|
||||||
|
json_agg(json_build_object(
|
||||||
|
'typ_doc', ref_nomenclatures.get_nomenclature_label(cor_urban_type_range.id_doc_type),
|
||||||
|
'zone', ref_nomenclatures.get_nomenclature_label(cor_urban_type_range.id_range_type)
|
||||||
|
)) doc_range
|
||||||
|
FROM pr_zh.cor_zh_doc_range
|
||||||
|
JOIN pr_zh.cor_urban_type_range USING (id_cor)
|
||||||
|
GROUP BY id_doc
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
id_zh,
|
||||||
|
json_agg(json_build_object(
|
||||||
|
'typ_doc', ref_nomenclatures.get_nomenclature_label(t_urban_planning_docs.id_doc_type),
|
||||||
|
'doc_range', doc_range,
|
||||||
|
'zone', l_areas.area_name,
|
||||||
|
'remarque', t_urban_planning_docs.remark
|
||||||
|
)) docs_urba
|
||||||
|
FROM pr_zh.t_urban_planning_docs
|
||||||
|
JOIN ref_geo.l_areas USING (id_area)
|
||||||
|
JOIN urban_type USING (id_doc)
|
||||||
|
GROUP BY id_zh
|
||||||
|
), actions AS (
|
||||||
|
SELECT
|
||||||
|
id_zh,
|
||||||
|
json_agg(json_build_object(
|
||||||
|
'priorite', ref_nomenclatures.get_nomenclature_label(t_actions.id_priority_level),
|
||||||
|
'action', bib_actions.name,
|
||||||
|
'remarque', t_actions.remark
|
||||||
|
) ORDER BY id_priority_level,bib_actions.name) prio_actions
|
||||||
|
FROM pr_zh.t_actions
|
||||||
|
JOIN pr_zh.bib_actions USING (id_action)
|
||||||
|
GROUp BY id_zh
|
||||||
|
), zh_area_com AS (
|
||||||
|
SELECT
|
||||||
|
id_zh,
|
||||||
|
json_agg(l_areas.area_name||' ('||cover||'%%)' ORDER BY l_areas.area_name) commune
|
||||||
|
FROM pr_zh.cor_zh_area
|
||||||
|
JOIN ref_geo.l_areas USING (id_area)
|
||||||
|
WHERE cover IS NOT NULL
|
||||||
|
GROUP BY id_zh
|
||||||
|
), dep AS (
|
||||||
|
SELECT
|
||||||
|
id_zh,
|
||||||
|
json_agg(l_areas.area_name ORDER BY l_areas.area_name) departement
|
||||||
|
FROM pr_zh.cor_zh_area
|
||||||
|
JOIN ref_geo.l_areas USING (id_area)
|
||||||
|
join ref_geo.bib_areas_types bat using (id_type)
|
||||||
|
WHERE cover IS null and bat.type_code = 'DEP'
|
||||||
|
GROUP BY id_zh
|
||||||
|
), inventaire AS (
|
||||||
|
SELECT
|
||||||
|
id_zh,
|
||||||
|
json_agg(json_build_object(
|
||||||
|
'inventaire',l_areas.area_code ||' - '||l_areas.area_name,
|
||||||
|
'url', l_areas."source"
|
||||||
|
) ORDER BY l_areas.area_name) inventaire
|
||||||
|
FROM pr_zh.cor_zh_area
|
||||||
|
JOIN ref_geo.l_areas USING (id_area)
|
||||||
|
join ref_geo.bib_areas_types bat using (id_type)
|
||||||
|
WHERE cover IS null and bat.type_code not in ('DEP')
|
||||||
|
GROUP BY id_zh
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
zh_uuid,
|
zh_uuid,
|
||||||
@ -177,6 +254,9 @@ SELECT
|
|||||||
update_date updt_date,
|
update_date updt_date,
|
||||||
geom,
|
geom,
|
||||||
area surface,
|
area surface,
|
||||||
|
rb.river_bassin,
|
||||||
|
dep.departement,
|
||||||
|
zh_area_com.commune,
|
||||||
ref_nomenclatures.get_nomenclature_label(id_sdage) sdage,
|
ref_nomenclatures.get_nomenclature_label(id_sdage) sdage,
|
||||||
ref_nomenclatures.get_nomenclature_label(id_sage) sage,
|
ref_nomenclatures.get_nomenclature_label(id_sage) sage,
|
||||||
habitats.habitats,
|
habitats.habitats,
|
||||||
@ -212,7 +292,11 @@ SELECT
|
|||||||
--total_hab_cover,
|
--total_hab_cover,
|
||||||
especes.nb_flora nb_flora_sp,
|
especes.nb_flora nb_flora_sp,
|
||||||
especes.nb_vertebrates nb_vertebrate_sp,
|
especes.nb_vertebrates nb_vertebrate_sp,
|
||||||
especes.nb_invertebrates nb_invertebrate_sp
|
especes.nb_invertebrates nb_invertebrate_sp,
|
||||||
|
inventaire.inventaire,
|
||||||
|
actions.prio_actions,
|
||||||
|
instrument.instrument,
|
||||||
|
urba.docs_urba
|
||||||
--remark_is_other_inventory
|
--remark_is_other_inventory
|
||||||
FROM pr_zh.t_zh
|
FROM pr_zh.t_zh
|
||||||
JOIN utilisateurs.t_roles crea_role ON t_zh.create_author = crea_role.id_role
|
JOIN utilisateurs.t_roles crea_role ON t_zh.create_author = crea_role.id_role
|
||||||
@ -226,8 +310,15 @@ LEFT JOIN inflow USING (zh_uuid)
|
|||||||
LEFT JOIN outflow USING (zh_uuid)
|
LEFT JOIN outflow USING (zh_uuid)
|
||||||
LEFT JOIN functions USING (zh_uuid)
|
LEFT JOIN functions USING (zh_uuid)
|
||||||
LEFT JOIN especes USING (zh_uuid)
|
LEFT JOIN especes USING (zh_uuid)
|
||||||
|
LEFT JOIN rb USING (id_zh)
|
||||||
|
LEFT JOIN instrument USING (id_zh)
|
||||||
|
LEFT JOIN urba USING (id_zh)
|
||||||
|
LEFT JOIN actions USING (id_zh)
|
||||||
|
LEFT JOIN zh_area_com USING (id_zh)
|
||||||
|
LEFT JOIN dep USING (id_zh)
|
||||||
|
LEFT JOIN inventaire USING (id_zh)
|
||||||
--group BY zh_uuid
|
--group BY zh_uuid
|
||||||
WHERE code not like '38CENIS%'
|
WHERE code not like '38CENIS%%'
|
||||||
order by code
|
order by code
|
||||||
;
|
;
|
||||||
'''
|
'''
|
||||||
|
|||||||
Loading…
x
Reference in New Issue
Block a user