DROP TABLE IF EXISTS parcelle_info_locaux;
CREATE TABLE parcelle_info_locaux AS
WITH infos AS (
SELECT
p.parcelle,
-- identification
l.dnubat AS l_batiment, l.descr AS l_numero_entree,
l.dniv AS l_niveau_etage, l.dpor AS l_numero_local,
(l.dnubat || l.descr || l.dniv || l.dpor) AS l_identifiant,
-- adresse
ltrim(l.dnvoiri, '0') || l.dindic AS l_numero_voirie,
CASE WHEN v.libvoi IS NOT NULL THEN v.natvoi || v.libvoi ELSE p.cconvo || p.dvoilib END AS l_adresse,
-- proprio et acte
string_agg((l10.ccodep || l10.ccocom || '-' ||l10.dnupro), '|') AS l10_compte_proprietaire,
string_agg(
trim((
'Numéro: ' || pr.dnuper ||
'
Nom: ' || trim(coalesce(pr.dqualp, '')) || ' ' || trim(coalesce(pr.ddenom, '')) ||
'
Adresse: ' || ltrim(trim(coalesce(pr.dlign4, '')), '0') || trim(coalesce(pr.dlign5, '')) || ' ' || trim(coalesce(pr.dlign6, '')) ||
'
Date de naissance: ' || Coalesce( trim(cast(pr.jdatnss AS text) ), '-') ||
'
Lieux de naissance: ' || coalesce(trim(pr.dldnss), '-') ||
'
Code droit: ' || Coalesce(ccodro_lib, '') ||
'
Code démembrement: ' || Coalesce(ccodem_lib, '')
))
, '|'
) AS l10_proprietaires,
l10.jdatat AS l10_date_acte,
-- autres infos
dteloc_lib AS l10_type_local,
cconlc_lib AS l10_nature_local,
ccoplc_lib AS l10_nature_construction_particuliere,
l10.jannat AS l10_annee_construction,
l10.dnbniv AS l10_nombre_niveaux,
dnatlc_lib AS l10_nature_occupation,
-- pev : informations générales
pev.pev,
ccoaff_lib AS pev_affectation,
pev.ccostb AS pev_lettre_serie,
pev.dcapec AS pev_categorie,
pev.dcetlc AS pev_entretien,
pev.dvlpera AS pev_valeur_locative,
pev.gnexpl AS pev_nature_exoneration_permanente,
pev.dnuref AS pev_numero_local_type,
pev.dcsplca AS pev_coefficient_situation_particuliere,
pev.dcsglca AS pev_coefficient_situation_generale,
-- pev : taxation (1 seule par PEV)
Coalesce(Cast(pt.co_vlbaia * px.pexb / 100 AS numeric(10,2)) , 0) as co_vlbaia, pt.co_bipevla as co_bipevla,
Coalesce(Cast(pt.gp_vlbaia * px.pexb / 100 AS numeric(10,2)) , 0) as gp_vlbaia, pt.gp_bipevla as gp_bipevla,
Coalesce(Cast(pt.de_vlbaia * px.pexb / 100 AS numeric(10,2)) , 0) as de_vlbaia, pt.de_bipevla as de_bipevla,
Coalesce(Cast(pt.re_vlbaia * px.pexb / 100 AS numeric(10,2)) , 0) as re_vlbaia, Coalesce(pt.re_bipevla, 0) as re_bipevla
FROM parcelle p
INNER JOIN local00 l ON l.parcelle = p.parcelle
INNER JOIN local10 l10 ON l10.local00 = l.local00
INNER JOIN pev ON pev.local10 = l10.local10
LEFT JOIN voie v ON v.voie = l.voie
LEFT JOIN pevtaxation pt ON pt.pev = pev.pev
LEFT JOIN pevexoneration px ON px.pev = pev.pev
LEFT JOIN "dteloc" ON l10.dteloc = dteloc.dteloc
LEFT JOIN "cconlc" ON l10.cconlc = cconlc.cconlc
LEFT JOIN "ccoplc" ON l10.ccoplc = ccoplc.ccoplc
LEFT JOIN "dnatlc" ON l10.dnatlc = dnatlc.dnatlc
LEFT JOIN "ccoaff" ON pev.ccoaff = ccoaff.ccoaff
LEFT JOIN proprietaire AS pr ON pr.comptecommunal = l10.comptecommunal
LEFT JOIN "ccodro" c2 ON pr.ccodro = c2.ccodro
LEFT JOIN "ccodem" c3 ON pr.ccodem = c3.ccodem
WHERE 2>1
--AND p.parcelle = '%s'
GROUP BY
p.parcelle,
l.dnubat, l.dniv, l.descr, l.dpor,
l.dnvoiri, l.dindic,
v.natvoi, v.libvoi, p.cconvo, p.dvoilib,
l10.ccodep, l10.ccocom, l10.dnupro, l10.jdatat,
dteloc_lib, cconlc_lib, ccoplc_lib, l10.jannat, l10.dnbniv, dnatlc_lib,
pev.pev, ccoaff_lib, pev.ccostb, pev.dcapec, pev.dcetlc, pev.dvlpera, pev.gnexpl, pev.dnuref, pev.dcsplca, pev.dcsglca,
pt.co_vlbaia, pt.gp_vlbaia, pt.de_vlbaia, pt.re_vlbaia, px.pexb, pt.co_bipevla, pt.gp_bipevla, pt.de_bipevla, pt.re_bipevla
ORDER BY l_identifiant
--LIMIT 1
),
pevs AS (
SELECT pp.pev,
'Habitation' AS type_pev, 'Habitation' AS sous_type_pev,
(
'Nombre de pièces: ' || pp.dnbpdc || '
Pièces principales: ' || pp.dnbppr ||
'
Surface des pièces: ' || pp.dsupdc || ' m2' || '
Salles à manger: ' || pp.dnbsam || '
Chambres: ' || pp.dnbcha ||
'
Cuisines < 9m2: ' || pp.dnbcu8 || '
Cuisines > 9m2: ' || pp.dnbcu9 ||
'
Salles d''eau: ' || pp.dnbsea || '
Pièces annexes: ' || pp.dnbann
) AS descriptif,
(
'Eau: ' || pp.geaulc || '
Électricité: ' || pp.gelelc ||
'
Gaz: ' || pp.ggazlc || '
Chauffage central: ' || pp.gchclc ||
'
Baignoire(s): ' || pp.dnbbai || '
Douche(s): ' || pp.dnbdou ||
'
Lavabo(s): ' || pp.dnblav || '
WC: ' || pp.dnbwc
) AS confort
FROM pevprincipale pp
JOIN infos ON infos.pev = pp.pev
UNION ALL
SELECT pd.pev,
'Dépendance' AS type_pev, cconad_lib AS sous_type_pev,
(
'Situation particulière: ' || pd.dcspdea || '
Surface réelle: ' || pd.dsudep || ' m2' ||
'
Pondération: ' || pd.dcimlc || '
État d''entretien: ' || pd.detent
) AS descriptif,
(
'Eau: ' || pd.geaulc || '
Électricité: ' || pd.gelelc ||
'
Chauffage central: ' || pd.gchclc || '
Baignoire(s): ' || pd.dnbbai ||
'
Douche(s): ' || pd.dnbdou || '
Lavabo(s): ' || pd.dnblav || '
WC: ' || pd.dnbwc
) AS confort
FROM pevdependances pd
JOIN infos ON infos.pev = pd.pev
LEFT JOIN cconad ON cconad.cconad = pd.cconad
UNION ALL
SELECT po.pev,
'Professionnel' AS type, 'Local professionnel' AS sous_type_pev,
Coalesce('Surface réelle: ' || po.vsurzt || ' m2', '') AS descriptif,
'' AS confort
FROM pevprofessionnelle po
JOIN infos ON infos.pev = po.pev
),
source AS (
SELECT
parcelle,
l_batiment, l_numero_entree, l_niveau_etage, l_numero_local, l_identifiant, l_numero_voirie, l_adresse,
l10_compte_proprietaire, l10_proprietaires, l10_date_acte, l10_type_local, l10_nature_local, l10_nature_construction_particuliere, l10_annee_construction, l10_nombre_niveaux,
pev_affectation, pev_lettre_serie, pev_categorie, pev_entretien, pev_valeur_locative, pev_nature_exoneration_permanente,
pev_numero_local_type, pev_coefficient_situation_particuliere, pev_coefficient_situation_generale,
co_vlbaia, gp_vlbaia, de_vlbaia, re_vlbaia, co_bipevla, gp_bipevla, de_bipevla, re_bipevla,
count(p.pev) AS nb_pev,
string_agg(
('Type: ' || type_pev || '
Sous-type: ' || Coalesce(sous_type_pev, '') || Coalesce('
' ||
'Bat: ' || l_batiment ||
'
Entrée: ' || l_numero_entree ||
'
Etage: ' || l_niveau_etage ||
'
Local: ' || l_numero_local ||
'
Identifiant: ' || l_identifiant ||
'
Adresse: ' || l_adresse ||
'
' ||
'Compte propriétaire: ' || l10_compte_proprietaire ||
'
Date de l''acte: ' || l10_date_acte ||
'
' ||
'Type: ' || l10_type_local ||
'
Nature: ' || l10_nature_local ||
'
Construction: ' || l10_nature_construction_particuliere ||
'
Année de construction: ' || l10_annee_construction ||
'
Niveaux: ' || l10_nombre_niveaux ||
'
' ||
'Affectation: ' || pev_affectation ||
'
Lettre de série: ' || pev_lettre_serie ||
'
Catégorie: ' || pev_categorie ||
'
Entretien: ' || Coalesce(pev_entretien, -1) ||
'
Valeur locative: ' || Coalesce(pev_valeur_locative, -1) ||
'
Exonération permanente: ' || Coalesce(pev_nature_exoneration_permanente, '') ||
'
Numéro du local type: ' || Coalesce(pev_numero_local_type, '') ||
'
Situation générale: ' || Coalesce(pev_coefficient_situation_generale, '') ||
'
Situation particulière: ' || Coalesce(pev_coefficient_situation_particuliere, '') ||
'
' ||
'Commune: ' || co_bipevla ||
'
Intercommunalité: ' || gp_bipevla ||
'
Département: ' || de_bipevla ||
'
Région: ' || re_bipevla ||
'
__________________________
' ||
replace(infos_pev, '@', '
__________________________
__________________________
') ||
'
__________________________' ||
'
' || replace(l10_proprietaires, '|', '
') || '
' ) , '