USE batiments; -- Table temp pour FFO (nb_niveau, nb_log) DROP TABLE IF EXISTS tmp_ffo_999; CREATE TABLE tmp_ffo_999 ( batiment_groupe_id VARCHAR(50), code_departement_insee VARCHAR(5), nb_niveau INT, annee_construction INT, usage_niveau_1_txt VARCHAR(100), mat_mur_txt VARCHAR(100), mat_toit_txt VARCHAR(100), nb_log INT, KEY (batiment_groupe_id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; LOAD DATA LOCAL INFILE '/var/osm/csv/batiment_groupe_ffo_bat.csv' INTO TABLE tmp_ffo_999 CHARACTER SET 'UTF8mb4' FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' IGNORE 1 LINES; -- Table temp pour Adresse (lien BAN) DROP TABLE IF EXISTS tmp_adr_999; CREATE TABLE tmp_adr_999 ( wkt TEXT, batiment_groupe_id VARCHAR(50), cle_interop_adr VARCHAR(50), code_departement_insee VARCHAR(5), classe VARCHAR(50), lien_valide TINYINT, origine VARCHAR(50), KEY (batiment_groupe_id), KEY (cle_interop_adr) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; LOAD DATA LOCAL INFILE '/var/osm/csv/rel_batiment_groupe_adresse.csv' INTO TABLE tmp_adr_999 CHARACTER SET 'UTF8mb4' FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' IGNORE 1 LINES; -- Table temp pour RNC (copropriétés) DROP TABLE IF EXISTS tmp_rnc_999; CREATE TABLE tmp_rnc_999 ( batiment_groupe_id VARCHAR(50), code_departement_insee VARCHAR(5), numero_immat_principal VARCHAR(50), periode_construction_max VARCHAR(50), l_annee_construction VARCHAR(100), nb_lot_garpark INT, nb_lot_tot INT, nb_log INT, nb_lot_tertiaire INT, l_nom_copro VARCHAR(200), l_siret VARCHAR(50), copro_dans_pvd TINYINT, KEY (batiment_groupe_id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; LOAD DATA LOCAL INFILE '/var/osm/csv/batiment_groupe_rnc.csv' INTO TABLE tmp_rnc_999 CHARACTER SET 'UTF8mb4' FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' IGNORE 1 LINES; -- Table temp pour BDTOPO (altitude) DROP TABLE IF EXISTS tmp_topo_999; CREATE TABLE tmp_topo_999 ( batiment_groupe_id VARCHAR(50), code_departement_insee VARCHAR(5), l_nature VARCHAR(200), l_usage_1 VARCHAR(200), l_usage_2 VARCHAR(200), l_etat VARCHAR(100), hauteur_mean DECIMAL(10,2), max_hauteur DECIMAL(10,2), altitude_sol_mean DECIMAL(10,2), KEY (batiment_groupe_id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; LOAD DATA LOCAL INFILE '/var/osm/csv/batiment_groupe_bdtopo_bat.csv' INTO TABLE tmp_topo_999 CHARACTER SET 'UTF8mb4' FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' IGNORE 1 LINES; -- Table temp pour Usage principal DROP TABLE IF EXISTS tmp_usage_999; CREATE TABLE tmp_usage_999 ( batiment_groupe_id VARCHAR(50), code_departement_insee VARCHAR(5), usage_principal_bdnb_open VARCHAR(100), KEY (batiment_groupe_id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; LOAD DATA LOCAL INFILE '/var/osm/csv/batiment_groupe_synthese_propriete_usage.csv' INTO TABLE tmp_usage_999 CHARACTER SET 'UTF8mb4' FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' IGNORE 1 LINES; -- Table temp pour DLE Enedis (compteurs électriques) DROP TABLE IF EXISTS tmp_dle_999; CREATE TABLE tmp_dle_999 ( batiment_groupe_id VARCHAR(50), code_departement_insee VARCHAR(5), millesime VARCHAR(10), nb_pdl_res INT, nb_pdl_pro INT, nb_pdl_tot INT, conso_res DECIMAL(12,2), conso_pro DECIMAL(12,2), conso_tot DECIMAL(12,2), conso_res_par_pdl DECIMAL(12,2), conso_pro_par_pdl DECIMAL(12,2), conso_tot_par_pdl DECIMAL(12,2), KEY (batiment_groupe_id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; LOAD DATA LOCAL INFILE '/var/osm/csv/batiment_groupe_dle_elec_multimillesime.csv' INTO TABLE tmp_dle_999 CHARACTER SET 'UTF8mb4' FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' IGNORE 1 LINES; -- Création de la table finale avec jointure et filtre DROP TABLE IF EXISTS bat999; CREATE TABLE bat999 ( batiment_groupe_id VARCHAR(50) PRIMARY KEY, code_departement_insee VARCHAR(5), cle_interop_adr VARCHAR(50), nb_niveau INT, nb_log INT, nb_pdl_tot INT, annee_construction INT, residence VARCHAR(200), usage_principal VARCHAR(100), altitude_sol_mean DECIMAL(10,2), gps_lat DECIMAL(10,7), gps_lng DECIMAL(10,7), KEY (cle_interop_adr), KEY (usage_principal), KEY (nb_log) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; INSERT INTO bat999 SELECT f.batiment_groupe_id, f.code_departement_insee, a.cle_interop_adr, f.nb_niveau, f.nb_log, d.nb_pdl_tot, f.annee_construction, REPLACE(REPLACE(REPLACE(REPLACE(r.l_nom_copro, '[', ''), ']', ''), '"', ''), ' ', ' ') as residence, u.usage_principal_bdnb_open as usage_principal, t.altitude_sol_mean, NULL as gps_lat, NULL as gps_lng FROM tmp_ffo_999 f INNER JOIN tmp_adr_999 a ON f.batiment_groupe_id = a.batiment_groupe_id AND a.lien_valide = 1 LEFT JOIN tmp_rnc_999 r ON f.batiment_groupe_id = r.batiment_groupe_id LEFT JOIN tmp_topo_999 t ON f.batiment_groupe_id = t.batiment_groupe_id LEFT JOIN tmp_usage_999 u ON f.batiment_groupe_id = u.batiment_groupe_id LEFT JOIN tmp_dle_999 d ON f.batiment_groupe_id = d.batiment_groupe_id WHERE u.usage_principal_bdnb_open IN ('Résidentiel individuel', 'Résidentiel collectif', 'Secondaire', 'Tertiaire') AND f.nb_log > 1 AND a.cle_interop_adr IS NOT NULL GROUP BY f.batiment_groupe_id; -- Mise à jour des coordonnées GPS depuis la base adresses UPDATE bat999 b JOIN adresses.cp999 a ON b.cle_interop_adr = a.id SET b.gps_lat = a.gps_lat, b.gps_lng = a.gps_lng WHERE b.cle_interop_adr IS NOT NULL; -- Nettoyage des tables temporaires DROP TABLE IF EXISTS tmp_ffo_999; DROP TABLE IF EXISTS tmp_adr_999; DROP TABLE IF EXISTS tmp_rnc_999; DROP TABLE IF EXISTS tmp_topo_999; DROP TABLE IF EXISTS tmp_usage_999; DROP TABLE IF EXISTS tmp_dle_999; -- Historique INSERT INTO _histo SET date_import=NOW(), dept='999', nb_batiments=(SELECT COUNT(*) FROM bat999);