from pycen import con_rho def indicI12_zh(con): sql = """ DROP TABLE IF EXISTS indicnew.indic_sig_zh; CREATE TABLE IF NOT EXISTS indicnew.indic_sig_zh AS ( SELECT DISTINCT zh.id_bdd, st_area2d(zh.geom)::double precision AS area FROM refgeo.zh ); ALTER TABLE indicnew.indic_sig_zh ADD CONSTRAINT indicnew_sig_zh_pkey PRIMARY KEY (id_bdd); ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS isole double precision; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS diffus double precision; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS groupe double precision; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS peudense double precision; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS dense double precision; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS tresdense double precision; --DROP TABLE IF EXISTS indicnew.indic_sig_zh_temp; CREATE TABLE IF NOT EXISTS indicnew.indic_sig_zh_temp AS ( SELECT zh.id_bdd, tache_urbaine.reclasse AS reclasse, Sum(st_area2d(st_intersection(tache_urbaine.geom, zh.geom)))::double precision AS reclasse_surf FROM tachenew.tache_urbaine JOIN refgeo.zh ON (st_intersects(tache_urbaine.geom, zh.geom)) GROUP BY zh.id_bdd, tache_urbaine.reclasse, zh.geom ); UPDATE indicnew.indic_sig_zh SET isole = (SELECT indic_sig_zh_temp.reclasse_surf FROM indicnew.indic_sig_zh_temp WHERE indic_sig_zh.id_bdd = indic_sig_zh_temp.id_bdd AND indic_sig_zh_temp.reclasse = '1- isolé'); UPDATE indicnew.indic_sig_zh SET diffus = (SELECT indic_sig_zh_temp.reclasse_surf FROM indicnew.indic_sig_zh_temp WHERE indic_sig_zh.id_bdd = indic_sig_zh_temp.id_bdd AND indic_sig_zh_temp.reclasse = '2- diffus'); UPDATE indicnew.indic_sig_zh SET groupe = (SELECT indic_sig_zh_temp.reclasse_surf FROM indicnew.indic_sig_zh_temp WHERE indic_sig_zh.id_bdd = indic_sig_zh_temp.id_bdd AND indic_sig_zh_temp.reclasse = '3- groupé'); UPDATE indicnew.indic_sig_zh SET peudense = (SELECT indic_sig_zh_temp.reclasse_surf FROM indicnew.indic_sig_zh_temp WHERE indic_sig_zh.id_bdd = indic_sig_zh_temp.id_bdd AND indic_sig_zh_temp.reclasse = '4- urbain peu dense'); UPDATE indicnew.indic_sig_zh SET dense = (SELECT indic_sig_zh_temp.reclasse_surf FROM indicnew.indic_sig_zh_temp WHERE indic_sig_zh.id_bdd = indic_sig_zh_temp.id_bdd AND indic_sig_zh_temp.reclasse = '5- urbain dense'); UPDATE indicnew.indic_sig_zh SET tresdense = (SELECT indic_sig_zh_temp.reclasse_surf FROM indicnew.indic_sig_zh_temp WHERE indic_sig_zh.id_bdd = indic_sig_zh_temp.id_bdd AND indic_sig_zh_temp.reclasse = '6- urbain très dense'); DROP TABLE IF EXISTS indicnew.indic_sig_zh_temp; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS bati_area double precision; WITH t2 AS ( SELECT t1.id_bdd, t1.surf FROM refgeo.zh JOIN ( SELECT zh.id_bdd, Sum(st_area2d(st_intersection(zh.geom, tache_urbaine.geom))) AS surf FROM refgeo.zh JOIN tachenew.tache_urbaine ON (st_intersects(zh.geom, tache_urbaine.geom)) GROUP BY id_bdd ) AS t1 USING (id_bdd) ) UPDATE indicnew.indic_sig_zh SET bati_area = t2.surf FROM t2 WHERE indic_sig_zh.id_bdd = t2.id_bdd; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS arvf_area double precision; WITH t2 AS ( SELECT t1.id_bdd, t1.surf FROM refgeo.zh JOIN ( SELECT zh.id_bdd, Sum(st_area2d(st_intersection(zh.geom, arvf_global_buffer.geom))) AS surf FROM refgeo.zh JOIN arvfnew.arvf_global_buffer ON (st_intersects(zh.geom, arvf_global_buffer.geom)) GROUP BY id_bdd ) AS t1 USING (id_bdd) ) UPDATE indicnew.indic_sig_zh SET arvf_area = t2.surf FROM t2 WHERE indic_sig_zh.id_bdd = t2.id_bdd; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS artif_area double precision; WITH t2 AS ( SELECT t1.id_bdd, t1.surf FROM refgeo.zh JOIN ( SELECT zh.id_bdd, Sum(st_area2d(st_intersection(zh.geom, tache_artif.geom))) AS surf FROM refgeo.zh JOIN tachenew.tache_artif ON (st_intersects(zh.geom, tache_artif.geom)) GROUP BY id_bdd ) AS t1 USING (id_bdd) ) UPDATE indicnew.indic_sig_zh SET artif_area = t2.surf FROM t2 WHERE indic_sig_zh.id_bdd = t2.id_bdd; """ with con.begin() as cnx: cnx.execute(sql) print('indicI12_zh created') def indicI12_zh_buff(con): sql = ''' ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS area_buff double precision; UPDATE indicnew.indic_sig_zh SET area_buff = st_area2d(zh.geom_buff) FROM refgeo.zh WHERE indic_sig_zh.id_bdd = zh.id_bdd; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS isole_buff double precision; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS diffus_buff double precision; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS groupe_buff double precision; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS peudense_buff double precision; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS dense_buff double precision; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS tresdense_buff double precision; --DROP TABLE IF EXISTS indicnew.indic_sig_zh_temp; CREATE TABLE IF NOT EXISTS indicnew.indic_sig_zh_temp AS ( SELECT zh.id_bdd, tache_urbaine.reclasse AS reclasse, Sum(st_area2d(st_Intersection(tache_urbaine.geom, zh.geom_buff)))::double precision AS reclasse_surf FROM tachenew.tache_urbaine JOIN refgeo.zh ON (st_intersects(tache_urbaine.geom, zh.geom_buff)) GROUP BY zh.id_bdd, tache_urbaine.reclasse, zh.geom_buff ); UPDATE indicnew.indic_sig_zh SET isole_buff = (SELECT indic_sig_zh_temp.reclasse_surf FROM indicnew.indic_sig_zh_temp WHERE indic_sig_zh.id_bdd = indic_sig_zh_temp.id_bdd AND indic_sig_zh_temp.reclasse = '1- isolé'); UPDATE indicnew.indic_sig_zh SET diffus_buff = (SELECT indic_sig_zh_temp.reclasse_surf FROM indicnew.indic_sig_zh_temp WHERE indic_sig_zh.id_bdd = indic_sig_zh_temp.id_bdd AND indic_sig_zh_temp.reclasse = '2- diffus'); UPDATE indicnew.indic_sig_zh SET groupe_buff = (SELECT indic_sig_zh_temp.reclasse_surf FROM indicnew.indic_sig_zh_temp WHERE indic_sig_zh.id_bdd = indic_sig_zh_temp.id_bdd AND indic_sig_zh_temp.reclasse = '3- groupé'); UPDATE indicnew.indic_sig_zh SET peudense_buff = (SELECT indic_sig_zh_temp.reclasse_surf FROM indicnew.indic_sig_zh_temp WHERE indic_sig_zh.id_bdd = indic_sig_zh_temp.id_bdd AND indic_sig_zh_temp.reclasse = '4- urbain peu dense'); UPDATE indicnew.indic_sig_zh SET dense_buff = (SELECT indic_sig_zh_temp.reclasse_surf FROM indicnew.indic_sig_zh_temp WHERE indic_sig_zh.id_bdd = indic_sig_zh_temp.id_bdd AND indic_sig_zh_temp.reclasse = '5- urbain dense'); UPDATE indicnew.indic_sig_zh SET tresdense_buff = (SELECT indic_sig_zh_temp.reclasse_surf FROM indicnew.indic_sig_zh_temp WHERE indic_sig_zh.id_bdd = indic_sig_zh_temp.id_bdd AND indic_sig_zh_temp.reclasse = '6- urbain très dense'); DROP TABLE IF EXISTS indicnew.indic_sig_zh_temp; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS bati_area_buff double precision; WITH t2 AS ( SELECT t1.id_bdd, t1.surf FROM refgeo.zh JOIN ( SELECT zh.id_bdd, Sum(st_area2d(st_Intersection(zh.geom_buff, tache_urbaine.geom))) AS surf FROM refgeo.zh JOIN tachenew.tache_urbaine ON (st_intersects(zh.geom_buff, tache_urbaine.geom)) GROUP BY id_bdd ) AS t1 USING (id_bdd) ) UPDATE indicnew.indic_sig_zh SET bati_area_buff = t2.surf FROM t2 WHERE indic_sig_zh.id_bdd = t2.id_bdd; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS arvf_area_buff double precision; WITH t2 AS ( SELECT t1.id_bdd, t1.surf FROM refgeo.zh JOIN ( SELECT zh.id_bdd, Sum(st_area2d(st_intersection(zh.geom_buff, arvf_global_buffer.geom))) AS surf FROM refgeo.zh JOIN arvfnew.arvf_global_buffer ON (st_intersects(zh.geom_buff, arvf_global_buffer.geom)) GROUP BY id_bdd ) AS t1 USING (id_bdd) ) UPDATE indicnew.indic_sig_zh SET arvf_area_buff = t2.surf FROM t2 WHERE indic_sig_zh.id_bdd = t2.id_bdd; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS artif_area_buff double precision; WITH t2 AS ( SELECT t1.id_bdd, t1.surf FROM refgeo.zh JOIN ( SELECT zh.id_bdd, Sum(st_area2d(st_intersection(zh.geom_buff, tache_artif.geom))) AS surf FROM refgeo.zh JOIN tachenew.tache_artif ON (st_intersects(zh.geom_buff, tache_artif.geom)) GROUP BY id_bdd ) AS t1 USING (id_bdd) ) UPDATE indicnew.indic_sig_zh SET artif_area_buff = t2.surf FROM t2 WHERE indic_sig_zh.id_bdd = t2.id_bdd; ''' with con.begin() as cnx: cnx.execute(sql) print('indicI12_zh_buff created') def indicI13_zh(con): sql = """ -- Pression agricole sur sites ALTER TABLE IF EXISTS indicnew.indic_sig_zh DROP COLUMN IF EXISTS agri_ign_impact_area; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN IF NOT EXISTS agri_ign_impact_area double precision; WITH calcul_impact_rpg AS ( SELECT ilots_sites.id_bdd, Sum(ilots_sites.surf_impact) AS surf_impact, Sum(ilots_sites.surf_impact) * 100 / ilots_sites.surf_site AS pourc_impact FROM ( SELECT t1.num_ilot, id_bdd, st_area(t2.geom) AS surf_site, st_area(st_intersection(t1.geom, t2.geom)) AS surf_inters, (st_area(st_intersection(t1.geom, t2.geom))) * t1.pourc_impact AS surf_impact, st_intersection(t1.geom, t2.geom) AS geom FROM rpgnew.rpg_global t1 JOIN refgeo.zh t2 ON (st_intersects(t1.geom, t2.geom)) ) AS ilots_sites GROUP BY ilots_sites.id_bdd, ilots_sites.surf_site ) UPDATE indicnew.indic_sig_zh SET agri_ign_impact_area = calcul_impact_rpg.surf_impact FROM calcul_impact_rpg WHERE indic_sig_zh.id_bdd = calcul_impact_rpg.id_bdd; -- Requête exécutée avec succès en 2 s 116 msec. """ with con.begin() as cnx: cnx.execute(sql) print('indicI13_zh created') def indicI13_zh_buff(con): sql = """ -- Pression agricole sur sites_buffer ALTER TABLE IF EXISTS indicnew.indic_sig_zh DROP COLUMN IF EXISTS agri_ign_impact_area_buff; ALTER TABLE indicnew.indic_sig_zh ADD COLUMN agri_ign_impact_area_buff double precision; WITH calcul_impact_rpg_buff AS ( SELECT ilots_sites.id_bdd, Sum(ilots_sites.surf_impact_buff) AS surf_impact_buff, Sum(ilots_sites.surf_impact_buff) * 100 / ilots_sites.surf_site_buff AS pourc_impact_buff FROM ( SELECT t1.num_ilot, t2.id_bdd, st_area(t2.geom_buff) AS surf_site_buff, st_area(st_intersection(t1.geom, t2.geom_buff)) AS surf_inters, (st_area(st_intersection(t1.geom, t2.geom_buff))) * t1.pourc_impact AS surf_impact_buff, st_intersection(t1.geom, t2.geom_buff) AS geom FROM rpgnew.rpg_global t1 JOIN refgeo.zh t2 ON (st_intersects(t1.geom, t2.geom_buff)) ) AS ilots_sites GROUP BY ilots_sites.id_bdd, ilots_sites.surf_site_buff ) UPDATE indicnew.indic_sig_zh SET agri_ign_impact_area_buff = calcul_impact_rpg_buff.surf_impact_buff FROM calcul_impact_rpg_buff WHERE indic_sig_zh.id_bdd = calcul_impact_rpg_buff.id_bdd; -- Requête exécutée avec succès en 4 s 843 msec. """ with con.begin() as cnx: cnx.execute(sql) print('indicI13_zh_buff created') def indicI13_bv(con): sql = """ -- Pression agricole sur BVMDO ALTER TABLE IF EXISTS indicnew.indic_sig_bvmdo DROP COLUMN IF EXISTS agri_ign_impact_area; ALTER TABLE indicnew.indic_sig_bvmdo ADD COLUMN agri_ign_impact_area double precision; WITH calcul_impact_rpg_bvmdo AS ( SELECT ilots_bvmdo.cmdo, Sum(ilots_bvmdo.surf_impact) AS surf_impact, Sum(ilots_bvmdo.surf_impact) * 100 / ilots_bvmdo.surf_bvmdo AS pourc_impact FROM ( SELECT t1.num_ilot, t2.cmdo, st_area(t2.geom) AS surf_bvmdo, st_area(st_intersection(t1.geom, t2.geom)) AS surf_inters, (st_area(st_intersection(t1.geom, t2.geom))) * t1.pourc_impact AS surf_impact, st_intersection(t1.geom, t2.geom) AS geom FROM rpgnew.rpg_global t1 JOIN refgeo.bvmdo t2 ON (st_intersects(t1.geom, t2.geom)) ) AS ilots_bvmdo GROUP BY ilots_bvmdo.cmdo, ilots_bvmdo.surf_bvmdo ) UPDATE indicnew.indic_sig_bvmdo SET agri_ign_impact_area = calcul_impact_rpg_bvmdo.surf_impact FROM calcul_impact_rpg_bvmdo WHERE indic_sig_bvmdo.cmdo = calcul_impact_rpg_bvmdo.cmdo; -- Requête exécutée avec succès en 6 s 414 msec. """ with con.begin() as cnx: cnx.execute(sql) print('indicI13_bv created') def create_zhGeom_buff(con): sql = """ ALTER TABLE refgeo.zh ADD COLUMN IF NOT EXISTS geom_buff geometry(MultiPolygon,2154); UPDATE refgeo.zh SET geom_buff = st_multi(st_difference(st_buffer(zh.geom, ( |/ (st_area(zh.geom)*2/pi()) ) - ( |/ (st_area(zh.geom)/pi()) ), 40), zh.geom)); """ with con.begin() as cnx: cnx.execute(sql) print('geom_buff created') def indicBilan(con): sql = """ DROP TABLE IF EXISTS indicnew.indic_bilan_zh; CREATE TABLE indicnew.indic_bilan_zh AS WITH t1 AS ( SELECT zh.id_bdd as id_bdd, Count(*) as nb_zone_hydro, Sum(indic_sig_bvmdo.area) as surf_zone_hydro, Sum(indic_sig_bvmdo.isole) as isole_zone_hydro, Sum(indic_sig_bvmdo.diffus) as diffus_zone_hydro, Sum(indic_sig_bvmdo.groupe) as groupe_zone_hydro, Sum(indic_sig_bvmdo.peudense) as peudense_zone_hydro, Sum(indic_sig_bvmdo.dense) as dense_zone_hydro, Sum(indic_sig_bvmdo.tresdense) as tresdense_zone_hydro, Sum(indic_sig_bvmdo.bati_area) as surf_zone_hydro_bati, Sum(indic_sig_bvmdo.arvf_area) as surf_zone_hydro_arvf, Sum(indic_sig_bvmdo.artif_area) as surf_zone_hydro_artif, Sum(indic_sig_bvmdo.agri_ign_impact_area) as surf_zone_hydro_agri FROM refgeo.zh JOIN refgeo.bvmdo ON (st_intersects(zh.geom, bvmdo.geom)) JOIN indicnew.indic_sig_bvmdo USING (cmdo) GROUP BY zh.id_bdd) SELECT id_bdd, coalesce(indic_sig_zh.area, 0) as surf_zh, coalesce(indic_sig_zh.area, 0) + coalesce(indic_sig_zh.area_buff, 0) as surf_rhomeo, CASE WHEN (coalesce(indic_sig_zh.bati_area, 0) + coalesce(indic_sig_zh.bati_area_buff, 0)) > 0 THEN (coalesce(indic_sig_zh.peudense, 0) + coalesce(indic_sig_zh.dense, 0) + coalesce(indic_sig_zh.tresdense, 0) + coalesce(indic_sig_zh.peudense_buff, 0) + coalesce(indic_sig_zh.dense_buff, 0) + coalesce(indic_sig_zh.tresdense_buff, 0)) / (coalesce(indic_sig_zh.bati_area, 0) + coalesce(indic_sig_zh.bati_area_buff, 0)) * 100 ELSE 0 END as presdirect_urba, (coalesce(indic_sig_zh.artif_area, 0) + coalesce(indic_sig_zh.artif_area_buff, 0)) / (coalesce(indic_sig_zh.area, 0) + coalesce(indic_sig_zh.area_buff, 0)) * 100 as presdirect_artif, (coalesce(indic_sig_zh.agri_ign_impact_area, 0) + coalesce(indic_sig_zh.agri_ign_impact_area_buff, 0)) / (indic_sig_zh.area + indic_sig_zh.area_buff) * 100 as presdirect_agri, CASE WHEN t1.surf_zone_hydro_bati > 0 THEN (coalesce(t1.peudense_zone_hydro, 0) + coalesce(t1.dense_zone_hydro, 0) + coalesce(t1.tresdense_zone_hydro, 0)) / t1.surf_zone_hydro_bati * 100 ELSE 0 END as presindir_urba, coalesce(t1.surf_zone_hydro_artif, 0) / t1.surf_zone_hydro * 100 as presindir_artif, coalesce(t1.surf_zone_hydro_agri, 0) / t1.surf_zone_hydro * 100 as presindir_agri, LEFT(current_timestamp(0)::text, 10) as date_maj FROM refgeo.zh INNER JOIN indicnew.indic_sig_zh USING (id_bdd) INNER JOIN t1 USING (id_bdd); ALTER TABLE indicnew.indic_bilan_zh DROP CONSTRAINT IF EXISTS indic_bilan_zh_pkey; ALTER TABLE indicnew.indic_bilan_zh ADD CONSTRAINT indic_bilan_zh_pkey PRIMARY KEY(id_bdd); """ with con.begin() as cnx: cnx.execute(sql) print('indicBilan created') if __name__ == '__main__': from pycen import con_rho create_zhGeom_buff(con_rho) indicI12_zh(con_rho) indicI12_zh_buff(con_rho) indicI13_zh(con_rho) indicI13_zh_buff(con_rho) indicBilan(con_rho)