# -*- coding: utf-8 -*- """ /*************************************************************************** BackinMFU A QGIS plugin Permet de créer une nouvelle session d'animation foncière ------------------- begin : 2015-10-02 git sha : $Format:%H$ copyright : (C) 2015 by CEN Savoie email : a.lesconnec@cen-savoie.org ***************************************************************************/ /*************************************************************************** * * * This program is free software; you can redistribute it and/or modify * * it under the terms of the GNU General Public License as published by * * the Free Software Foundation; either version 2 of the License, or * * (at your option) any later version. * * * ***************************************************************************/ """ from PyQt5 import QtCore, QtGui from PyQt5.QtCore import * from PyQt5.QtGui import * from PyQt5.QtWidgets import QAction, QTableWidgetItem from PyQt5.QtXml import QDomDocument from qgis.core import * from qgis.gui import * # Initialize Qt resources from file resources.py from pluginsCenSavoie_v3 import resources # Import the code for the dialog from pluginsCenSavoie_v3.tools.backinMFU_dialog import BackinMFUDialog # Import du fichier de configuration from pluginsCenSavoie_v3.tools.confPython import bd_cen_host, bd_cen_port, bd_cen_name, bd_cen_mdp_1st_cnx import os.path import sys import qgis import os import psycopg2 import psycopg2.extras import base64 import re from time import localtime, strftime class BackinMFU: """QGIS Plugin Implementation.""" def __init__(self, iface, cenToolbar): """Constructor. :param iface: An interface instance that will be passed to this class which provides the hook by which you can manipulate the QGIS application at run time. :type iface: QgsInterface """ # Variable HOTE de l'accès à la base de données global host host = bd_cen_host global port port = bd_cen_port global bdd bdd = bd_cen_name global mdp_1st_cnx mdp_1st_cnx = bd_cen_mdp_1st_cnx global os_user if sys.platform in ('linux','darwin'): os_user = os.environ['USER'] else: os_user = os.environ['USERNAME'] # Save reference to the QGIS interface self.iface = iface self.canvas = self.iface.mapCanvas() # initialize plugin directory self.plugin_dir = os.path.dirname(__file__) # Create the dialog (after translation) and keep reference self.dlg = BackinMFUDialog() # Add toolbar button self.action= QAction(QIcon(":/plugins/pluginsCenSavoie_v3/icons/backinMFU.png"), QCoreApplication.translate('BackinMFU', u'Retour vers la MFU'), self.iface.mainWindow()) self.action.triggered.connect(self.run) self.action.setEnabled(True) cenToolbar.addAction(self.action) def run(self): """Run method that performs all the real work""" # show the dialog self.dlg.img_logo.setPixmap(QPixmap(":/plugins/pluginsCenSavoie_v3/tools/images/Logo_CEN_Savoie.png")) self.dlg.lbl_delorean.setPixmap(QPixmap(":/plugins/pluginsCenSavoie_v3/tools/images/delorean.png")) self.dlg.lbl_fond.setPixmap(QPixmap(":/plugins/pluginsCenSavoie_v3/tools/images/fond_70.png")) self.dlg.lbl_fond.stackUnder(self.dlg.button_box) self.dlg.show() # Run the dialog event loop result = self.dlg.exec_() # See if OK was pressed if result: first_conn = psycopg2.connect("host=" + host + " port=" + port + " dbname=" + bdd + " user=first_cnx password=" + mdp_1st_cnx) first_cur = first_conn.cursor(cursor_factory = psycopg2.extras.DictCursor) first_cur.execute("SELECT mdp_cen, usename FROM pg_catalog.pg_user t1, admin_sig.utilisateurs t2 WHERE t2.oid = t1.usesysid AND (utilisateur_id = '" + os_user + "' OR utilisateur_os = '" + os_user + "')") res_ident = first_cur.fetchone() mdp = base64.b64decode(str(res_ident[0])).decode('utf-8') user = res_ident[1] first_conn.close() uri = QgsDataSourceUri() uri.setConnection(host ,port ,bdd ,user ,mdp) calDate = self.dlg.calSelect.selectedDate().toString('yyyy-MM-dd') table_name = 'mfu_'+calDate sql = """ WITH RECURSIVE table_lot AS ( SELECT site_id, old_cad_site_id, new_lot_id, new_lot_id AS lot_id_origin, 0 AS level, ARRAY[old_cad_site_id, new_cad_site_id] as tbl_cad_site_id FROM foncier_maj.vm_filiation_parcelles WHERE diff_surf = 0 UNION SELECT v.site_id, v.old_cad_site_id, v.new_lot_id, t.lot_id_origin, t.level + 1, CASE WHEN v.old_cad_site_id = ANY (t.tbl_cad_site_id) THEN CASE WHEN v.new_cad_site_id = ANY (t.tbl_cad_site_id) THEN t.tbl_cad_site_id ELSE array_append(t.tbl_cad_site_id, v.new_cad_site_id) END ELSE CASE WHEN v.new_cad_site_id = ANY (t.tbl_cad_site_id) THEN array_append(t.tbl_cad_site_id, v.old_cad_site_id) ELSE array_append(array_append(t.tbl_cad_site_id, v.old_cad_site_id), v.new_cad_site_id) END END FROM foncier_maj.vm_filiation_parcelles as v INNER JOIN table_lot as t ON (t.old_cad_site_id = v.new_cad_site_id) WHERE diff_surf = 0 ), t_max_level AS ( SELECT lot_id_origin, max(level) as level FROM table_lot GROUP BY lot_id_origin ), t_filiation_lots AS ( SELECT DISTINCT table_lot.site_id, table_lot.lot_id_origin, table_lot.tbl_cad_site_id FROM table_lot JOIN t_max_level USING (lot_id_origin, level) LEFT JOIN table_lot as table_lot2 ON (table_lot2.tbl_cad_site_id @> table_lot.tbl_cad_site_id AND table_lot2.tbl_cad_site_id <> table_lot.tbl_cad_site_id AND table_lot2.site_id = table_lot.site_id) WHERE table_lot2.tbl_cad_site_id IS NULL ), tprob AS ( SELECT DISTINCT unnest(string_to_array(array_to_string(array_agg(site_id), ','), ',')) AS site_id FROM ( SELECT DISTINCT site_id FROM alertes.v_prob_mfu_baddata UNION SELECT DISTINCT site_id FROM alertes.v_prob_cadastre_cen WHERE statutmfu_id = 1 UNION SELECT DISTINCT site_id FROM alertes.v_alertes_mu WHERE alerte LIKE 'termin%' UNION SELECT DISTINCT substring(v_prob_mfu_sansparc.mfu_id::text, 4, 4) AS site_id FROM alertes.v_prob_mfu_sansparc ) tsousprob ), t_actes AS ( SELECT acte, mfu_id, COALESCE(date_effet_conv, date_sign_acte) as date_acte_debut, COALESCE(NULLIF(date_fin_acte, 'N.D.'), COALESCE(last_end, 'infini')) as date_acte_fin FROM alertes.v_tdb_mfu WHERE statutmfu_id NOT IN (0, 3) ), t_temp_mu AS ( SELECT DISTINCT cadastre_site.site_id, par_id, COALESCE(lot_id_origin, lot_id) AS lot_id, COALESCE(r_cad_site_mu.surf_mu, dcntlo) as dcntlo, COALESCE(r_cad_site_mu.geom, parcelles_cen.geom) as geom, CASE WHEN surf_mu IS NOT NULL THEN 'Convention pour partie' ELSE 'Convention' END AS mfu, mu_id AS mfu_id, r_cad_site_mu.date_entree, r_cad_site_mu.date_sortie, r_cad_site_mu.motif_entree_id FROM cadastre.parcelles_cen JOIN cadastre.lots_cen USING (par_id) JOIN cadastre.cadastre_cen USING (lot_id) JOIN foncier.cadastre_site USING (cad_cen_id) JOIN foncier.r_cad_site_mu USING (cad_site_id) JOIN foncier.mu_conventions USING (mu_id) JOIN foncier.d_typmu USING (typmu_id) LEFT JOIN t_filiation_lots ON (t_filiation_lots.site_id = cadastre_site.site_id AND cad_site_id = ANY(tbl_cad_site_id)) WHERE d_typmu.mfu = 't' ), t_synthese_mu AS ( SELECT site_id, par_id, lot_id, dcntlo as surf_mfu, geom, mfu, mfu_id, date_acte_debut, GREATEST(MIN(date_entree), date_acte_debut) as min_date_entree_mu, LEAST(MAX(date_sortie), date_acte_fin) as max_date_sortie_mu FROM t_temp_mu JOIN t_actes USING (mfu_id) GROUP BY t_temp_mu.site_id, t_temp_mu.par_id, t_temp_mu.lot_id, t_temp_mu.dcntlo, t_temp_mu.geom, t_temp_mu.mfu, t_temp_mu.mfu_id, t_actes.date_acte_debut, t_actes.date_acte_fin ), t_temp_mf AS ( SELECT DISTINCT cadastre_site.site_id, par_id, COALESCE(lot_id_origin, lot_id) AS lot_id, dcntlo, parcelles_cen.geom, 'Acquisition' AS mfu, mf_id AS mfu_id, r_cad_site_mf.date_entree, r_cad_site_mf.date_sortie FROM cadastre.parcelles_cen JOIN cadastre.lots_cen USING (par_id) JOIN cadastre.cadastre_cen USING (lot_id) JOIN foncier.cadastre_site USING (cad_cen_id) JOIN foncier.r_cad_site_mf USING (cad_site_id) LEFT JOIN t_filiation_lots ON (t_filiation_lots.site_id = cadastre_site.site_id AND cad_site_id = ANY(tbl_cad_site_id)) ), t_synthese_mf AS ( SELECT site_id, par_id, lot_id, dcntlo as surf_mfu, geom, mfu, mfu_id, date_acte_debut, GREATEST(MIN(date_entree), date_acte_debut) as min_date_entree_mf, LEAST(MAX(date_sortie), date_acte_fin) as max_date_sortie_mf FROM t_temp_mf JOIN t_actes USING (mfu_id) GROUP BY t_temp_mf.site_id, t_temp_mf.lot_id, t_temp_mf.par_id, t_temp_mf.dcntlo, t_temp_mf.geom, t_temp_mf.mfu, t_temp_mf.mfu_id, t_actes.date_acte_debut, t_actes.date_acte_fin ), tmfu AS ( SELECT DISTINCT site_id, par_id, geom, lot_id, surf_mfu as surf_acq, 0 as surf_conv, mfu, mfu_id as acte_id, date_acte_debut, LEFT(min_date_entree_mf, 10) AS min_date_entree_mf, LEFT(max_date_sortie_mf, 10) AS max_date_sortie_mf, '3000-01-01' as min_date_entree_mu, '3000-12-31' as max_date_sortie_mu, 0 AS motif_entree_id_mu, CASE WHEN tprob.site_id IS NOT NULL THEN 1 ELSE 0 END as etat_bilan FROM t_synthese_mf LEFT JOIN tprob USING (site_id) UNION SELECT DISTINCT t_synthese_mu.site_id, t_synthese_mu.par_id, t_synthese_mu.geom, t_synthese_mu.lot_id, 0 as surf_acq, surf_mfu as surf_conv, t_synthese_mu.mfu, t_synthese_mu.mfu_id as acte_id, date_acte_debut, '3000-01-01' as min_date_entree_mf, '3000-12-31' as max_date_sortie_mf, LEFT(min_date_entree_mu, 10) AS min_date_entree_mu, LEFT(max_date_sortie_mu, 10) AS max_date_sortie_mu, motif_entree_id AS motif_entree_id_mu, CASE WHEN tprob.site_id IS NOT NULL THEN 1 ELSE 0 END as etat_bilan FROM t_synthese_mu JOIN t_temp_mu ON (t_synthese_mu.site_id = t_temp_mu.site_id AND t_synthese_mu.min_date_entree_mu = t_temp_mu.date_entree AND t_synthese_mu.mfu_id = t_temp_mu.mfu_id AND t_synthese_mu.lot_id = t_temp_mu.lot_id) LEFT JOIN tprob ON (t_synthese_mu.site_id = tprob.site_id) ), t_bilan1 AS ( SELECT DISTINCT site_id, lot_id, par_id, geom, mfu, acte_id, min_date_entree_mf, max_date_sortie_mf, min_date_entree_mu, max_date_sortie_mu, CASE WHEN mfu = 'Acquisition' AND min_date_entree_mf <= '"""+calDate+"""' AND (max_date_sortie_mf = 'N.D.' OR max_date_sortie_mf >= '"""+calDate+"""') THEN surf_acq ELSE 0 END AS surf_acqu, CASE WHEN mfu LIKE 'Convention%' AND min_date_entree_mu <= '"""+calDate+"""' AND (max_date_sortie_mu = 'N.D.' OR max_date_sortie_mu >= '"""+calDate+"""') THEN surf_conv ELSE 0 END AS surf_conv, etat_bilan FROM tmfu ), tmfu_one_day1 AS ( SELECT tmfu.*, t_bilan1.surf_acqu, t_bilan1.surf_conv FROM t_bilan1 JOIN tmfu USING (lot_id) WHERE (t_bilan1.surf_acqu > 0 AND t_bilan1.max_date_sortie_mf = '"""+calDate+"""') OR (t_bilan1.surf_conv > 0 AND t_bilan1.max_date_sortie_mu = '"""+calDate+"""') ), tmfu_one_day2 AS ( SELECT old_lot_id, array_agg(new_lot_id) as tbl_lot_one_day FROM tmfu_one_day1 JOIN foncier_maj.vm_filiation_parcelles ON (lot_id = old_lot_id AND tmfu_one_day1.site_id = vm_filiation_parcelles.site_id) JOIN tmfu ON (new_lot_id = tmfu.lot_id) WHERE ( surf_acqu > 0 AND tmfu.min_date_entree_mf != 'N.D.' AND tmfu_one_day1.max_date_sortie_mf != 'N.D.' AND tmfu.min_date_entree_mf::date = tmfu_one_day1.max_date_sortie_mf::date +'1 day'::interval ) OR ( tmfu.surf_conv > 0 AND tmfu.min_date_entree_mu != 'N.D.' AND tmfu_one_day1.max_date_sortie_mu != 'N.D.' AND tmfu.min_date_entree_mu::date = tmfu_one_day1.max_date_sortie_mu::date +'1 day'::interval ) GROUP BY old_lot_id UNION SELECT new_lot_id, array_agg(old_lot_id) as tbl_lot_one_day FROM tmfu_one_day1 JOIN foncier_maj.vm_filiation_parcelles ON (lot_id = new_lot_id AND tmfu_one_day1.site_id = vm_filiation_parcelles.site_id) JOIN tmfu ON (old_lot_id = tmfu.lot_id) WHERE ( surf_acqu > 0 AND tmfu.max_date_sortie_mf != 'N.D.' AND tmfu_one_day1.min_date_entree_mf != 'N.D.' AND tmfu.max_date_sortie_mf::date = tmfu_one_day1.min_date_entree_mf::date -'1 day'::interval ) OR ( tmfu.surf_conv > 0 AND tmfu.max_date_sortie_mu != 'N.D.' AND tmfu_one_day1.min_date_entree_mu != 'N.D.' AND tmfu.max_date_sortie_mu::date = tmfu_one_day1.min_date_entree_mu::date -'1 day'::interval ) GROUP BY new_lot_id ), t_bilan2 AS ( SELECT DISTINCT tmfu.site_id, old_lot_id as lot_id, par_id, geom, mfu, tmfu.acte_id, tmfu.min_date_entree_mf, tmfu.max_date_sortie_mf, tmfu.min_date_entree_mu, tmfu.max_date_sortie_mu, CASE WHEN tmfu.mfu = 'Acquisition' THEN tmfu.surf_acq ELSE 0 END AS surf_acqu, CASE WHEN tmfu.mfu LIKE 'Convention%' THEN tmfu.surf_conv ELSE 0 END AS surf_conv, tmfu.etat_bilan FROM tmfu_one_day2 JOIN tmfu ON (tmfu.lot_id = ANY(tbl_lot_one_day)) ), t_bilan3 AS ( SELECT site_id, par_id, geom, mfu, COALESCE(SUM(surf_acqu), 0) AS surf_acqu, COALESCE(SUM(surf_conv), 0) AS surf_conv, MAX(etat_bilan) AS etat_bilan FROM (SELECT * FROM t_bilan1 UNION SELECT * FROM t_bilan2) as t GROUP BY site_id, par_id, geom, mfu HAVING SUM(surf_acqu) > 0 OR SUM(surf_conv) > 0 ), t_bilan4 AS ( SELECT DISTINCT t_bilan3.par_id, sites.site_id, array_to_string(array_agg(DISTINCT mfu ORDER BY mfu), ' / ') as mfu, SUM(CASE WHEN surf_acqu > 0 THEN surf_acqu ELSE surf_conv END) as surf_mfu, MAX(geom) as geom, etat_bilan FROM sites.sites JOIN t_bilan3 USING (site_id) GROUP BY t_bilan3.par_id, sites.site_id, t_bilan3.etat_bilan ) SELECT row_number() OVER (ORDER BY par_id) AS gid, t_bilan4.* FROM t_bilan4 ORDER BY site_id, par_id """ uri.setDataSource("", u"(%s\n)" % sql, "geometrie", "", "gid") layer = self.iface.addVectorLayer(uri.uri(), table_name, "postgres") styleText = layer.getStyleFromDatabase(str(22))[0] styleDoc = QDomDocument() styleDoc.setContent(styleText) layer.importNamedStyle(styleDoc) self.dlg.close() self.canvas.refresh()