view zh v2

This commit is contained in:
Colas Geier 2024-02-26 15:32:02 +01:00
parent bfcc86a5a7
commit 9543915c73

View File

@ -1,27 +1,10 @@
#!/usr/bin/env python3 #!/usr/bin/env python3
# -*- coding: UTF-8 -*-. # -*- coding: UTF-8 -*-.
from sqlalchemy import create_engine, text from sqlalchemy import text
from sqlalchemy.engine import URL
from datetime import datetime as dt from datetime import datetime as dt
import pandas as pd
import geopandas as gpd import geopandas as gpd
from pycen import con
# Parametres bdd
user = 'cen_admin'
pwd = '#CEN38@venir'
adr = '91.134.194.221'
port = '5432'
base = 'azalee'
url = URL.create('postgresql+psycopg2',
username=user,
password=pwd,
host=adr,
database=base,
)
con = create_engine(url)
drop_v_zh = 'DROP VIEW IF EXISTS zones_humides.v_zoneshumides CASCADE;' drop_v_zh = 'DROP VIEW IF EXISTS zones_humides.v_zoneshumides CASCADE;'
with con.begin() as cnx: with con.begin() as cnx:
@ -216,7 +199,7 @@ SELECT DISTINCT ON (id_site)
int_patri, int_patri,
"val_socioEco" "val_socioEco"
FROM crosstab( FROM crosstab(
$$WITH auteur AS ( $$ WITH auteur AS (
SELECT DISTINCT ON (id_sitefct) SELECT DISTINCT ON (id_sitefct)
c.id_sitefct, c.id_sitefct,
string_agg(c1.auteur,';' ORDER BY c1.auteur) auteur string_agg(c1.auteur,';' ORDER BY c1.auteur) auteur
@ -224,26 +207,41 @@ FROM crosstab(
JOIN personnes.v_personne c1 ON c1.id = c.id_auteur JOIN personnes.v_personne c1 ON c1.id = c.id_auteur
GROUP BY c.id_sitefct GROUP BY c.id_sitefct
ORDER BY 1 ORDER BY 1
) ), tmp_select as (
SELECT SELECT
--a.id_geom_site::bigint, id_site,
id_site, (SELECT regexp_split_to_table(auth,',') FROM (values (string_agg(d.auteur,',' order by ROW()))) AS value(auth) Limit 1) auteur,
d.auteur, MAX(a.date) date,
MAX(a.date) date, c.nom_court type_param,
c.nom_court type_param, b.nom,
string_agg( string_agg(DISTINCT a.description,'\n') remark
CASE WHEN a.description IS NULL THEN b.nom FROM zones_humides.r_site_fctecosociopatri a
WHEN a.description = '' THEN b.nom JOIN (zones_humides.param_fct_eco_socio_patri b
ELSE CONCAT(b.nom,' (',a.description,')') END, JOIN zones_humides.type_param_fct c ON b.id_type = c.id
) ON a.id_fct = b.id
JOIN auteur d ON d.id_sitefct = a.id
WHERE a."valid"
GROUP BY a.id_site,c.nom_court,b.nom
ORDER BY a.id_site,c.nom_court DESC,b.nom
)
SELECT
id_site,
string_agg(
DISTINCT CASE WHEN extract(year from date)>'1'
THEN auteur||'-'|| extract(year from date)
ELSE auteur END,
'; ') auteur,
MAX(date) date,
type_param,
string_agg(distinct
CASE WHEN remark IS NULL THEN nom
WHEN remark = '' THEN nom
ELSE CONCAT(nom,' (',remark,')') END,
';') fct ';') fct
FROM zones_humides.r_site_fctecosociopatri a FROM tmp_select
JOIN (zones_humides.param_fct_eco_socio_patri b GROUP BY 1,4
JOIN zones_humides.type_param_fct c ON b.id_type = c.id ORDER BY 1,4,3;$$,
) ON a.id_fct = b.id
JOIN auteur d ON d.id_sitefct = a.id
WHERE a."valid"
GROUP BY a.id_site,d.auteur,c.nom_court
ORDER BY 1,4;$$,
$$SELECT DISTINCT nom_court FROM zones_humides.type_param_fct ORDER BY 1 ASC;$$ $$SELECT DISTINCT nom_court FROM zones_humides.type_param_fct ORDER BY 1 ASC;$$
) AS ct ( ) AS ct (
"id_site" text, "id_site" text,
@ -289,22 +287,26 @@ FROM crosstab(
SELECT SELECT
--a.id_geom_site::bigint, --a.id_geom_site::bigint,
id_site, id_site,
d.auteur, string_agg(
DISTINCT CASE WHEN extract(year from a.date)>'1'
THEN d.auteur||'-'|| extract(year from a.date)
ELSE d.auteur END,
'; ') auteur,
MAX(a.date) date, MAX(a.date) date,
c.nom_court type_param, c.nom_court type_param,
string_agg( string_agg( DISTINCT
CASE WHEN a.description IS NULL THEN b.nom CASE WHEN a.description IS NULL THEN b.nom
WHEN a.description = '' THEN b.nom WHEN a.description = '' THEN b.nom
ELSE CONCAT(b.nom,' (',a.description,')') END, ELSE CONCAT(b.nom,' (',a.description,')') END,
';') fct '; ') fct
FROM zones_humides.r_site_critdelim a FROM zones_humides.r_site_critdelim a
JOIN (zones_humides.param_delim_fct b JOIN (zones_humides.param_delim_fct b
JOIN zones_humides.type_param_delim_fct c ON b.id_type = c.id JOIN zones_humides.type_param_delim_fct c ON b.id_type = c.id
) ON a.id_crit_delim = b.id ) ON a.id_crit_delim = b.id
JOIN auteur d ON d.id_sitedelim = a.id JOIN auteur d ON d.id_sitedelim = a.id
WHERE a."valid" WHERE a."valid"
GROUP BY a.id_site,d.auteur,c.nom_court GROUP BY 1,4
ORDER BY 1,2,3$$, ORDER BY 3,1,2$$,
$$SELECT DISTINCT nom_court FROM zones_humides.type_param_delim_fct ORDER BY 1 DESC;$$ $$SELECT DISTINCT nom_court FROM zones_humides.type_param_delim_fct ORDER BY 1 DESC;$$
) AS ct ( ) AS ct (
"id_site" text, "id_site" text,
@ -583,7 +585,7 @@ with con.begin() as cnx:
test = """ test = """
SELECT * FROM zones_humides.v_zoneshumides; SELECT * FROM zones_humides.v_zoneshumides;
""" """
data = pd.read_sql_query( data = gpd.pd.read_sql_query(
sql = text(test), sql = text(test),
con = con) con = con)