From 598ba8d187ad191e673b08da2ac6304339f71fd4 Mon Sep 17 00:00:00 2001 From: Paul Bienkowski Date: Sat, 30 Apr 2022 20:31:32 +0200 Subject: [PATCH] add dynamic tile arguments --- api/obs/api/routes/tiles.py | 16 +++++-- api/tools/prepare_sql_tiles.py | 45 ++++++++++++++++++- tile-generator/layers/obs_events/layer.sql | 11 +++-- .../layers/obs_events/obs_events.yaml | 8 +++- 4 files changed, 70 insertions(+), 10 deletions(-) diff --git a/api/obs/api/routes/tiles.py b/api/obs/api/routes/tiles.py index abaf70b..35e1d95 100644 --- a/api/obs/api/routes/tiles.py +++ b/api/obs/api/routes/tiles.py @@ -1,5 +1,6 @@ from gzip import decompress from sqlite3 import connect +from sanic.exceptions import Forbidden from sanic.response import raw from sqlalchemy import select, text @@ -23,7 +24,7 @@ def get_tile(filename, zoom, x, y): content = db.execute( "SELECT tile_data FROM tiles WHERE zoom_level=? AND tile_column=? AND tile_row=?", - (zoom, x, (2 ** zoom - 1) - y), + (zoom, x, (2**zoom - 1) - y), ).fetchone() return content and content[0] or None @@ -38,11 +39,21 @@ async def tiles(req, zoom: int, x: int, y: str): tile = get_tile(req.app.config.TILES_FILE, int(zoom), int(x), int(y)) else: + user_id = req.ctx.get_single_arg("user_id", convert=int, default=None) + if user_id is not None: + if req.ctx.user is None or req.ctx.user.id != user_id: + raise Forbidden() + tile = await req.ctx.db.scalar( - text(f"select data from getmvt(:zoom, :x, :y) as b(data, key);").bindparams( + text( + f"select data from getmvt(:zoom, :x, :y, :user_id, :min_time, :max_time) as b(data, key);" + ).bindparams( zoom=int(zoom), x=int(x), y=int(y), + user_id=user_id, + min_time=None, + max_time=None, ) ) @@ -66,4 +77,3 @@ async def tiles(req, zoom: int, x: int, y: str): tile = decompress(tile) return raw(tile, content_type="application/x-protobuf", headers=headers) - diff --git a/api/tools/prepare_sql_tiles.py b/api/tools/prepare_sql_tiles.py index 36d96dd..90100e6 100755 --- a/api/tools/prepare_sql_tiles.py +++ b/api/tools/prepare_sql_tiles.py @@ -6,9 +6,12 @@ import re import os import glob from os.path import normpath, abspath, join +from typing import List, Tuple + from sqlalchemy import text import sqlparse +from openmaptiles.sqltomvt import MvtGenerator from obs.api.app import app from obs.api.db import connect_db, make_session @@ -21,6 +24,32 @@ TILE_GENERATOR = normpath( ) TILESET_FILE = join(TILE_GENERATOR, "openbikesensor.yaml") +EXTRA_ARGS = [ + # name, type, default + ("user_id", "integer", "NULL"), + ("min_time", "timestamp", "NULL"), + ("max_time", "timestamp", "NULL"), +] + + +class CustomMvtGenerator(MvtGenerator): + def generate_sqltomvt_func(self, fname, extra_args: List[Tuple[str, str]]) -> str: + """ + Creates a SQL function that returns a single bytea value or null. This + method is overridden to allow for custom arguments in the created function + """ + extra_args_types = "".join([f", {a[1]}" for a in extra_args]) + extra_args_definitions = "".join( + [f", {a[0]} {a[1]} DEFAULT {a[2]}" for a in extra_args] + ) + + return f"""\ +DROP FUNCTION IF EXISTS {fname}(integer, integer, integer{extra_args_types}); +CREATE FUNCTION {fname}(zoom integer, x integer, y integer{extra_args_definitions}) +RETURNS {'TABLE(mvt bytea, key text)' if self.key_column else 'bytea'} AS $$ +{self.generate_sql()}; +$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT;""" + def parse_pg_url(url=app.config.POSTGRES_URL): m = re.match( @@ -114,9 +143,21 @@ async def generate_sql(build_dir): with open(filename, "rt") as f: sql_snippets.append(f.read()) - getmvt_sql = await _run( - f"python $(which generate-sqltomvt) {TILESET_FILE!r} --key --gzip --postgis-ver 3.0.1 --function --fname=getmvt" + mvt = CustomMvtGenerator( + tileset=TILESET_FILE, + postgis_ver="3.0.1", + zoom="zoom", + x="x", + y="y", + gzip=True, + test_geometry=False, # ? + key_column=True, ) + getmvt_sql = mvt.generate_sqltomvt_func("getmvt", EXTRA_ARGS) + print(getmvt_sql) + + # drop old versions of the function + sql_snippets.append("DROP FUNCTION IF EXISTS getmvt(integer, integer, integer);") sql_snippets.append(getmvt_sql) return sql_snippets diff --git a/tile-generator/layers/obs_events/layer.sql b/tile-generator/layers/obs_events/layer.sql index 7ae714f..574d67c 100644 --- a/tile-generator/layers/obs_events/layer.sql +++ b/tile-generator/layers/obs_events/layer.sql @@ -1,8 +1,8 @@ -CREATE OR REPLACE FUNCTION layer_obs_events(bbox geometry, zoom_level int) +CREATE OR REPLACE FUNCTION layer_obs_events(bbox geometry, zoom_level int, user_id integer, min_time timestamp, max_time timestamp) RETURNS TABLE(event_id bigint, geometry geometry, distance_overtaker float, distance_stationary float, direction int, course float, speed float, zone zone_type, way_id bigint) AS $$ SELECT - id::bigint as event_id, + overtaking_event.id::bigint as event_id, ST_Transform(overtaking_event.geometry, 3857) as geometry, distance_overtaker, distance_stationary, @@ -12,7 +12,10 @@ RETURNS TABLE(event_id bigint, geometry geometry, distance_overtaker float, dist CASE WHEN road.zone IS NULL THEN 'urban' else road.zone END as zone, overtaking_event.way_id::bigint as way_id FROM overtaking_event - FULL OUTER JOIN road ON (road.way_id = overtaking_event.way_id) - WHERE ST_Transform(overtaking_event.geometry, 3857) && bbox; + FULL OUTER JOIN road ON road.way_id = overtaking_event.way_id + JOIN track on track.id = overtaking_event.track_id + WHERE ST_Transform(overtaking_event.geometry, 3857) && bbox + AND (user_id is NULL OR user_id = track.author_id) + AND time BETWEEN COALESCE(min_time, '1900-01-01'::timestamp) AND COALESCE(max_time, '2100-01-01'::timestamp); $$ LANGUAGE SQL IMMUTABLE; diff --git a/tile-generator/layers/obs_events/obs_events.yaml b/tile-generator/layers/obs_events/obs_events.yaml index be11e7c..aa03e5c 100644 --- a/tile-generator/layers/obs_events/obs_events.yaml +++ b/tile-generator/layers/obs_events/obs_events.yaml @@ -25,7 +25,13 @@ layer: geometry_field: geometry key_field: event_id key_field_as_attribute: no - query: (SELECT event_id, geometry, distance_overtaker, distance_stationary, direction, course, speed, zone, way_id FROM layer_obs_events(!bbox!, z(!scale_denominator!))) AS t + query: > + ( + SELECT + event_id, geometry, distance_overtaker, distance_stationary, direction, course, speed, zone, way_id + FROM + layer_obs_events(!bbox!, z(!scale_denominator!), user_id, min_time, max_time) + ) AS t schema: - ./layer.sql