Skip to content

Commit

Permalink
feat: improve the display time of meshes on the species map
Browse files Browse the repository at this point in the history
  • Loading branch information
jpm-cbna committed Apr 12, 2024
1 parent 5a918b1 commit 3f90d47
Show file tree
Hide file tree
Showing 7 changed files with 131 additions and 43 deletions.
12 changes: 6 additions & 6 deletions atlas/atlasAPI.py
Original file line number Diff line number Diff line change
Expand Up @@ -56,7 +56,7 @@ def getObservationsMailleAndPointAPI(cd_ref):


@api.route("/observationsMaille/<int:cd_ref>", methods=["GET"])
def getObservationsMailleAPI(cd_ref, year_min=None, year_max=None):
def getObservationsMailleAPI(cd_ref):
"""
Retourne les observations d'un taxon par maille (et le nombre d'observation par maille)
Expand Down Expand Up @@ -94,17 +94,17 @@ def getObservationsGenericApi(cd_ref: int):
[type]: [description]
"""
session = db.session
observations = (
vmObservationsMaillesRepository.getObservationsMaillesChilds(
if current_app.config["AFFICHAGE_MAILLE"]:
observations = vmObservationsMaillesRepository.getObservationsMaillesChilds(
session,
cd_ref,
year_min=request.args.get("year_min"),
year_max=request.args.get("year_max"),
)
if current_app.config["AFFICHAGE_MAILLE"]
else vmObservationsRepository.searchObservationsChilds(session, cd_ref)
)
else:
observations = vmObservationsRepository.searchObservationsChilds(session, cd_ref)
session.close()

return jsonify(observations)


Expand Down
22 changes: 22 additions & 0 deletions atlas/modeles/entities/tMaillesTerritoire.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
# coding: utf-8
from geoalchemy2.types import Geometry
from sqlalchemy import Column, Integer, MetaData, Table, Text
from sqlalchemy.ext.declarative import declarative_base

from atlas.utils import engine

metadata = MetaData()
Base = declarative_base()


class TMaillesTerritoire(Base):
__table__ = Table(
"t_mailles_territoire",
metadata,
Column("id_maille", Integer, primary_key=True, unique=True),
Column("the_geom", Geometry()),
Column("geojson_maille", Text),
schema="atlas",
autoload=True,
autoload_with=engine,
)
9 changes: 4 additions & 5 deletions atlas/modeles/entities/vmObservations.py
Original file line number Diff line number Diff line change
Expand Up @@ -36,11 +36,10 @@ class VmObservationsMailles(Base):
__table__ = Table(
"vm_observations_mailles",
metadata,
Column("id_observation", Integer, primary_key=True, unique=True),
Column("id_maille", Integer),
Column("the_geom", Geometry),
Column("geojson_maille", Text),
Column("annee", String(1000)),
Column("cd_ref", Integer, primary_key=True, index=True),
Column("annee", String(1000), primary_key=True, index=True),
Column("id_maille", Integer, primary_key=True, index=True),
Column("nbr", Integer),
schema="atlas",
autoload=True,
autoload_with=db.engine,
Expand Down
29 changes: 19 additions & 10 deletions atlas/modeles/repositories/vmObservationsMaillesRepository.py
Original file line number Diff line number Diff line change
@@ -1,9 +1,10 @@
import json

from geojson import Feature, FeatureCollection
from sqlalchemy.sql import text, func, or_
from sqlalchemy.sql import text, func, any_

from atlas.modeles.entities.vmObservations import VmObservationsMailles
from atlas.modeles.entities.tMaillesTerritoire import TMaillesTerritoire
from atlas.modeles.utils import deleteAccent, findPath


Expand All @@ -12,17 +13,25 @@ def getObservationsMaillesChilds(session, cd_ref, year_min=None, year_max=None):
Retourne les mailles et le nombre d'observation par maille pour un taxon et ses enfants
sous forme d'un geojson
"""
subquery = session.query(func.atlas.find_all_taxons_childs(cd_ref))
query = session.query(func.atlas.find_all_taxons_childs(cd_ref))
taxons_ids = query.all()
taxons_ids.append(cd_ref)

query = (
session.query(
func.count(VmObservationsMailles.id_observation).label("nb_obs"),
func.max(VmObservationsMailles.annee).label("last_observation"),
VmObservationsMailles.id_maille,
VmObservationsMailles.geojson_maille,
TMaillesTerritoire.geojson_maille,
func.max(VmObservationsMailles.annee).label("last_obs_year"),
func.count(VmObservationsMailles.nbr).label("obs_nbr"),
)
.join(
TMaillesTerritoire,
TMaillesTerritoire.id_maille == VmObservationsMailles.id_maille,
)
.group_by(VmObservationsMailles.id_maille, VmObservationsMailles.geojson_maille)
.filter(
or_(VmObservationsMailles.cd_ref.in_(subquery), VmObservationsMailles.cd_ref == cd_ref)
.filter(VmObservationsMailles.cd_ref == any_(taxons_ids))
.group_by(
VmObservationsMailles.id_maille,
TMaillesTerritoire.geojson_maille,
)
)
if year_min and year_max:
Expand All @@ -35,8 +44,8 @@ def getObservationsMaillesChilds(session, cd_ref, year_min=None, year_max=None):
geometry=json.loads(o.geojson_maille),
properties={
"id_maille": o.id_maille,
"nb_observations": o.nb_obs,
"last_observation": o.last_observation,
"nb_observations": o.obs_nbr,
"last_observation": o.last_obs_year,
},
)
for o in query.all()
Expand Down
27 changes: 16 additions & 11 deletions data/atlas/12.atlas.t_mailles_territoire.sql
Original file line number Diff line number Diff line change
@@ -1,14 +1,19 @@
DROP TABLE IF EXISTS atlas.t_mailles_territoire;

-- MV for having only meshs of the territory
CREATE TABLE atlas.t_mailles_territoire
AS SELECT
st_transform(c.geom, 4326) AS the_geom,
st_asgeojson(st_transform(c.geom, 4326)) AS geojson_maille,
c.id_area AS id_maille
FROM ref_geo.l_areas c
JOIN ref_geo.bib_areas_types t ON t.id_type = c.id_type
JOIN atlas.t_layer_territoire mt ON ST_intersects(c.geom,st_transform(mt.the_geom, find_srid('ref_geo', 'l_areas', 'geom')))
WHERE c.enable = true AND t.type_code = :type_maille;
CREATE TABLE atlas.t_mailles_territoire AS
SELECT
st_transform(a.geom, 4326) AS the_geom,
st_asgeojson(st_transform(a.geom, 4326)) AS geojson_maille,
a.id_area AS id_maille
FROM ref_geo.l_areas AS a
JOIN ref_geo.bib_areas_types AS t
ON t.id_type = a.id_type
JOIN atlas.t_layer_territoire AS l
ON ST_intersects(a.geom, st_transform(l.the_geom, find_srid('ref_geo', 'l_areas', 'geom')))
WHERE a.enable = true
AND t.type_code = :type_maille ;

CREATE UNIQUE INDEX t_mailles_territoire_id_maille_idx ON atlas.t_mailles_territoire USING btree (id_maille);
CREATE UNIQUE INDEX ON atlas.t_mailles_territoire
USING btree (id_maille);
CREATE INDEX ON atlas.t_mailles_territoire
USING spgist (the_geom);
30 changes: 19 additions & 11 deletions data/atlas/13.atlas.vm_observations_mailles.sql
Original file line number Diff line number Diff line change
@@ -1,13 +1,21 @@
CREATE MATERIALIZED VIEW atlas.vm_observations_mailles
AS SELECT obs.cd_ref,
obs.id_observation,
m.id_maille,
m.geojson_maille,
date_part('year', dateobs) as annee
FROM atlas.vm_observations obs
JOIN atlas.t_mailles_territoire m ON st_intersects(obs.the_geom_point, m.the_geom)
CREATE MATERIALIZED VIEW atlas.vm_observations_mailles AS
SELECT
o.cd_ref,
date_part('year', o.dateobs) AS annee,
m.id_maille,
COUNT(o.id_observation) AS nbr
FROM atlas.vm_observations AS o
JOIN atlas.t_mailles_territoire AS m
ON (o.the_geom_point && m.the_geom)
GROUP BY o.cd_ref, date_part('year', o.dateobs), m.id_maille
ORDER BY o.cd_ref, annee
WITH DATA;

create unique index on atlas.vm_observations_mailles (id_observation);
create index on atlas.vm_observations_mailles (id_maille);
create index on atlas.vm_observations_mailles (cd_ref);
CREATE UNIQUE INDEX ON atlas.vm_observations_mailles
USING btree (cd_ref, annee, id_maille);

CREATE INDEX ON atlas.vm_observations_mailles
USING btree (annee);

CREATE INDEX ON atlas.vm_observations_mailles
USING btree (id_maille, cd_ref);
45 changes: 45 additions & 0 deletions data/update/update_1.6.1to1.6.2.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,45 @@
DROP MATERIALIZED VIEW IF EXISTS atlas.vm_observations_mailles;
DROP TABLE IF EXISTS atlas.t_mailles_territoire;


CREATE TABLE atlas.t_mailles_territoire AS
SELECT
st_transform(a.geom, 4326) AS the_geom,
st_asgeojson(st_transform(a.geom, 4326)) AS geojson_maille,
a.id_area AS id_maille
FROM ref_geo.l_areas AS a
JOIN ref_geo.bib_areas_types AS t
ON t.id_type = a.id_type
JOIN atlas.t_layer_territoire AS l
ON ST_intersects(a.geom, st_transform(l.the_geom, find_srid('ref_geo', 'l_areas', 'geom')))
WHERE a.enable = true
AND t.type_code = :type_maille ;

CREATE UNIQUE INDEX ON atlas.t_mailles_territoire
USING btree (id_maille);

CREATE INDEX ON atlas.t_mailles_territoire
USING spgist (the_geom);


CREATE MATERIALIZED VIEW atlas.vm_observations_mailles AS
SELECT
o.cd_ref,
date_part('year', o.dateobs) AS annee,
m.id_maille,
COUNT(o.id_observation) AS nbr
FROM atlas.vm_observations AS o
JOIN atlas.t_mailles_territoire AS m
ON (o.the_geom_point && m.the_geom)
GROUP BY o.cd_ref, date_part('year', o.dateobs), m.id_maille
ORDER BY o.cd_ref, annee
WITH DATA;

CREATE UNIQUE INDEX ON atlas.vm_observations_mailles
USING btree (cd_ref, annee, id_maille);

CREATE INDEX ON atlas.vm_observations_mailles
USING btree (annee);

CREATE INDEX ON atlas.vm_observations_mailles
USING btree (id_maille, cd_ref);

0 comments on commit 3f90d47

Please sign in to comment.