Skip to content
GitLab
Explore
Sign in
Register
Primary navigation
Search or go to…
Project
datacirco-prepare-data
Manage
Activity
Members
Labels
Plan
Issues
Issue boards
Milestones
Wiki
Code
Merge requests
Repository
Branches
Commits
Tags
Repository graph
Compare revisions
Snippets
Build
Pipelines
Jobs
Pipeline schedules
Artifacts
Deploy
Releases
Package registry
Container registry
Model registry
Operate
Environments
Terraform modules
Monitor
Incidents
Service Desk
Analyze
Value stream analytics
Contributor analytics
CI/CD analytics
Repository analytics
Model experiments
Help
Help
Support
GitLab documentation
Compare GitLab plans
GitLab community forum
Contribute to GitLab
Provide feedback
Keyboard shortcuts
?
Snippets
Groups
Projects
Show more breadcrumbs
leximpact
DataCirco
datacirco-prepare-data
Commits
e3581a10
Commit
e3581a10
authored
6 months ago
by
Benoît Courty
Browse files
Options
Downloads
Patches
Plain Diff
Optimisation du temps de traitement
parent
6d0060ed
No related branches found
No related tags found
1 merge request
!52
Prepare prod
Changes
2
Show whitespace changes
Inline
Side-by-side
Showing
2 changed files
datacirco/modules_data/logement_data.py
+17
-17
17 additions, 17 deletions
datacirco/modules_data/logement_data.py
populate_db/logements.py
+44
-0
44 additions, 0 deletions
populate_db/logements.py
with
61 additions
and
17 deletions
datacirco/modules_data/logement_data.py
+
17
−
17
View file @
e3581a10
...
...
@@ -534,22 +534,22 @@ class GetLogement:
]
if
len
(
self
.
data
.
logements
.
dpe
)
>
4
and
len
(
self
.
data
.
logements
.
dpe_dep
)
>
4
:
sql1
=
f
"""
SELECT classe_ges, coalesce(a.annee_2013, 0) as annee_2013, coalesce(a.annee_2014, 0) as annee_2014, coalesce(a.annee_2015, 0) as annee_2015,
coalesce(a.annee_2016, 0) as annee_2016, coalesce(a.annee_2017, 0) as annee_2017, coalesce(a.annee_2018, 0) as annee_2018
,
coalesce(
a.
annee_201
9
, 0) as annee_201
9
, coalesce(
a.
annee_20
20
, 0) as annee_20
20
, coalesce(
a.
annee_20
2
1, 0) as annee_20
2
1
FROM (
select * from crosstab(
$$SELECT d.classe_estimation_ges, LEFT(d.date_etablissement_dpe,4) as annee_etablissement_DPE,
coalesce(COUNT(DISTINCT d.numero_dpe), 0) as nb_ges
FROM ademe_dpe_logements as d
LEFT JOIN zone_circo c
ON st_intersects(c.wkb_geometry, d.geom
)
WHERE (c.ref =
'
{
self
.
circo
}
'
OR (d.geom IS NULL AND (d.code_insee_commune_actualise in (
{
in_communes
}
))))
AND LEFT(d.date_etablissement_dpe,4) between
'
2013
'
and
'
2021
'
AND d.classe_estimation_ges IN (
'
A
'
,
'
B
'
,
'
C
'
,
'
D
'
,
'
E
'
,
'
F
'
,
'
G
'
)
GROUP BY 1,2
ORDER BY 1,2$$,
sql1
=
f
"""
SELECT classe_ges
,
coalesce(annee_201
3
, 0) as annee_201
3
, coalesce(annee_20
14
, 0) as annee_20
14
, coalesce(annee_201
5
, 0) as annee_201
5,
coalesce(annee_2016, 0) as annee_2016, coalesce(annee_2017, 0) as annee_2017, coalesce(annee_2018, 0) as annee_2018,
coalesce(annee_2019, 0) as annee_2019, coalesce(annee_2020, 0) as annee_2020, coalesce(annee_2021, 0) as annee_2021
FROM crosstab(
$$SELECT
classe_estimation_ges,
annee,
SUM(nb_ges
)
FROM mv_dpe_stats_2013_2021
WHERE circonscription =
'
{
self
.
circo
}
'
GROUP BY 1,2
ORDER BY 1,2$$,
$$SELECT generate_series(2013,2021)$$
)
as
T (
)
AS
T (
classe_ges text,
"
annee_2013
"
int,
"
annee_2014
"
int,
...
...
@@ -560,7 +560,7 @@ class GetLogement:
"
annee_2019
"
int,
"
annee_2020
"
int,
"
annee_2021
"
int
)
) as a
;
);
"""
utilitaires
.
db_exec
(
self
.
db
.
mogrify
(
sql1
))
liste_ges_avant_2021
=
[
...
...
This diff is collapsed.
Click to expand it.
populate_db/logements.py
+
44
−
0
View file @
e3581a10
...
...
@@ -55,6 +55,10 @@ run(
UPDATE
{
table_name
}
SET geom=ST_SetSRID(ST_Makepoint(longitude::numeric, latitude::numeric),4326);
CREATE INDEX
{
table_name
}
_geom ON
{
table_name
}
USING GIST (geom);
CLUSTER
{
table_name
}
USING
{
table_name
}
_geom;
-- Pour les filtres principaux
CREATE INDEX idx_dpe_code_insee ON ademe_dpe_logements(code_insee_commune_actualise);
CREATE INDEX idx_dpe_date ON ademe_dpe_logements((LEFT(date_etablissement_dpe, 4)));
CREATE INDEX idx_dpe_classe_ges ON ademe_dpe_logements(classe_estimation_ges);
"""
)
...
...
@@ -117,6 +121,46 @@ run(
"""
)
print
(
"
Creation d
'
une MATERIALIZED VIEW pour les DPE 2013 à 2021, cela va être long... 14 minutes
"
)
run
(
"""
-- Création d
'
une table de liaison circonscription/communes
CREATE MATERIALIZED VIEW mv_circo_communes AS
SELECT ref, unnest(communes) AS code_insee
FROM zone_circo;
-- Index pour les jointures sur les codes INSEE
CREATE INDEX idx_mv_circo_communes ON mv_circo_communes(ref, code_insee);
-- Vue matérialisée principale
CREATE MATERIALIZED VIEW mv_dpe_stats_2013_2021 AS
SELECT
COALESCE(c1.ref, c2.ref) AS circonscription,
d.classe_estimation_ges,
LEFT(d.date_etablissement_dpe,4) AS annee,
COUNT(DISTINCT d.numero_dpe) AS nb_ges,
BOOL_OR(d.geom IS NOT NULL) AS via_geom,
BOOL_OR(d.geom IS NULL) AS via_insee
FROM ademe_dpe_logements d
LEFT JOIN zone_circo c1
ON d.geom IS NOT NULL
AND ST_Intersects(c1.wkb_geometry, d.geom)
LEFT JOIN mv_circo_communes c2
ON d.geom IS NULL
AND d.code_insee_commune_actualise = c2.code_insee
WHERE d.classe_estimation_ges IN (
'
A
'
,
'
B
'
,
'
C
'
,
'
D
'
,
'
E
'
,
'
F
'
,
'
G
'
)
GROUP BY 1, 2, 3;
CREATE INDEX idx_mv_dpe_circo ON mv_dpe_stats_2013_2021(circonscription);
CREATE INDEX idx_mv_dpe_annee ON mv_dpe_stats_2013_2021(annee);
CREATE INDEX idx_mv_dpe_classe ON mv_dpe_stats_2013_2021(classe_estimation_ges);
"""
)
print
(
"
Base DPE des logements 2024
"
)
table
=
"
ademe_dpe_logements_2024
"
...
...
This diff is collapsed.
Click to expand it.
Preview
0%
Loading
Try again
or
attach a new file
.
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Save comment
Cancel
Please
register
or
sign in
to comment