856 lines
33 KiB
Python
856 lines
33 KiB
Python
#!/usr/bin/env python3
|
|
# -*- coding: UTF-8 -*-
|
|
|
|
from pycen import con_fon
|
|
from sqlalchemy.sql import text
|
|
from sqlalchemy.engine import URL
|
|
from sqlalchemy import create_engine
|
|
import pandas as pd
|
|
import geopandas as gpd
|
|
|
|
# user = 'cgeier'
|
|
# pwd = 'adm1n*bdCen'
|
|
# adr = '91.134.194.221'
|
|
# base = 'cadastre'
|
|
user = 'postgres'
|
|
pwd = 'foncier_test1'
|
|
adr = '172.17.0.2'
|
|
base = 'postgres'
|
|
url = URL.create('postgresql+psycopg2',
|
|
username=user,
|
|
password=pwd,
|
|
host=adr,
|
|
database=base,
|
|
)
|
|
con_cad = create_engine(url)
|
|
|
|
|
|
def recup_cols_table(table,con,schema='38_202207'):
|
|
lst_cols = con.dialect.get_columns(con,table,schema)
|
|
return [x['name'] for x in lst_cols]
|
|
|
|
|
|
def __get_pkey__(engine,table_name,schema):
|
|
pk = engine.dialect.get_pk_constraint(engine,table_name=table_name,schema=schema)
|
|
return pk
|
|
|
|
|
|
def _where_parcelle(sql0,schema,list_parid):
|
|
|
|
if list_parid is not None:
|
|
chunk = None
|
|
if isinstance(list_parid,str):
|
|
list_parid = [list_parid]
|
|
|
|
LIST_ID = str(tuple(list_parid)).replace(',)',')')
|
|
|
|
sql1 = '''
|
|
WHERE p.parcelle IN {list_id}
|
|
;'''.format(sch=schema,list_id=LIST_ID)
|
|
else :
|
|
chunk = 200000
|
|
sql1 = ';'
|
|
|
|
sql = sql0 + sql1
|
|
df = pd.read_sql_query(text(sql),con=con_cad,chunksize=chunk)
|
|
|
|
# if chunk is not None:
|
|
# for d in df:
|
|
# print(d.shape[0])
|
|
# d.drop_duplicates(inplace=True)
|
|
# print(d.drop_duplicates().shape[0])
|
|
# else :
|
|
# df.drop_duplicates(inplace=True)
|
|
|
|
return df
|
|
|
|
|
|
def _get_chunk(df1,df2):
|
|
# cptp1 = pd.DataFrame()
|
|
list_DF1 = []
|
|
for d1 in df1:
|
|
list_DF1.append(d1)
|
|
|
|
DF1 = pd.concat(list_DF1)
|
|
|
|
# cptp2 = pd.DataFrame()
|
|
list_DF2 = []
|
|
for d2 in df2:
|
|
list_DF2.append(d2)
|
|
|
|
DF2 = pd.concat(list_DF2)
|
|
|
|
return pd.concat([DF1,DF2]).drop_duplicates()
|
|
|
|
|
|
def __get_parcelles__(sql0,list_parid):
|
|
|
|
if list_parid is not None:
|
|
chunk = None
|
|
if isinstance(list_parid,str):
|
|
list_parid = [list_parid]
|
|
|
|
LIST_ID = str(tuple(list_parid)).replace(',)',')')
|
|
|
|
sql1 = '''
|
|
WHERE t1.geo_parcelle IN {list_id}
|
|
;'''.format(list_id=LIST_ID)
|
|
else :
|
|
chunk = None
|
|
sql1 = ';'
|
|
|
|
sql = sql0 + sql1
|
|
# print(text(sql))
|
|
return gpd.read_postgis(sql=sql,con=con_cad,chunksize=chunk)
|
|
|
|
|
|
def _get_parcelles1(schema='38_202207',list_parid=None):
|
|
sql0 = '''SELECT DISTINCT ON (t1.geo_parcelle)
|
|
t1.geo_parcelle,
|
|
case when t1.geom is null then t2.geom
|
|
else t1.geom
|
|
end geom,
|
|
substring(p.parcelle from 1 for 2)||substring(p.parcelle from 4 for 12) par_id,
|
|
substring(p.parcelle from 1 for 2)||substring(p.parcelle from 4 for 3) codcom,
|
|
substring(p.parcelle from 1 for 2) ccodep,
|
|
substring(p.parcelle from 4 for 3) ccocom,
|
|
substring(p.parcelle from 7 for 3) ccopre,
|
|
substring(p.parcelle from 10 for 2) ccosec,
|
|
substring(p.parcelle from 12 for 4) dnupla,
|
|
p.annee annee_pci,
|
|
t1.update_dat,
|
|
p.dparpi,
|
|
p.dcntpa,
|
|
p.ccocomm,
|
|
p.ccoprem,
|
|
p.ccosecm,
|
|
p.dnuplam,
|
|
p.ccovoi,
|
|
p.ccoriv,
|
|
p.type_filiation "type",
|
|
substring(t1.geo_parcelle from 1 for 2)||substring(t1.geo_parcelle from 4 for 3)||p.ccovoi vl_id,
|
|
(SELECT STRING_AGG(DISTINCT gtoper::text,',') FROM "{sch}".proprietaire WHERE (ccodep,ccocom,dnupro) = (t3.ccodep,t3.ccocom,t3.dnupro)) gtoper,
|
|
(SELECT STRING_AGG(DISTINCT ccogrm::text,',') FROM "{sch}".proprietaire WHERE (ccodep,ccocom,dnupro) = (t3.ccodep,t3.ccocom,t3.dnupro)) ccogrm,
|
|
(SELECT STRING_AGG(DISTINCT CONCAT(gtoper::text||COALESCE('_'||ccogrm::text,'')),',') FROM "{sch}".proprietaire WHERE (ccodep,ccocom,dnupro) = (t3.ccodep,t3.ccocom,t3.dnupro)) ccogrm,
|
|
(SELECT STRING_AGG(DISTINCT TRIM(ddenom)::text,',') FROM "{sch}".proprietaire WHERE (ccodep,ccocom,dnupro) = (t3.ccodep,t3.ccocom,t3.dnupro)) ddenom
|
|
FROM "{sch}".{t1} p
|
|
LEFT JOIN "{sch}".parcelle_info t2 ON t2.geo_parcelle = p.parcelle
|
|
LEFT JOIN "{sch}"."geo_parcelle" t1 ON t1.geo_parcelle = p.parcelle
|
|
LEFT JOIN "{sch}".proprietaire t3 USING (ccodep,ccocom,dnupro)
|
|
'''.format(
|
|
sch=schema,
|
|
t1='parcelle')
|
|
|
|
return __get_parcelles__(sql0,list_parid)
|
|
|
|
def drop_tables(con):
|
|
sql = '''
|
|
TRUNCATE TABLE cadastre.parcelles RESTART IDENTITY CASCADE;
|
|
TRUNCATE TABLE cadastre.cadastre RESTART IDENTITY CASCADE;
|
|
TRUNCATE TABLE cadastre.cptprop RESTART IDENTITY CASCADE;
|
|
TRUNCATE TABLE cadastre.r_prop_cptprop RESTART IDENTITY CASCADE;
|
|
TRUNCATE TABLE cadastre.lots RESTART IDENTITY CASCADE;
|
|
TRUNCATE TABLE cadastre.lots_natcult RESTART IDENTITY CASCADE;
|
|
TRUNCATE TABLE cadastre.proprios RESTART IDENTITY CASCADE;
|
|
TRUNCATE TABLE cadastre.vl RESTART IDENTITY CASCADE;
|
|
ALTER SEQUENCE
|
|
cadastre.cadastre_cad_id_seq RESTART WITH 1;
|
|
ALTER SEQUENCE
|
|
cadastre.lots_natcult_lotnatcult_id_seq RESTART WITH 1;
|
|
'''
|
|
with con.begin() as cnx:
|
|
cnx.execute(sql)
|
|
|
|
def where_parid(parid):
|
|
if not parid: return ""
|
|
return "AND parcelle.parcelle {} {}".format(
|
|
"IN" if isinstance(parid, (list,pd.Series)) and len(parid) > 1 else "=",
|
|
tuple(parid) if isinstance(parid, (list,pd.Series)) and len(parid) > 1
|
|
else "'%s'"%parid[0] if isinstance(parid, (list,pd.Series)) and len(parid) == 1
|
|
else "'%s'"%parid
|
|
)
|
|
|
|
# CENRA 2020
|
|
def _insert_voie1(schema='38_202207',list_parid=None):
|
|
'''Insertion des voies et lieux-dits dans cadastre.vl à partir de voie.
|
|
On ne garde que les voies qui sont effectivement affectées à des parcelles pour ne pas se trainer les voies annulées (annul = 'O')
|
|
'''
|
|
sql0 = '''set work_mem='512MB';
|
|
INSERT into cadastre.vl
|
|
SELECT
|
|
v.ccodep||v.ccocom||v.codvoi AS vl_id, --character varying(10) NOT NULL, -->>> c'est pas le bon compte de caractères, mais je n'ai pas de doublons en auvergne
|
|
v.libvoi AS libelle,--character varying(50),
|
|
null AS geom -- geom geometry(MultiPolygon,2154),
|
|
FROM "{sch}".voie v
|
|
LEFT JOIN "{sch}".parcelle ON v.ccodep||v.ccocom||v.codvoi = parcelle.ccodep||parcelle.ccocom||parcelle.ccovoi
|
|
WHERE v.ccodep||v.ccocom||v.codvoi IN (
|
|
SELECT DISTINCT ccodep||ccocom||ccovoi FROM "{sch}".parcelle )
|
|
'''.format(
|
|
sch=schema)
|
|
|
|
if list_parid:
|
|
sql0 += where_parid(list_parid)
|
|
|
|
with con_fon.begin() as cnx:
|
|
cnx.execute(sql0)
|
|
|
|
def _insert_voie2(schema='38_202207',list_parid=None):
|
|
'''Insertions des vois manquantes à partir de leur ccoriv --> 12
|
|
'''
|
|
sql0 = '''set work_mem='512MB';
|
|
INSERT into cadastre.vl
|
|
SELECT DISTINCT
|
|
parcelle.ccodep||parcelle.ccocom||parcelle.ccovoi AS vl_id,
|
|
libvoi
|
|
FROM "{sch}".parcelle
|
|
JOIN "{sch}".voie ON voie.ccoriv = parcelle.ccoriv AND voie.ccocom = parcelle.ccocom
|
|
WHERE parcelle.ccodep||parcelle.ccocom||parcelle.ccovoi NOT IN (
|
|
SELECT ccodep||ccocom||codvoi AS vl_id FROM "{sch}".voie)
|
|
'''.format(
|
|
sch=schema)
|
|
|
|
if list_parid:
|
|
sql0 += where_parid(list_parid)
|
|
|
|
with con_fon.begin() as cnx:
|
|
cnx.execute(sql0)
|
|
def _insert_voie3(schema='38_202207',list_parid=None):
|
|
'''Ajout manuel des dernières voies référencées dans parcelle mais introuvables dans voie (ni par codvoi ni par ccoriv) --> 0
|
|
'''
|
|
sql0 = '''set work_mem='512MB';
|
|
INSERT into cadastre.vl
|
|
SELECT DISTINCT ccodep||ccocom||ccovoi AS vl_id, 'NON TROUVEE' AS libelle
|
|
FROM "{sch}".parcelle
|
|
WHERE ccodep||ccocom||ccovoi NOT IN (SELECT vl_id from cadastre.vl)
|
|
'''.format(
|
|
sch=schema)
|
|
|
|
if list_parid:
|
|
sql0 += where_parid(list_parid)
|
|
|
|
with con_fon.begin() as cnx:
|
|
cnx.execute(sql0)
|
|
|
|
def insert_voie(schema='38_202207',list_parid=None):
|
|
_insert_voie1(schema,list_parid)
|
|
_insert_voie2(schema,list_parid)
|
|
_insert_voie3(schema,list_parid)
|
|
print('INSERT voie OK')
|
|
|
|
|
|
# def _manage_parc_without_geom(schema='38_202207'):
|
|
# sql = '''CREATE TEMP TABLE parcelles_sans_geom AS (
|
|
# SELECT parcelle FROM "{sch}".parcelle a LEFT JOIN "{sch}".geo_parcelle b ON b.geo_parcelle = a.parcelle WHERE b.geo_parcelle is null
|
|
# '''.format(
|
|
# sch=schema)
|
|
# with con_fon.begin() as cnx:
|
|
# cnx.execute(sql)
|
|
|
|
# def add_old_geom(schema='38_202207'):
|
|
# sql = '''
|
|
# '''
|
|
|
|
|
|
def _insert_parcelle1(schema='38_202207',list_parid=None):
|
|
'''01/ parcelles'''
|
|
sql = '''set work_mem='512MB';
|
|
INSERT INTO cadastre.parcelles
|
|
(
|
|
SELECT DISTINCT ON (ccodep || ccocom || replace(ccopre, ' ', '0') || replace(ccosec, ' ', '0') || dnupla)
|
|
ccodep || ccocom || replace(ccopre, ' ', '0') || replace(ccosec, ' ', '0') || dnupla AS par_id,
|
|
-- Identifiant de la parcelle
|
|
ccodep || ccocom AS codcom,
|
|
-- Code insee de la commune
|
|
--CASE WHEN btrim(ccovoi) <> '' THEN ccodep || ccocom || ccovoi ELSE NULL END AS vl_id,
|
|
ccodep || ccocom || ccovoi AS vl_id,
|
|
--character varying(10) NOT NULL, -->>> on ne met rien lorsque que ccovoi non renseigné dans la table parcelle
|
|
btrim(ccopre) as ccopre,
|
|
-- Préfixe de section ou quartier servi
|
|
btrim(ccosec) as ccosec,
|
|
-- Code de la section
|
|
CASE WHEN btrim(dnupla) = ''
|
|
THEN NULL :: INTEGER
|
|
ELSE ltrim(btrim(dnupla), '0') :: INTEGER END AS dnupla,
|
|
-- Numéro de la parcelle
|
|
CASE WHEN btrim(dparpi) = ''
|
|
THEN NULL :: INTEGER
|
|
ELSE ltrim(btrim(dparpi), '0') :: INTEGER END AS dparpi,
|
|
-- Ancien numéro de la parcelle, parcelle primitive
|
|
dcntpa :: INTEGER,
|
|
-- Contenance cadastrale de la parcelle
|
|
NULL AS typprop_id,
|
|
-- Type de propriété de la parcelle >>>>>>>>>>>>>>>>>>>>>>>>>>>>>> à remplir après (Cf. tâches de mise à jour du cadastre)
|
|
geom,
|
|
-- Géométrie de la parcelle
|
|
ccocomm,
|
|
-- Commune Parcelle mère
|
|
ccoprem,
|
|
-- Préfixe Parcelle mère
|
|
btrim(ccosecm) as ccosecm,
|
|
-- Section Parcelle mère
|
|
CASE WHEN dnuplam = ''
|
|
THEN NULL :: INTEGER
|
|
ELSE ltrim(dnuplam, '0') :: INTEGER
|
|
END AS dnuplam,
|
|
-- Numéro Parcelle mère
|
|
type_filiation AS "type", -- Type de filiation
|
|
jdatat
|
|
FROM "{sch}".parcelle
|
|
JOIN "{sch}".geo_parcelle ON geo_parcelle.geo_parcelle = parcelle.parcelle
|
|
|
|
'''.format(
|
|
sch=schema)
|
|
|
|
if list_parid:
|
|
sql += where_parid(list_parid).replace('AND','WHERE')
|
|
sql += ');'
|
|
with con_fon.begin() as cnx:
|
|
cnx.execute(sql)
|
|
|
|
# A REPRENDRE
|
|
def _insert_parcelle2(schema='38_202207',list_parid=None):
|
|
'''2/ Géométries manquantes
|
|
Parcelles MAJIC qui n'ont plus de geom dans EDIGEO parce qu'elles ont été fusionnées, divisées ou transférées
|
|
Il y a la geom des nouvelles parcelles dans EDIGEO mais rien dans MAJIC
|
|
On récupère la geom sur un EDIGEO antérieur'''
|
|
sql = '''set work_mem='512MB';
|
|
INSERT INTO cadastre.parcelles
|
|
( WITH t1 as (
|
|
SELECT DISTINCT ON (a.ccodep || a.ccocom || replace(a.ccopre, ' ', '0') || replace(a.ccosec, ' ', '0') || a.dnupla)
|
|
parcelle,
|
|
a.ccodep || a.ccocom || replace(a.ccopre, ' ', '0') || replace(a.ccosec, ' ', '0') || a.dnupla AS par_id,
|
|
-- Identifiant de la parcelle
|
|
a.ccodep || a.ccocom AS codcom,
|
|
-- Code insee de la commune
|
|
--CASE WHEN btrim(ccovoi) <> '' THEN ccodep || ccocom || ccovoi ELSE NULL END AS vl_id,
|
|
a.ccodep || a.ccocom || a.ccovoi AS vl_id,
|
|
--character varying(10) NOT NULL, -->>> on ne met rien lorsque que ccovoi non renseigné dans la table parcelle
|
|
replace(a.ccopre, ' ', '0') AS ccopre,
|
|
-- Préfixe de section ou quartier servi
|
|
-- btrim(a.ccosec) AS ccosec,
|
|
replace(a.ccosec, ' ', '0') AS ccosec,
|
|
-- Code de la section
|
|
CASE WHEN btrim(a.dnupla) = ''
|
|
THEN NULL :: INTEGER
|
|
ELSE ltrim(btrim(a.dnupla), '0') :: INTEGER
|
|
END AS dnupla,
|
|
-- Numéro de la parcelle
|
|
CASE WHEN btrim(a.dparpi) = ''
|
|
THEN NULL :: INTEGER
|
|
ELSE ltrim(btrim(a.dparpi), '0') :: INTEGER
|
|
END AS dparpi,
|
|
-- Ancien numéro de la parcelle, parcelle primitive
|
|
a.dcntpa :: INTEGER,
|
|
-- Contenance cadastrale de la parcelle
|
|
NULL AS typprop_id,
|
|
-- Type de propriété de la parcelle >>>>>>>>>>>>>>>>>>>>>>>>>>>>>> à remplir après (Cf. tâches de mise à jour du cadastre)
|
|
-- parcelles_cen.geom,
|
|
-- Géométrie de la parcelle
|
|
a.ccocomm,
|
|
-- Commune Parcelle mère
|
|
a.ccoprem,
|
|
-- Préfixe Parcelle mère
|
|
btrim(a.ccosecm) AS ccosecm,
|
|
-- Section Parcelle mère
|
|
CASE WHEN a.dnuplam = ''
|
|
THEN NULL :: INTEGER
|
|
ELSE ltrim(a.dnuplam, '0') :: INTEGER END AS dnuplam,
|
|
-- Numéro Parcelle mère
|
|
a.type_filiation AS "type", -- Type de filiation
|
|
a.jdatat
|
|
FROM "{sch}".parcelle a )
|
|
SELECT
|
|
t1.par_id,
|
|
t1.codcom,
|
|
t1.vl_id,
|
|
t1.ccopre,
|
|
t1.ccosec,
|
|
t1.dnupla,
|
|
t1.dparpi,
|
|
t1.dcntpa,
|
|
t1.typprop_id,
|
|
CASE WHEN b.geom IS NULL THEN parcelles_cen.geom
|
|
ELSE b.geom END geom,
|
|
t1.ccocomm,
|
|
t1.ccoprem,
|
|
t1.ccosecm,
|
|
t1.dnuplam,
|
|
t1.type,
|
|
t1.jdatat
|
|
FROM t1
|
|
LEFT JOIN "{sch}".parcelle_info b ON t1.parcelle = b.geo_parcelle -- les parcelles sans geom
|
|
LEFT JOIN "{sch}".parcelle c ON t1.parcelle = c.parcelle -- les parcelles sans geom
|
|
LEFT JOIN cadastre.parcelles_cen ON t1.par_id = parcelles_cen.par_id
|
|
WHERE t1.par_id NOT IN (SELECT par_id FROM cadastre.parcelles)
|
|
)
|
|
'''.format(
|
|
sch=schema)
|
|
|
|
if list_parid:
|
|
sql += where_parid(list_parid)
|
|
|
|
with con_fon.begin() as cnx:
|
|
cnx.execute(sql)
|
|
|
|
def insert_parcelle(schema='38_202207',list_parid=None):
|
|
_insert_parcelle1(schema,list_parid)
|
|
_insert_parcelle2(schema,list_parid)
|
|
print('INSERT parcelle OK')
|
|
|
|
|
|
def checkortho_proprio_sym(con,colonne,schema='38_202207'):
|
|
sql = '''
|
|
SELECT DISTINCT '{dep}' AS insee_dep, dnuper, string_agg(DISTINCT TRIM({column}),' / ') AS orthographes_voisines
|
|
FROM "{sch}".proprietaire
|
|
GROUP BY dnuper HAVING count(DISTINCT TRIM({column})) > 1
|
|
'''.format(dep = schema[:2],
|
|
sch=schema,
|
|
column=colonne)
|
|
return pd.read_sql(sql,con=con)
|
|
|
|
def update_synonyme_proprio(con,data,colonne,schema='38_202207'):
|
|
data['split_ortho'] = (data.orthographes_voisines
|
|
.str.replace("'","''")
|
|
.str.split(' / '))
|
|
for i,row in data.iterrows():
|
|
sql = '''UPDATE "{sch}".proprietaire SET {column} = '{dd1}' WHERE btrim({column}) {sym} {dd2} AND dnuper = '{dnup}';'''.format(
|
|
sch=schema,
|
|
dnup=row.dnuper,
|
|
column=colonne,
|
|
dd1=row.split_ortho[0],
|
|
sym='IN' if len(row.split_ortho[1:]) > 1 else '=',
|
|
dd2=tuple(row.split_ortho[1:]) if len(row.split_ortho[1:]) > 1 else "'%s'"% row.split_ortho[1])
|
|
|
|
with con.begin() as cnx:
|
|
cnx.execute(sql)
|
|
|
|
def check_proprio(schema='38_202207',con=con_fon):
|
|
is_synonyme = checkortho_proprio_sym(con,'ddenom',schema)
|
|
if not is_synonyme.empty:
|
|
update_synonyme_proprio(con,is_synonyme,'ddenom',schema)
|
|
|
|
is_diff_lab = checkortho_proprio_sym(con,'dldnss',schema)
|
|
if not is_diff_lab.empty:
|
|
update_synonyme_proprio(con,is_diff_lab,'dldnss',schema)
|
|
|
|
is_incomplete = checkortho_proprio_sym(con,'jdatnss',schema)
|
|
if not is_incomplete.empty:
|
|
update_synonyme_proprio(con,is_incomplete,'jdatnss',schema)
|
|
|
|
is_diff_ccogrm = checkortho_proprio_sym(con,'ccogrm',schema)
|
|
if not is_diff_ccogrm.empty:
|
|
update_synonyme_proprio(con,is_diff_ccogrm,'ccogrm',schema)
|
|
|
|
is_diff_dsglpm = checkortho_proprio_sym(con,'dsglpm',schema)
|
|
if not is_diff_dsglpm.empty:
|
|
update_synonyme_proprio(con,is_diff_dsglpm,'dsglpm',schema)
|
|
|
|
is_diff_dnatpr = checkortho_proprio_sym(con,'dnatpr',schema)
|
|
if not is_diff_dnatpr.empty:
|
|
update_synonyme_proprio(con,is_diff_dnatpr,'dnatpr',schema)
|
|
|
|
is_diff_dprnus = checkortho_proprio_sym(con,'dprnus',schema)
|
|
if not is_diff_dprnus.empty:
|
|
update_synonyme_proprio(con,is_diff_dprnus,'dprnus',schema)
|
|
is_diff_dprnlp = checkortho_proprio_sym(con,'dprnlp',schema)
|
|
if not is_diff_dprnlp.empty:
|
|
update_synonyme_proprio(con,is_diff_dprnlp,'dprnlp',schema)
|
|
is_diff_dnomus = checkortho_proprio_sym(con,'dnomus',schema)
|
|
if not is_diff_dnomus.empty:
|
|
update_synonyme_proprio(con,is_diff_dnomus,'dnomus',schema)
|
|
|
|
def _insert_proprio(schema='38_202207',list_parid=None):
|
|
sql = '''set work_mem='512MB';
|
|
INSERT INTO cadastre.proprios
|
|
SELECT DISTINCT
|
|
ccodep||dnuper dnuper,
|
|
ccoqua::integer,
|
|
btrim(ddenom) AS ddenom,
|
|
jdatnss,
|
|
btrim(dldnss) AS dldnss,
|
|
btrim(dsglpm) AS dsglpm,
|
|
btrim(dlign3) AS dlign3,
|
|
btrim(dlign4) AS dlign4,
|
|
btrim(dlign5) AS dlign5,
|
|
btrim(dlign6) AS dlign6,
|
|
btrim(dnatpr) AS dnatpr,
|
|
gtoper::integer,
|
|
ccogrm::integer,
|
|
btrim(dqualp) AS dnatpr,
|
|
btrim(dnomlp) AS dnomlp,
|
|
btrim(dprnlp) AS dprnlp,
|
|
btrim(dnomus) AS dnomus,
|
|
btrim(dprnus) AS dprnus,
|
|
btrim(dforme) AS dforme
|
|
FROM "{sch}".proprietaire
|
|
'''.format(
|
|
sch=schema)
|
|
with con_fon.begin() as cnx:
|
|
cnx.execute(sql)
|
|
|
|
def insert_no_proprio(schema='38_202207'):
|
|
sql = '''
|
|
INSERT INTO cadastre.proprios (dnuper, ddenom)
|
|
VALUES ('{dep}Y99999', ' PROPRIETAIRES NON RENSEIGNES');
|
|
'''.format(
|
|
dep=schema[:2])
|
|
with con_fon.begin() as cnx:
|
|
cnx.execute(sql)
|
|
|
|
def insert_proprio(schema='38_202207'):
|
|
check_proprio(schema,con_fon)
|
|
_insert_proprio(schema)
|
|
insert_no_proprio(schema)
|
|
print('INSERT proprio OK')
|
|
|
|
|
|
def _insert_cptprop1(schema='38_202207'):
|
|
'''
|
|
Insertion des comptes de propriété depuis la table proprietaire
|
|
'''
|
|
sql = '''set work_mem='512MB';
|
|
INSERT INTO cadastre.cptprop
|
|
SELECT DISTINCT ccodep || ccocom || dnupro
|
|
FROM "{sch}".proprietaire WHERE btrim(dnupro) <> ''
|
|
'''.format(
|
|
sch=schema)
|
|
with con_fon.begin() as cnx:
|
|
cnx.execute(sql)
|
|
def _insert_cptprop2(schema='38_202207'):
|
|
'''
|
|
Insertion des comptes de propriété utilisés dans
|
|
lots/parcelles/suf mais non référencés dans proprietaire
|
|
'''
|
|
sql = '''set work_mem='512MB';
|
|
INSERT INTO cadastre.cptprop
|
|
SELECT DISTINCT ccodep || ccocom || dnuprol
|
|
FROM "{sch}".lots WHERE comptecommunal NOT IN (SELECT DISTINCT comptecommunal FROM "{sch}".proprietaire)
|
|
UNION
|
|
SELECT DISTINCT ccodep || ccocom || dnupro
|
|
FROM "{sch}".parcelle WHERE comptecommunal NOT IN (SELECT DISTINCT comptecommunal FROM "{sch}".proprietaire)
|
|
UNION
|
|
SELECT DISTINCT ccodep || ccocom || dnupro
|
|
FROM "{sch}".suf WHERE comptecommunal NOT IN (SELECT DISTINCT comptecommunal FROM "{sch}".proprietaire)
|
|
'''.format(
|
|
sch=schema)
|
|
with con_fon.begin() as cnx:
|
|
cnx.execute(sql)
|
|
|
|
def insert_cptprop(schema='38_202207'):
|
|
_insert_cptprop1(schema)
|
|
_insert_cptprop2(schema)
|
|
print('INSERT cptprop OK')
|
|
|
|
def _insert_r_prop_cptprop0(schema='38_202207'):
|
|
sql = '''set work_mem='512MB';
|
|
INSERT INTO cadastre.r_prop_cptprop
|
|
SELECT DISTINCT
|
|
ccodep||dnuper,
|
|
ccodep || ccocom || dnupro,
|
|
btrim(dnomlp),
|
|
btrim(dprnlp),
|
|
CASE WHEN btrim(epxnee) = ''
|
|
THEN NULL::text
|
|
ELSE btrim(epxnee)
|
|
END AS epxnee ,
|
|
btrim(dnomcp),
|
|
btrim(dprncp),
|
|
btrim(ccodro),
|
|
btrim(ccodem)
|
|
FROM "{sch}".proprietaire WHERE btrim(dnupro) <> ''
|
|
'''.format(
|
|
sch=schema)
|
|
with con_fon.begin() as cnx:
|
|
cnx.execute(sql)
|
|
def _insert_r_prop_cptprop1(schema='38_202207'):
|
|
sql = '''set work_mem='512MB';
|
|
INSERT INTO cadastre.r_prop_cptprop
|
|
SELECT DISTINCT '{dep}Y99999', ccodep || ccocom || dnuprol
|
|
FROM "{sch}".lots WHERE comptecommunal NOT IN (SELECT DISTINCT comptecommunal FROM "{sch}".proprietaire)
|
|
UNION
|
|
SELECT DISTINCT '{dep}Y99999', ccodep || ccocom || dnupro
|
|
FROM "{sch}".parcelle WHERE comptecommunal NOT IN (SELECT DISTINCT comptecommunal FROM "{sch}".proprietaire)
|
|
UNION
|
|
SELECT DISTINCT '{dep}Y99999', ccodep || ccocom || dnupro
|
|
FROM "{sch}".suf WHERE comptecommunal NOT IN (SELECT DISTINCT comptecommunal FROM "{sch}".proprietaire)
|
|
'''.format(
|
|
sch=schema,
|
|
dep=schema[:2]
|
|
)
|
|
with con_fon.begin() as cnx:
|
|
cnx.execute(sql)
|
|
|
|
def insert_r_prop_cptprop(schema='38_202207'):
|
|
_insert_r_prop_cptprop0(schema)
|
|
_insert_r_prop_cptprop1(schema)
|
|
print('INSERT r_prop_cptprop OK')
|
|
|
|
|
|
def _insert_lot1(schema='38_202207',list_parid=None):
|
|
sql = '''set work_mem='512MB';
|
|
INSERT INTO cadastre.lots (lot_id, par_id, dnulot, dcntlo)
|
|
--les parcelles divisées en lots de la table lots
|
|
(WITH parcelle AS (
|
|
SELECT DISTINCT
|
|
ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla||dnulot AS id_lot, -- Identifiant du lot character varying(21)
|
|
ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla AS par_id, -- Identifiant de la parcelle
|
|
dnulot, -- Numéro du lot
|
|
max(dcntlo) AS dcntlo -- Contenance cadastrale (m²) on prend contenance maxi quand même id_lot mais dcntlo différentes
|
|
FROM "{sch}".lots
|
|
JOIN "{sch}".geo_parcelle ON lots.parcelle = geo_parcelle.geo_parcelle -- on ne garde que les lots sur des parcelles dont on a la géométrie
|
|
WHERE ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla||dnulot IN
|
|
( -- on sélectionne uniquement les lots qui supportent une subdivision fiscale pour exclure les lots batis
|
|
SELECT ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla||dnulot FROM "{sch}".suf WHERE btrim(dnulot) <> '')
|
|
GROUP BY ccodep, ccocom, ccopre, ccosec, dnupla, dnulot
|
|
UNION -- les lots de la table suf qui ne sont pas dans la table lots
|
|
SELECT DISTINCT
|
|
ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla||dnulot AS id_lot, -- Identifiant du lot character varying(21)
|
|
ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla AS par_id, -- Identifiant de la parcelle
|
|
dnulot, -- Numéro du lot
|
|
sum(dcntsf) AS dcntlo -- Contenance cadastrale (m²) = On additionne les contenances des différentes suf qui composent le lot
|
|
FROM "{sch}".suf
|
|
JOIN "{sch}".geo_parcelle ON suf.parcelle = geo_parcelle.geo_parcelle -- on ne garde que les sufs sur des parcelles dont on a la géométrie
|
|
WHERE btrim(dnulot) <> '' AND ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla||dnulot NOT IN (
|
|
SELECT DISTINCT ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla||dnulot FROM "{sch}".lots WHERE btrim(dnulot)<>'')
|
|
GROUP BY ccodep, ccocom, ccopre, ccosec, dnupla, dnulot
|
|
UNION -- les parcelles à lot unique
|
|
-- on sélectionne les parcelles qui supportent une subdivision fiscale (unique ou multiple) même si divisées en lots car dans ce cas ce sont surement des copropriétés (lots batis/jardins...)
|
|
SELECT DISTINCT
|
|
ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla AS id_lot, -- Identifiant du lot fictif(=id parcelle)
|
|
ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla AS par_id, -- Identifiant de la parcelle
|
|
null AS dnulot, -- Numéro du lot
|
|
dcntpa AS dcntlo-- Contenance cadastrale (m²)
|
|
FROM "{sch}".parcelle
|
|
JOIN "{sch}".geo_parcelle ON parcelle.parcelle = geo_parcelle.geo_parcelle -- on ne garde que les parcelles dont on a la géométrie
|
|
WHERE ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla IN
|
|
(SELECT ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla||trim(dnulot) FROM "{sch}".suf) -- toutes les parcelles dont dnulot est NULL
|
|
)
|
|
SELECT id_lot, par_id, dnulot, dcntlo
|
|
FROM parcelle
|
|
'''.format(
|
|
sch=schema)
|
|
|
|
if list_parid:
|
|
list_parid = [x[:2] + x[3:] for x in list_parid]
|
|
sql += (where_parid(list_parid)
|
|
.replace('AND', 'WHERE')
|
|
.replace('.parcelle','.par_id')
|
|
)
|
|
|
|
sql += ');'
|
|
|
|
with con_fon.begin() as cnx:
|
|
cnx.execute(sql)
|
|
|
|
|
|
def _insert_lot2(schema='38_202207'):
|
|
sql = '''set work_mem='512MB';
|
|
insert into cadastre.lots (lot_id, par_id, dnulot, dcntlo,geom)
|
|
with t1 as (
|
|
SELECT DISTINCT
|
|
-- CASE WHEN TRIM(t.dnulot) = '' OR TRIM(t.dnulot) IS NULL
|
|
-- THEN substring(t.parcelle from 1 for 2)||substring(t.parcelle from 4 for 12)||TRIM(t.ccosub)
|
|
-- ELSE substring(t.parcelle from 1 for 2)||substring(t.parcelle from 4 for 12)||TRIM(t.dnulot)
|
|
-- END lot_id,
|
|
--substring(t.parcelle from 1 for 2)||substring(t.parcelle from 4 for 12)||TRIM(t.dnulot) lot_id,
|
|
ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||TRIM(dnupla)||TRIM(dnulot) AS lot_id,
|
|
parcelle,
|
|
t.ccosub,
|
|
t.dcntsf,
|
|
--substring(t.parcelle from 1 for 2)||substring(t.parcelle from 4 for 12) par_id,
|
|
ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||TRIM(dnupla) AS par_id,
|
|
CASE WHEN TRIM(t.dnulot) = '' OR TRIM(t.dnulot) IS NULL
|
|
THEN TRIM(t.ccosub)
|
|
ELSE TRIM(t.dnulot)
|
|
END dnulot
|
|
FROM "{sch}"."suf" t
|
|
)
|
|
select distinct on (t1.lot_id,t1.par_id)
|
|
t1.lot_id,
|
|
t1.par_id,
|
|
t1.dnulot,
|
|
CASE WHEN t1.dcntsf IS NULL
|
|
THEN l.dcntlo
|
|
ELSE t1.dcntsf
|
|
END dcntlo,
|
|
CASE WHEN geo_sub1.geom IS NULL
|
|
THEN geo_sub2.geom
|
|
ELSE geo_sub1.geom
|
|
END geom
|
|
from t1
|
|
JOIN "{sch}".parcelle p USING (parcelle)
|
|
LEFT JOIN "{sch}".geo_parcelle geo_p ON geo_p.geo_parcelle = p.parcelle
|
|
LEFT JOIN "{sch}".lots l USING (parcelle)
|
|
--LEFT JOIN "{sch}".lotslocaux ll USING (lots)
|
|
LEFT JOIN "{sch}".geo_subdfisc_parcelle geo_sub_p ON p.parcelle = geo_sub_p.geo_parcelle
|
|
--LEFT JOIN "{sch}".geo_subdfisc geo_sub USING (geo_subdfisc)
|
|
LEFT JOIN "{sch}".geo_subdfisc geo_sub1
|
|
ON (geo_sub1.geo_subdfisc = geo_sub_p.geo_subdfisc AND LOWER(geo_sub1.tex) = LOWER(t1.ccosub))
|
|
LEFT JOIN "{sch}".geo_subdfisc geo_sub2
|
|
ON (geo_sub2.geo_subdfisc = geo_sub_p.geo_subdfisc AND TRIM(LOWER(geo_sub2.tex)) = '')
|
|
WHERE (t1.par_id,t1.lot_id) not IN ( select par_id,lot_id from cadastre.lots )
|
|
OR t1.par_id not IN ( select par_id from cadastre.lots )
|
|
order by 2,1,5
|
|
;
|
|
'''.format(
|
|
sch=schema)
|
|
with con_fon.begin() as cnx:
|
|
cnx.execute(sql)
|
|
|
|
|
|
def insert_lot(schema='38_202207'):
|
|
_insert_lot1(schema)
|
|
_insert_lot2(schema)
|
|
print('INSERT lot OK')
|
|
|
|
|
|
def insert_cadastre(schema='38_202207',list_parid=None):
|
|
sql = '''set work_mem='512MB';
|
|
INSERT into cadastre.cadastre (lot_id, dnupro)
|
|
( WITH t1 as (
|
|
--les pdl
|
|
SELECT DISTINCT
|
|
ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla||dnulot AS lot_id, -- Identifiant du lot character varying(21)
|
|
ccodep || ccocom || dnuprol AS dnupro
|
|
FROM "{sch}".lots
|
|
JOIN "{sch}".geo_parcelle ON lots.parcelle = geo_parcelle.geo_parcelle -- on ne garde que les lots sur des parcelles dont on a la géométrie
|
|
WHERE
|
|
ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla||trim(dnulot) IN ( -- on sélectionne uniquement les lots qui supportent une subdivision fiscale
|
|
SELECT ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla||trim(dnulot)
|
|
FROM "{sch}".suf)
|
|
UNION
|
|
-- les lots de la table suf qui ne sont pas dans la table lots
|
|
SELECT DISTINCT
|
|
ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla||dnulot AS id_lot, -- Identifiant du lot character varying(21)
|
|
ccodep || ccocom || dnupro AS dnupro
|
|
FROM "{sch}".suf
|
|
JOIN "{sch}".geo_parcelle ON suf.parcelle = geo_parcelle.geo_parcelle -- on ne garde que les sufs sur des parcelles dont on a la géométrie
|
|
WHERE
|
|
trim(dnulot) <> '' AND ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla||btrim(dnulot)
|
|
NOT IN (
|
|
SELECT DISTINCT ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla||btrim(dnulot) FROM "{sch}".lots)
|
|
UNION
|
|
---les parcelles sans lot
|
|
SELECT DISTINCT
|
|
ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla AS id_lot, -- Identifiant du lot fictif(=id parcelle)
|
|
ccodep || ccocom || dnupro AS dnupro
|
|
FROM "{sch}".parcelle
|
|
JOIN "{sch}".geo_parcelle ON parcelle.parcelle = geo_parcelle.geo_parcelle -- on ne garde que les parcelles dont on a la géométrie
|
|
WHERE
|
|
ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla IN
|
|
(SELECT ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla||btrim(dnulot) FROM "{sch}".suf) -- toutes les parcelles dont dnulot est NULL
|
|
)
|
|
SELECT lot_id, dnupro FROM t1
|
|
'''.format(
|
|
sch=schema)
|
|
|
|
if list_parid:
|
|
sql += 'JOIN cadastre.lots l USING (lot_id) '
|
|
list_parid = [x[:2] + x[3:] for x in list_parid]
|
|
sql += (where_parid(list_parid)
|
|
.replace('AND', 'WHERE')
|
|
.replace('parcelle.parcelle','l.par_id')
|
|
)
|
|
|
|
sql += ');'
|
|
|
|
with con_fon.begin() as cnx:
|
|
cnx.execute(sql)
|
|
|
|
print('INSERT cadastre OK')
|
|
|
|
|
|
def cadastre_missing(con=con_fon):
|
|
sql = '''set work_mem='512MB';
|
|
INSERT into cadastre.cadastre (lot_id, dnupro)
|
|
SELECT DISTINCT
|
|
lot_id, -- Identifiant du lot character varying(21)
|
|
dnupro
|
|
FROM cadastre.cadastre_cen
|
|
WHERE lot_id NOT IN (SELECT lot_id FROM cadastre.cadastre)
|
|
AND lot_id IN (SELECT lot_id FROM cadastre.lots)
|
|
AND dnupro IN (SELECT dnupro FROM cadastre.cptprop)
|
|
;
|
|
'''
|
|
with con.begin() as cnx:
|
|
cnx.execute(sql)
|
|
|
|
|
|
def insert_lotnatcult(schema='38_202207',list_parid=None):
|
|
sql = '''set work_mem='512MB';
|
|
INSERT INTO cadastre.lots_natcult (lot_id, dsgrpf, cnatsp, dclssf, ccosub, dcntsf)
|
|
SELECT DISTINCT
|
|
ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla||btrim(dnulot) AS lot_id, -- Identifiant du lot (c'est bon, quand il n'y a pas de lot, c'est la même façon de noter l'identifiant)
|
|
btrim(dsgrpf) AS dsgrpf , -- Sous-groupe de nature de culture
|
|
btrim(cnatsp) AS cnatsp , -- Code nature de culture spéciale
|
|
CASE WHEN trim(dclssf) = '' OR dclssf = '00'
|
|
THEN NULL::integer
|
|
ELSE ltrim(dclssf,'0')::integer
|
|
END AS dclssf, -- Classe dans le groupe et la série tarif
|
|
btrim(ccosub) AS ccosub , -- Lettres indicatives de la suf
|
|
dcntsf -- Contenance de la suf
|
|
FROM "{sch}".suf
|
|
WHERE
|
|
ccodep||ccocom||replace(ccopre, ' ', '0')||replace(ccosec, ' ', '0')||dnupla||trim(dnulot) IN (SELECT lot_id FROM cadastre.lots)
|
|
'''.format(
|
|
sch=schema)
|
|
|
|
if list_parid:
|
|
sql += (where_parid(list_parid)
|
|
.replace('parcelle.parcelle','suf.suf')
|
|
)
|
|
|
|
with con_fon.begin() as cnx:
|
|
cnx.execute(sql)
|
|
|
|
print('INSERT lotnatcult OK')
|
|
|
|
|
|
def update_typprop(con=con_fon):
|
|
sql = '''set work_mem='512MB';
|
|
UPDATE
|
|
cadastre.parcelles
|
|
SET typprop_id = nullif(concat_ws('_',gtoper::text,ccogrm::text),'')
|
|
FROM cadastre.proprios
|
|
JOIN cadastre.r_prop_cptprop USING (dnuper)
|
|
JOIN cadastre.cptprop USING (dnupro)
|
|
JOIN cadastre.cadastre USING (dnupro)
|
|
JOIN cadastre.lots USING (lot_id)
|
|
WHERE lots.par_id = parcelles.par_id
|
|
AND typprop_id is NULL
|
|
'''
|
|
with con.begin() as cnx:
|
|
cnx.execute(sql)
|
|
|
|
print('UPDATE typprop OK')
|
|
|
|
if __name__ == "__main__":
|
|
|
|
from pycen import update_to_sql
|
|
# par = '3805050000E0523'
|
|
par = None
|
|
sch = '38_202501'
|
|
drop_tables(con_fon)
|
|
|
|
lst_sch = ['07_202501','26_202501','42_202501','38_202501']
|
|
for sch in lst_sch:
|
|
print(' INIT ',sch)
|
|
insert_voie(sch)
|
|
insert_parcelle(sch)
|
|
insert_proprio(sch)
|
|
insert_cptprop(sch)
|
|
insert_r_prop_cptprop(sch)
|
|
insert_lot(sch)
|
|
insert_cadastre(sch)
|
|
insert_lotnatcult(sch)
|
|
cadastre_missing(con_fon)
|
|
update_typprop(con_fon)
|
|
|
|
# pg_restore -h 172.17.0.2 -U postgres --dbname="bd_cen" -c /home/colas/Documents/9_PROJETS/0_FONCIER/DUMP/bd_cen_20240418_16h50_beforemaj2023.dump
|
|
|
|
_insert_lot1('38_202504','38405000ZD0209')
|
|
|
|
|
|
|
|
insert_cadastre('38_202504','380405000ZD0209')
|
|
insert_lotnatcult('38_202504','380405000ZD0209') |