diff --git a/.github/workflows/pytest.yml b/.github/workflows/pytest.yml index 66b710f..19417b6 100644 --- a/.github/workflows/pytest.yml +++ b/.github/workflows/pytest.yml @@ -66,7 +66,7 @@ jobs: uses: actions/setup-python@v4 with: python-version: ${{ matrix.python-version }} - cache: 'pip' + cache: "pip" - name: Install GDAL run: | sudo apt update diff --git a/dependencies/Utils-Flask-SQLAlchemy-Geo b/dependencies/Utils-Flask-SQLAlchemy-Geo index ed2a05f..2b5002b 160000 --- a/dependencies/Utils-Flask-SQLAlchemy-Geo +++ b/dependencies/Utils-Flask-SQLAlchemy-Geo @@ -1 +1 @@ -Subproject commit ed2a05f04f562be41cfc482c28bfc5aa30382b6b +Subproject commit 2b5002bf13762d1c49b5d18516cd72d82861f12c diff --git a/requirements.in b/requirements.in index 58c4b02..1403ea0 100755 --- a/requirements.in +++ b/requirements.in @@ -1,8 +1,9 @@ alembic flask>=2.1 flask-sqlalchemy +flask-marshmallow python-dotenv sqlalchemy>=1.4,<2 utils-flask-sqlalchemy>=0.3.0 -utils-flask-sqlalchemy-geo>=0.2.4 +utils-flask-sqlalchemy-geo>=0.2.8 psycopg2 diff --git a/src/ref_geo/env.py b/src/ref_geo/env.py index 9517d1d..4818622 100644 --- a/src/ref_geo/env.py +++ b/src/ref_geo/env.py @@ -2,6 +2,7 @@ from importlib import import_module from flask_sqlalchemy import SQLAlchemy +from flask_marshmallow import Marshmallow db_path = environ.get("FLASK_SQLALCHEMY_DB") @@ -14,4 +15,16 @@ environ["FLASK_SQLALCHEMY_DB"] = f"{__name__}.db" -__all__ = ["db"] +ma_path = environ.get("FLASK_MARSHMALLOW") +if ma_path and ma_path != f"{__name__}.ma": + ma_module_name, ma_object_name = ma_path.rsplit(".", 1) + ma_module = import_module(ma_module_name) + ma = getattr(ma_module, ma_object_name) +else: + ma = Marshmallow() + environ["FLASK_MARSHMALLOW"] = f"{__name__}.ma" + ma.SQLAlchemySchema.OPTIONS_CLASS.session = db.session + ma.SQLAlchemyAutoSchema.OPTIONS_CLASS.session = db.session + + +__all__ = ["db", "ma"] diff --git a/src/ref_geo/migrations/utils.py b/src/ref_geo/migrations/utils.py index 9a5da6c..9df8739 100644 --- a/src/ref_geo/migrations/utils.py +++ b/src/ref_geo/migrations/utils.py @@ -14,12 +14,26 @@ schema = "ref_geo" -""" -Supprimer les zones d’un type donnée, e.g. 'DEP', 'COM', … -""" +def geom_4326_exists(): + return ( + op.get_bind() + .execute( + """ + SELECT EXISTS ( + SELECT 1 + FROM information_schema.COLUMNS + WHERE table_schema = 'ref_geo' AND table_name='l_areas' AND column_name = 'geom_4326' + ) + """ + ) + .scalar() + ) def delete_area_with_type(area_type): + """ + Supprimer les zones d’un type donnée, e.g. 'DEP', 'COM', … + """ op.execute( f""" DELETE FROM {schema}.l_areas la @@ -52,18 +66,33 @@ def create_temporary_grids_table(schema, temp_table_name): def insert_grids_and_drop_temporary_table(schema, temp_table_name, area_type): logger.info("Copy grids in l_areas…") - op.execute( - f""" - INSERT INTO {schema}.l_areas (id_type, area_code, area_name, geom, geojson_4326) - SELECT - {schema}.get_id_area_type('{area_type}') AS id_type, - cd_sig, - code, - ST_Transform(geom, Find_SRID('{schema}', 'l_areas', 'geom')), - geojson - FROM {schema}.{temp_table_name} - """ - ) + if geom_4326_exists(): + # We insert geom and geom_4326 to avoid double conversion like 2154 → 3312 → 4326 + op.execute( + f""" + INSERT INTO {schema}.l_areas (id_type, area_code, area_name, geom, geom_4326) + SELECT + {schema}.get_id_area_type('{area_type}') AS id_type, + cd_sig, + code, + ST_Transform(geom, Find_SRID('{schema}', 'l_areas', 'geom')), + ST_SetSRID(ST_GeomFromGeoJSON(geojson), 4326) + FROM {schema}.{temp_table_name} + """ + ) + else: # legacy column geojson_4326 + op.execute( + f""" + INSERT INTO {schema}.l_areas (id_type, area_code, area_name, geom, geojson_4326) + SELECT + {schema}.get_id_area_type('{area_type}') AS id_type, + cd_sig, + code, + ST_Transform(geom, Find_SRID('{schema}', 'l_areas', 'geom')), + geojson + FROM {schema}.{temp_table_name} + """ + ) logger.info("Copy grids in li_grids…") op.execute( f""" diff --git a/src/ref_geo/migrations/versions/0dfdbfbccd63_ref_geo_french_municipalities.py b/src/ref_geo/migrations/versions/0dfdbfbccd63_ref_geo_french_municipalities.py index b37c795..5e06119 100644 --- a/src/ref_geo/migrations/versions/0dfdbfbccd63_ref_geo_french_municipalities.py +++ b/src/ref_geo/migrations/versions/0dfdbfbccd63_ref_geo_french_municipalities.py @@ -10,6 +10,7 @@ from ref_geo.migrations.utils import ( schema, delete_area_with_type, + geom_4326_exists, ) from utils_flask_sqla.migrations.utils import logger, open_remote_file @@ -59,24 +60,44 @@ def upgrade(): logger.info("Inserting municipalities data in temporary table…") cursor.copy_expert(f"COPY {schema}.{temp_table_name} FROM STDIN", geofile) logger.info("Copy municipalities in l_areas…") - op.execute( - f""" - INSERT INTO {schema}.l_areas ( - id_type, - area_code, - area_name, - geom, - geojson_4326 + if geom_4326_exists(): + op.execute( + f""" + INSERT INTO {schema}.l_areas ( + id_type, + area_code, + area_name, + geom, + geom_4326 + ) + SELECT + {schema}.get_id_area_type('COM') AS id_type, + insee_com, + nom_com, + ST_TRANSFORM(geom, Find_SRID('{schema}', 'l_areas', 'geom')), + ST_SetSRID(ST_GeomFromGeoJSON(geojson), 4326) + FROM {schema}.{temp_table_name} + """ + ) + else: + op.execute( + f""" + INSERT INTO {schema}.l_areas ( + id_type, + area_code, + area_name, + geom, + geojson_4326 + ) + SELECT + {schema}.get_id_area_type('COM') AS id_type, + insee_com, + nom_com, + ST_TRANSFORM(geom, Find_SRID('{schema}', 'l_areas', 'geom')), + geojson + FROM {schema}.{temp_table_name} + """ ) - SELECT - {schema}.get_id_area_type('COM') AS id_type, - insee_com, - nom_com, - ST_TRANSFORM(geom, Find_SRID('{schema}', 'l_areas', 'geom')), - geojson - FROM {schema}.{temp_table_name} - """ - ) logger.info("Copy municipalities in li_municipalities…") op.execute( f""" diff --git a/src/ref_geo/migrations/versions/3fdaa1805575_ref_geo_french_departments.py b/src/ref_geo/migrations/versions/3fdaa1805575_ref_geo_french_departments.py index 0b1a6c6..8bc1ba7 100644 --- a/src/ref_geo/migrations/versions/3fdaa1805575_ref_geo_french_departments.py +++ b/src/ref_geo/migrations/versions/3fdaa1805575_ref_geo_french_departments.py @@ -7,7 +7,7 @@ from alembic import op from shutil import copyfileobj -from ref_geo.migrations.utils import schema, delete_area_with_type +from ref_geo.migrations.utils import schema, delete_area_with_type, geom_4326_exists from utils_flask_sqla.migrations.utils import logger, open_remote_file @@ -50,18 +50,32 @@ def upgrade(): logger.info("Inserting departments data in temporary table…") cursor.copy_expert(f"COPY {schema}.{temp_table_name} FROM STDIN", geofile) logger.info("Copy departments data in l_areas…") - op.execute( - f""" - INSERT INTO {schema}.l_areas (id_type, area_code, area_name, geom, geojson_4326) - SELECT - {schema}.get_id_area_type('DEP') AS id_type, - insee_dep, - nom_dep, - ST_TRANSFORM(geom, Find_SRID('{schema}', 'l_areas', 'geom')), - geojson - FROM {schema}.{temp_table_name} - """ - ) + if geom_4326_exists(): + op.execute( + f""" + INSERT INTO {schema}.l_areas (id_type, area_code, area_name, geom, geom_4326) + SELECT + {schema}.get_id_area_type('DEP') AS id_type, + insee_dep, + nom_dep, + ST_TRANSFORM(geom, Find_SRID('{schema}', 'l_areas', 'geom')), + ST_SetSRID(ST_GeomFromGeoJSON(geojson), 4326) + FROM {schema}.{temp_table_name} + """ + ) + else: + op.execute( + f""" + INSERT INTO {schema}.l_areas (id_type, area_code, area_name, geom, geojson_4326) + SELECT + {schema}.get_id_area_type('DEP') AS id_type, + insee_dep, + nom_dep, + ST_TRANSFORM(geom, Find_SRID('{schema}', 'l_areas', 'geom')), + geojson + FROM {schema}.{temp_table_name} + """ + ) logger.info("Re-indexing…") op.execute(f"REINDEX INDEX {schema}.index_l_areas_geom") logger.info("Dropping temporary departments table…") diff --git a/src/ref_geo/migrations/versions/bc2fcc772b46_geom_4326.py b/src/ref_geo/migrations/versions/bc2fcc772b46_geom_4326.py new file mode 100644 index 0000000..555dd12 --- /dev/null +++ b/src/ref_geo/migrations/versions/bc2fcc772b46_geom_4326.py @@ -0,0 +1,163 @@ +"""Add column LAreas.geom_4326 + +Revision ID: bc2fcc772b46 +Revises: 795f6ea8ec45 +Create Date: 2023-11-28 17:34:39.273235 + +""" +from alembic import op +import sqlalchemy as sa +from geoalchemy2 import Geometry + + +# revision identifiers, used by Alembic. +revision = "bc2fcc772b46" +down_revision = "795f6ea8ec45" +branch_labels = None +depends_on = None + + +def upgrade(): + op.execute("DROP TRIGGER tri_calculate_geojson ON ref_geo.l_areas") + op.execute("DROP FUNCTION ref_geo.fct_tri_calculate_geojson()") + op.drop_column( + schema="ref_geo", + table_name="l_areas", + column_name="geojson_4326", + ) + op.add_column( + schema="ref_geo", + table_name="l_areas", + column=sa.Column("geom_4326", Geometry("MULTIPOLYGON", 4326)), + ) + op.execute( + """ + CREATE FUNCTION ref_geo.fct_tri_transform_geom() + RETURNS trigger AS + $BODY$ + DECLARE + local_srid integer; + c integer; + BEGIN + IF (TG_OP = 'INSERT') THEN + -- Insert policy: we set geom from geom_4326 if geom is null and geom_4326 is not null, and reciprocally. + -- If both geom and geom_4326 have been set (or both are null), we do nothing. + IF (NEW.geom IS NULL AND NEW.geom_4326 IS NOT NULL) THEN + NEW.geom = ST_Transform(NEW.geom_4326, local_srid); + RAISE NOTICE '(I) Updated geom'; + ELSEIF (NEW.geom IS NOT NULL AND NEW.geom_4326 IS NULL) THEN + NEW.geom_4326 = ST_Transform(NEW.geom, 4326); + RAISE NOTICE '(I) Updated geom_4326'; + END IF; + ELSEIF (TG_OP = 'UPDATE') THEN + -- Update policy: we set geom from geom_4326 if geom_4326 have been updated to non null value, + -- unless geom have also been modified to non null value, and reciprocally. + -- We also set geom from geom_4326 if geom is modified to null, and geom_4326 is not null (modified or not), + -- in order to be consistent when updating one or two columns at the same time. + IF ( + NEW.geom_4326 IS NOT NULL + AND + ( + (OLD.geom IS NOT DISTINCT FROM NEW.geom AND OLD.geom_4326 IS DISTINCT FROM NEW.geom_4326) + OR + (NEW.geom IS NULL AND OLD.geom IS NOT NULL) + ) + ) THEN + SELECT INTO local_srid Find_SRID('ref_geo', 'l_areas', 'geom'); + NEW.geom = ST_Transform(NEW.geom_4326, local_srid); + RAISE NOTICE '(U) Updated geom'; + ELSEIF ( + NEW.geom IS NOT NULL + AND + ( + (OLD.geom_4326 IS NOT DISTINCT FROM NEW.geom_4326 AND OLD.geom IS DISTINCT FROM NEW.geom) + OR + (NEW.geom_4326 IS NULL AND OLD.geom_4326 IS NOT NULL) + ) + ) THEN + NEW.geom_4326 = ST_Transform(NEW.geom, 4326); + RAISE NOTICE '(U) Updated geom_4326'; + END IF; + END IF; + RETURN NEW; + END; + $BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; + """ + ) + # Set geom_4326 before creating trigger! + op.execute( + """ + UPDATE + ref_geo.l_areas + SET + geom_4326 = ST_Transform(geom, 4326) + WHERE + geom IS NOT NULL; + """ + ) + op.execute( + """ + CREATE TRIGGER tri_transform_geom_insert + BEFORE + INSERT ON ref_geo.l_areas + FOR EACH + ROW + EXECUTE FUNCTION + ref_geo.fct_tri_transform_geom(); + CREATE TRIGGER tri_transform_geom_update + BEFORE + UPDATE ON ref_geo.l_areas + FOR EACH + ROW + EXECUTE FUNCTION + ref_geo.fct_tri_transform_geom(); + """ + ) + + +def downgrade(): + op.add_column( + schema="ref_geo", + table_name="l_areas", + column=sa.Column("geojson_4326", sa.String), + ) + op.execute( + """ + UPDATE + ref_geo.l_areas + SET + geojson_4326 = ST_AsGeoJson(geom_4326) + """ + ) + op.execute("DROP TRIGGER tri_transform_geom_insert ON ref_geo.l_areas") + op.execute("DROP TRIGGER tri_transform_geom_update ON ref_geo.l_areas") + op.execute("DROP FUNCTION ref_geo.fct_tri_transform_geom()") + op.drop_column( + schema="ref_geo", + table_name="l_areas", + column_name="geom_4326", + ) + op.execute( + """ + CREATE OR REPLACE FUNCTION ref_geo.fct_tri_calculate_geojson() + RETURNS trigger AS + $BODY$ + BEGIN + NEW.geojson_4326 = public.ST_asgeojson(public.st_transform(NEW.geom, 4326)); + RETURN NEW; + END; + $BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; + """ + ) + op.execute( + """ + CREATE TRIGGER tri_calculate_geojson + BEFORE INSERT OR UPDATE OF geom ON ref_geo.l_areas + FOR EACH ROW + EXECUTE PROCEDURE ref_geo.fct_tri_calculate_geojson(); + """ + ) diff --git a/src/ref_geo/migrations/versions/d02f4563bebe_ref_geo_french_regions.py b/src/ref_geo/migrations/versions/d02f4563bebe_ref_geo_french_regions.py index feb857d..14dcfed 100644 --- a/src/ref_geo/migrations/versions/d02f4563bebe_ref_geo_french_regions.py +++ b/src/ref_geo/migrations/versions/d02f4563bebe_ref_geo_french_regions.py @@ -11,6 +11,7 @@ from ref_geo.migrations.utils import ( schema, delete_area_with_type, + geom_4326_exists, ) from utils_flask_sqla.migrations.utils import logger, open_remote_file @@ -52,24 +53,44 @@ def upgrade(): logger.info("Inserting regions data in temporary table…") cursor.copy_expert(f"COPY {schema}.{temp_table_name} FROM STDIN", geofile) logger.info("Copy regions in l_areas…") - op.execute( - f""" - INSERT INTO {schema}.l_areas ( - id_type, - area_code, - area_name, - geom, - geojson_4326 + if geom_4326_exists(): + op.execute( + f""" + INSERT INTO {schema}.l_areas ( + id_type, + area_code, + area_name, + geom, + geom_4326 + ) + SELECT + {schema}.get_id_area_type('REG') as id_type, + insee_reg, + nom, + ST_Transform(geom, Find_SRID('{schema}', 'l_areas', 'geom')), + ST_SetSRID(ST_Transform(geom, 4326), 4326) + FROM {schema}.{temp_table_name} + """ + ) + else: + op.execute( + f""" + INSERT INTO {schema}.l_areas ( + id_type, + area_code, + area_name, + geom, + geojson_4326 + ) + SELECT + {schema}.get_id_area_type('REG') as id_type, + insee_reg, + nom, + ST_Transform(geom, Find_SRID('{schema}', 'l_areas', 'geom')), + ST_Transform(geom, 4326) + FROM {schema}.{temp_table_name} + """ ) - SELECT - {schema}.get_id_area_type('REG') as id_type, - insee_reg, - nom, - ST_Transform(geom, Find_SRID('{schema}', 'l_areas', 'geom')), - public.ST_asgeojson(public.st_transform(geom, 4326)) - FROM {schema}.{temp_table_name} - """ - ) logger.info("Re-indexing…") op.execute(f"REINDEX INDEX {schema}.index_l_areas_geom") logger.info("Dropping temporary regions table…") diff --git a/src/ref_geo/models.py b/src/ref_geo/models.py index 8e460be..81e70c7 100644 --- a/src/ref_geo/models.py +++ b/src/ref_geo/models.py @@ -54,9 +54,9 @@ class LAreas(db.Model): id_type = db.Column(db.Integer, ForeignKey("ref_geo.bib_areas_types.id_type")) area_name = db.Column(db.Unicode) area_code = db.Column(db.Unicode) - geom = db.Column(Geometry("GEOMETRY")) + geom = db.Column(Geometry("MULTIPOLYGON")) centroid = db.Column(Geometry("POINT")) - geojson_4326 = deferred(db.Column(db.Unicode)) + geom_4326 = deferred(db.Column(Geometry("MULTIPOLYGON", 4326))) source = db.Column(db.Unicode) enable = db.Column(db.Boolean, nullable=False, default=True) meta_create_date = db.Column(db.DateTime, default=datetime.now) @@ -192,7 +192,7 @@ class LPoints(db.Model): class LiMunicipalities(db.Model): __tablename__ = "li_municipalities" __table_args__ = {"schema": "ref_geo"} - id_municipality = db.Column(db.Integer, primary_key=True) + id_municipality = db.Column(db.String(25), primary_key=True) id_area = db.Column(db.Integer) status = db.Column(db.Unicode) insee_com = db.Column(db.Unicode) diff --git a/src/ref_geo/routes.py b/src/ref_geo/routes.py index 766f733..b32e349 100644 --- a/src/ref_geo/routes.py +++ b/src/ref_geo/routes.py @@ -11,6 +11,7 @@ from ref_geo.env import db from ref_geo.models import BibAreasTypes, LiMunicipalities, LAreas +from ref_geo.schemas import AreaTypeSchema, MunicipalitySchema, AreaSchema routes = Blueprint("ref_geo", __name__) @@ -26,11 +27,8 @@ ) geojson_intersect_filter = func.ST_Intersects( - LAreas.geom, - func.ST_Transform( - func.ST_SetSRID(func.ST_GeomFromGeoJSON(sa.bindparam("geojson")), 4326), - func.Find_SRID("ref_geo", "l_areas", "geom"), - ), + LAreas.geom_4326, + func.ST_SetSRID(func.ST_GeomFromGeoJSON(sa.bindparam("geojson")), 4326), ) area_size_func = func.ST_Area( @@ -76,10 +74,9 @@ def getGeoInfo(): return jsonify( { - "areas": [ - area.as_dict(fields=["id_area", "id_type", "area_code", "area_name"]) - for area in areas.all() - ], + "areas": AreaSchema(only=["id_area", "id_type", "area_code", "area_name"]).dump( + areas.all(), many=True + ), "altitude": altitude, } ) @@ -138,17 +135,14 @@ def getAreasIntersection(): response[id_type] = _areas[0].area_type.as_dict(fields=["type_code", "type_name"]) response[id_type].update( { - "areas": [ - area.as_dict( - fields=[ - "area_code", - "area_name", - "id_area", - "id_type", - ] - ) - for area in _areas - ], + "areas": AreaSchema( + only=[ + "area_code", + "area_name", + "id_area", + "id_type", + ] + ).dump(_areas, many=True) } ) @@ -169,16 +163,8 @@ def get_municipalities(): q = q.filter(LiMunicipalities.nom_com.ilike("{}%".format(parameters.get("nom_com")))) limit = int(parameters.get("limit")) if parameters.get("limit") else 100 - data = q.limit(limit) - return jsonify([d.as_dict() for d in data]) - - -def to_geojson(data): - features = [] - for feature in data: - geometry = feature.pop("geojson_4326", None) - features.append({"type": "Feature", "properties": feature, "geometry": geometry}) - return features + municipalities = q.limit(limit) + return jsonify(MunicipalitySchema().dump(municipalities, many=True)) @routes.route("/areas", methods=["GET"]) @@ -223,20 +209,20 @@ def get_areas(): limit = int(params.get("limit")[0]) if params.get("limit") else 100 - data = q.limit(limit) + areas = q.limit(limit) # allow to format response format = request.args.get("format", default="", type=str) fields = {"area_type.type_code"} if format == "geojson": - fields |= {"+geojson_4326"} - data = data.options(undefer("geojson_4326")) - response = [d.as_dict(fields=fields) for d in data] + fields |= {"+geom_4326"} + areas = areas.options(undefer("geom_4326")) + response = AreaSchema(only=fields, as_geojson=format == "geojson").dump(areas.all(), many=True) if format == "geojson": - # format features as geojson according to standard - response = to_geojson(response) - return jsonify(response) + # retro-compat: return a list of Features instead of the FeatureCollection + response = response["features"] + return response @routes.route("/area_size", methods=["Post"]) @@ -296,4 +282,4 @@ def get_area_types(): query = query.order_by(desc("type_name")) # FIELDS fields = ["type_name", "type_code", "id_type"] - return jsonify([d.as_dict(fields=fields) for d in query.all()]) + return jsonify(AreaTypeSchema(only=fields).dump(query.all(), many=True)) diff --git a/src/ref_geo/schemas.py b/src/ref_geo/schemas.py new file mode 100644 index 0000000..caf5488 --- /dev/null +++ b/src/ref_geo/schemas.py @@ -0,0 +1,31 @@ +from marshmallow_sqlalchemy.fields import Nested + +from utils_flask_sqla.schema import SmartRelationshipsMixin +from utils_flask_sqla_geo.schema import GeoAlchemyAutoSchema + +from ref_geo.env import db, ma +from ref_geo.models import BibAreasTypes, LAreas, LiMunicipalities + + +class AreaTypeSchema(SmartRelationshipsMixin, ma.SQLAlchemyAutoSchema): + class Meta: + model = BibAreasTypes + include_fk = True + load_instance = True + + +class AreaSchema(SmartRelationshipsMixin, GeoAlchemyAutoSchema): + class Meta: + model = LAreas + include_fk = True + load_instance = True + feature_geometry = "geom_4326" + + area_type = Nested(AreaTypeSchema) + + +class MunicipalitySchema(SmartRelationshipsMixin, GeoAlchemyAutoSchema): + class Meta: + model = LiMunicipalities + include_fk = True + load_instance = True diff --git a/src/ref_geo/tests/test_ref_geo.py b/src/ref_geo/tests/test_ref_geo.py index 78122b4..a0c7b76 100644 --- a/src/ref_geo/tests/test_ref_geo.py +++ b/src/ref_geo/tests/test_ref_geo.py @@ -351,7 +351,6 @@ def test_get_area_size_no_geom(self): def test_get_types(self): response = self.client.get(url_for("ref_geo.get_area_types")) - print(response.json) assert response.status_code == 200 def test_get_types_by_code(self, area_commune):