diff --git a/MARTIN_SETUP.md b/MARTIN_SETUP.md new file mode 100644 index 00000000..3bcab7e5 --- /dev/null +++ b/MARTIN_SETUP.md @@ -0,0 +1,86 @@ +# Martin Tile Server Setup + +Martin tile server serves vector tiles from PostGIS database views. + +## Overview + +Martin automatically discovers tables and views with geometry columns (SRID 4326) and serves them as Mapbox Vector Tiles. + +## Local Setup + +### 1. Docker Configuration + +Martin is configured in `docker-compose.yml`: +- Runs on port `3001` (host) mapped to port `3000` (container) +- Connects to the `opensensemap` database +- Waits for Postgres to be healthy before starting + +### 2. Environment Variables + +Optional `.env` variable: +```bash +MARTIN_URL=http://localhost:3001 +``` + +Defaults to `http://localhost:3001` if not set. + +### 3. Database View + +The `analysis_view` materialized view (created by migration `drizzle/0023_create_analysis_view.sql`) is automatically discovered by Martin. + +The view includes: +- `createdAt`, `boxId`, `tags` +- `geometry` (PostGIS Point, SRID 4326) +- Sensor data columns (temperature, humidity, PM values, etc.) + +## Usage + +### Endpoints + +- **Catalog**: `http://localhost:3001/catalog` - Lists all available tile sources +- **TileJSON**: `http://localhost:3001/analysis_view` - Metadata for the tile source +- **Tiles**: `http://localhost:3001/analysis_view/{z}/{x}/{y}.pbf` - Vector tile data + +### Starting Services + +1. Start Docker services: + ```bash + docker-compose up -d + ``` + +2. Ensure PostGIS is enabled: + ```bash + docker exec frontend-postgres-1 psql -U postgres -d opensensemap -c "CREATE EXTENSION IF NOT EXISTS postgis CASCADE;" + ``` + +3. Run migrations: + ```bash + npx tsx ./db/migrate.ts + ``` + +4. Verify Martin is running: + ```bash + curl http://localhost:3001/catalog + ``` + +### Adding Data + +Use `/api/boxes/{deviceId}/{sensorId}` to add measurements with optional location: + +```bash +curl -X POST http://localhost:3000/api/boxes/test-device-001/test-sensor-001 \ + -H "Content-Type: application/json" \ + -d '{ + "value": 21.4, + "createdAt": "2025-11-06T16:00:00Z", + "location": { "lat": 52.5200, "lng": 13.4050 } + }' +``` + +### Refreshing the View + +Refresh the materialized view to include new data: + +```bash +docker exec frontend-postgres-1 psql -U postgres -d opensensemap -c "REFRESH MATERIALIZED VIEW CONCURRENTLY analysis_view;" +``` diff --git a/app/utils/env.server.ts b/app/utils/env.server.ts index bc67a6fb..00b45be6 100644 --- a/app/utils/env.server.ts +++ b/app/utils/env.server.ts @@ -17,6 +17,7 @@ const schema = z.object({ MYBADGES_ISSUERID_OSEM: z.string(), MYBADGES_CLIENT_ID: z.string(), MYBADGES_CLIENT_SECRET: z.string(), + MARTIN_URL: z.string().url().optional(), }); declare global { @@ -45,6 +46,7 @@ export function getEnv() { MYBADGES_API_URL: process.env.MYBADGES_API_URL, MYBADGES_URL: process.env.MYBADGES_URL, SENSORWIKI_API_URL: process.env.SENSORWIKI_API_URL, + MARTIN_URL: process.env.MARTIN_URL || "http://localhost:3001", }; } diff --git a/docker-compose.yml b/docker-compose.yml index aed6c8a7..cffece0a 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -17,3 +17,27 @@ services: volumes: # - ./pgdata:/home/postgres/pgdata - ./db/imports:/home/postgres/imports + networks: + - app-network + healthcheck: + test: ["CMD-SHELL", "pg_isready -U postgres"] + interval: 5s + timeout: 5s + retries: 5 + + martin: + image: ghcr.io/maplibre/martin:latest + restart: always + ports: + - "3001:3000" + environment: + - DATABASE_URL=postgresql://postgres:postgres@postgres:5432/opensensemap?sslmode=disable + depends_on: + postgres: + condition: service_healthy + networks: + - app-network + +networks: + app-network: + driver: bridge diff --git a/drizzle/0023_create_analysis_view.sql b/drizzle/0023_create_analysis_view.sql new file mode 100644 index 00000000..cb58ffa8 --- /dev/null +++ b/drizzle/0023_create_analysis_view.sql @@ -0,0 +1,199 @@ +-- Create a table to track processed/read measurements +-- This allows us to exclude read measurements from the view without deleting them +CREATE TABLE IF NOT EXISTS processed_measurements ( + device_id TEXT NOT NULL, + time TIMESTAMP WITH TIME ZONE NOT NULL, + processed_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL, + PRIMARY KEY (device_id, time) +); + +CREATE INDEX IF NOT EXISTS idx_processed_measurements_device_time + ON processed_measurements(device_id, time); + +-- Create a view that flattens measurements with device, location, and sensor data +-- This view provides a denormalized structure for data analysis +-- Note: Regular view (not materialized) so it automatically reflects new data +-- +-- Structure: +-- - `createdAt`: measurement timestamp +-- - `boxId`: device ID +-- - `tags`: device tags array +-- - `geometry`: location point (SRID 4326) if available +-- Derived columns for common phenomena (temperature, humidity, soil_moisture, pressure, pm values, wind_speed, light_intensity, UV, sound levels, VOC, CO₂) used by Martin tiles +-- +-- Note: Groups measurements by time and device. If multiple locations exist for the same +-- time/device, uses the location from the first measurement with a location. +-- Only includes measurements that have NOT been processed (not in processed_measurements table). +DROP VIEW IF EXISTS analysis_view; +DROP MATERIALIZED VIEW IF EXISTS analysis_view; +CREATE VIEW analysis_view AS +WITH sensor_measurements AS ( + SELECT + m.time, + d.id AS device_id, + d.tags, + m.location_id, + s.id AS sensor_id, + s.title, + s.unit, + s.sensor_type, + m.value, + ( + CASE + WHEN LOWER(COALESCE(s.unit, '')) IN ('°c', 'c°', 'degc', 'celsius') + AND LOWER(COALESCE(s.title, '')) LIKE '%boden%' THEN 'soil_temperature' + WHEN LOWER(COALESCE(s.unit, '')) IN ('°c', 'c°', 'degc', 'celsius') THEN 'temperature' + WHEN LOWER(COALESCE(s.unit, '')) IN ('%', 'percent', 'prozent') + AND LOWER(COALESCE(s.title, '')) LIKE '%boden%' THEN 'soil_moisture' + WHEN LOWER(COALESCE(s.unit, '')) IN ('%', 'percent', 'prozent') THEN 'humidity' + WHEN (LOWER(COALESCE(s.unit, '')) LIKE '%µg/m%' + OR LOWER(COALESCE(s.unit, '')) LIKE '%ug/m%') THEN + CASE + WHEN LOWER(COALESCE(s.title, '')) LIKE '%pm1%' + OR LOWER(COALESCE(s.title, '')) LIKE '%pm01%' THEN 'pm1' + WHEN LOWER(COALESCE(s.title, '')) LIKE '%pm2.5%' + OR LOWER(COALESCE(s.title, '')) LIKE '%pm2,5%' + OR LOWER(COALESCE(s.title, '')) LIKE '%pm25%' THEN 'pm2_5' + WHEN LOWER(COALESCE(s.title, '')) LIKE '%pm4%' THEN 'pm4' + WHEN LOWER(COALESCE(s.title, '')) LIKE '%pm10%' THEN 'pm10' + ELSE NULL + END + WHEN LOWER(COALESCE(s.unit, '')) IN ('hpa', 'pa') THEN 'pressure' + WHEN LOWER(COALESCE(s.unit, '')) LIKE '%m/s%' THEN 'wind_speed' + WHEN LOWER(COALESCE(s.unit, '')) IN ('lx', 'lux') THEN 'light_intensity' + WHEN LOWER(COALESCE(s.unit, '')) LIKE '%µw/cm%' + OR LOWER(COALESCE(s.unit, '')) LIKE '%uw/cm%' THEN 'uv_intensity' + WHEN LOWER(COALESCE(s.unit, '')) = 'uv index' THEN 'uv_index' + WHEN LOWER(COALESCE(s.unit, '')) LIKE '%db%' THEN + CASE + WHEN LOWER(COALESCE(s.title, '')) LIKE '%min%' THEN 'sound_level_min' + WHEN LOWER(COALESCE(s.title, '')) LIKE '%max%' THEN 'sound_level_max' + WHEN LOWER(COALESCE(s.title, '')) LIKE '%eq%' + OR LOWER(COALESCE(s.title, '')) LIKE '%schalldruckpegel%' + THEN 'sound_level_eq' + ELSE 'sound_level' + END + WHEN LOWER(COALESCE(s.unit, '')) LIKE '%kohm%' + OR LOWER(COALESCE(s.unit, '')) LIKE '%kΩ%' THEN 'voc' + WHEN LOWER(COALESCE(s.unit, '')) = 'ppm' THEN 'co2' + ELSE NULL + END + ) AS canonical_key, + COALESCE( + CASE + WHEN LOWER(COALESCE(s.unit, '')) IN ('°c', 'c°', 'degc', 'celsius') + AND LOWER(COALESCE(s.title, '')) LIKE '%boden%' THEN 'soil_temperature' + WHEN LOWER(COALESCE(s.unit, '')) IN ('°c', 'c°', 'degc', 'celsius') THEN 'temperature' + WHEN LOWER(COALESCE(s.unit, '')) IN ('%', 'percent', 'prozent') + AND LOWER(COALESCE(s.title, '')) LIKE '%boden%' THEN 'soil_moisture' + WHEN LOWER(COALESCE(s.unit, '')) IN ('%', 'percent', 'prozent') THEN 'humidity' + WHEN (LOWER(COALESCE(s.unit, '')) LIKE '%µg/m%' + OR LOWER(COALESCE(s.unit, '')) LIKE '%ug/m%') THEN + CASE + WHEN LOWER(COALESCE(s.title, '')) LIKE '%pm1%' + OR LOWER(COALESCE(s.title, '')) LIKE '%pm01%' THEN 'pm1' + WHEN LOWER(COALESCE(s.title, '')) LIKE '%pm2.5%' + OR LOWER(COALESCE(s.title, '')) LIKE '%pm2,5%' + OR LOWER(COALESCE(s.title, '')) LIKE '%pm25%' THEN 'pm2_5' + WHEN LOWER(COALESCE(s.title, '')) LIKE '%pm4%' THEN 'pm4' + WHEN LOWER(COALESCE(s.title, '')) LIKE '%pm10%' THEN 'pm10' + ELSE NULL + END + WHEN LOWER(COALESCE(s.unit, '')) IN ('hpa', 'pa') THEN 'pressure' + WHEN LOWER(COALESCE(s.unit, '')) LIKE '%m/s%' THEN 'wind_speed' + WHEN LOWER(COALESCE(s.unit, '')) IN ('lx', 'lux') THEN 'light_intensity' + WHEN LOWER(COALESCE(s.unit, '')) LIKE '%µw/cm%' + OR LOWER(COALESCE(s.unit, '')) LIKE '%uw/cm%' THEN 'uv_intensity' + WHEN LOWER(COALESCE(s.unit, '')) = 'uv index' THEN 'uv_index' + WHEN LOWER(COALESCE(s.unit, '')) LIKE '%db%' THEN + CASE + WHEN LOWER(COALESCE(s.title, '')) LIKE '%min%' THEN 'sound_level_min' + WHEN LOWER(COALESCE(s.title, '')) LIKE '%max%' THEN 'sound_level_max' + WHEN LOWER(COALESCE(s.title, '')) LIKE '%eq%' + OR LOWER(COALESCE(s.title, '')) LIKE '%schalldruckpegel%' + THEN 'sound_level_eq' + ELSE 'sound_level' + END + WHEN LOWER(COALESCE(s.unit, '')) LIKE '%kohm%' + OR LOWER(COALESCE(s.unit, '')) LIKE '%kΩ%' THEN 'voc' + WHEN LOWER(COALESCE(s.unit, '')) = 'ppm' THEN 'co2' + ELSE NULL + END, + COALESCE( + NULLIF(s.sensor_wiki_phenomenon, ''), + NULLIF(s.sensor_type, ''), + NULLIF(s.title, ''), + s.id::text + ) + ) AS json_key + FROM measurement m + INNER JOIN sensor s ON m.sensor_id = s.id + INNER JOIN device d ON s.device_id = d.id +), +grouped_measurements AS ( + SELECT + sm.time, + sm.device_id, + sm.tags, + MAX(sm.location_id) AS location_id, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'temperature') AS temperature, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'soil_temperature') AS soil_temperature, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'humidity') AS humidity, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'soil_moisture') AS soil_moisture, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'pressure') AS pressure, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'pm1') AS pm1, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'pm2_5') AS pm2_5, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'pm4') AS pm4, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'pm10') AS pm10, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'wind_speed') AS wind_speed, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'light_intensity') AS light_intensity, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'uv_intensity') AS uv_intensity, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'uv_index') AS uv_index, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'sound_level') AS sound_level, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'sound_level_eq') AS sound_level_eq, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'sound_level_min') AS sound_level_min, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'sound_level_max') AS sound_level_max, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'voc') AS voc, + MAX(sm.value) FILTER (WHERE sm.canonical_key = 'co2') AS co2 + FROM sensor_measurements sm + GROUP BY sm.time, sm.device_id, sm.tags +) +SELECT + gm.time AS "createdAt", + gm.device_id AS "boxId", + gm.tags, + l.location::geometry(Point, 4326) AS geometry, + gm.temperature, + gm.soil_temperature, + gm.humidity, + gm.soil_moisture, + gm.pressure, + gm.pm1, + gm.pm2_5, + gm.pm4, + gm.pm10, + gm.wind_speed, + gm.light_intensity, + gm.uv_intensity, + gm.uv_index, + gm.sound_level, + gm.sound_level_eq, + gm.sound_level_min, + gm.sound_level_max, + gm.voc, + gm.co2 +FROM grouped_measurements gm +LEFT JOIN location l ON gm.location_id = l.id +LEFT JOIN processed_measurements pm + ON gm.device_id = pm.device_id + AND gm.time = pm.time +WHERE pm.device_id IS NULL; -- Only include unprocessed measurements + +-- Add comment to help identify this view +COMMENT ON VIEW analysis_view IS 'Denormalized view for data analysis combining measurements, devices, sensors, and locations. Derived columns expose common phenomena for vector tiles and API consumption. Only includes unprocessed measurements. Automatically reflects new data.'; + +-- Note: You may also want to add indexes on the underlying tables: +-- CREATE INDEX idx_measurement_time ON measurement(time); +-- CREATE INDEX idx_measurement_location_id ON measurement(location_id); +-- CREATE INDEX idx_sensor_device_id ON sensor(device_id); + diff --git a/drizzle/meta/_journal.json b/drizzle/meta/_journal.json index 176578a1..1c4f5e01 100644 --- a/drizzle/meta/_journal.json +++ b/drizzle/meta/_journal.json @@ -162,6 +162,13 @@ "when": 1761122113831, "tag": "0022_odd_sugar_man", "breakpoints": true + }, + { + "idx": 23, + "version": "7", + "when": 1761122113832, + "tag": "0023_create_analysis_view", + "breakpoints": true } ] } \ No newline at end of file