From 6a9e36c72e1d8cd7bf1250d119c05a086e670156 Mon Sep 17 00:00:00 2001 From: Maria Zadnepryanets Date: Thu, 6 Nov 2025 14:33:06 +0100 Subject: [PATCH 01/12] chore: setup martin and add analysis_view --- MARTIN_SETUP.md | 213 ++++++++++++++++++++++++++ app/utils/env.server.ts | 2 + docker-compose.yml | 24 +++ drizzle/0023_create_analysis_view.sql | 65 ++++++++ drizzle/meta/_journal.json | 7 + 5 files changed, 311 insertions(+) create mode 100644 MARTIN_SETUP.md create mode 100644 drizzle/0023_create_analysis_view.sql diff --git a/MARTIN_SETUP.md b/MARTIN_SETUP.md new file mode 100644 index 00000000..c9af704e --- /dev/null +++ b/MARTIN_SETUP.md @@ -0,0 +1,213 @@ +# Martin Tile Server Setup + +This document explains how to use Martin tile server to serve vector tiles from your PostGIS database. + +## Overview + +Martin is a tile server that generates and serves vector tiles on the fly from PostGIS databases. It's configured to: +- Run in the same Docker network as your PostGIS database +- Automatically discover tables and views with geometry columns (SRID 4326) +- Serve them as Mapbox Vector Tiles + +## Setup + +### 1. Database Views + +**Analysis View**: A database view `analysis_view` has been created for data analysis. The migration is in `drizzle/0023_create_analysis_view.sql`. + +The view provides a denormalized structure with: +- `createdAt`: measurement timestamp +- `boxId`: device ID +- `tags`: device tags array +- `geometry`: location point (SRID 4326) +- `measurements`: JSONB object containing all sensor measurements + +**Note**: Martin automatically discovers tables and views with geometry columns that have SRID 4326. The `analysis_view` geometry column is properly configured for Martin. + +### 2. Docker Configuration + +Martin is configured in `docker-compose.yml`: +- Runs on port `3000` +- Connects to the database specified in your `DATABASE_URL` (defaults to `opensensemap`) +- Uses the same Docker network (`app-network`) +- Waits for Postgres to be healthy before starting + +### 3. Environment Variables + +Add to your `.env` file (optional): +```bash +MARTIN_URL=http://localhost:3000 +``` + +If not set, it defaults to `http://localhost:3000`. + +**Note**: Martin's `DATABASE_URL` in `docker-compose.yml` should match your application's database name. Currently configured for `opensensemap` database. + +## Usage + +### Accessing Martin + +Martin is accessible directly at `http://localhost:3000` (or your configured `MARTIN_URL`): + +- **TileJSON**: `http://localhost:3000/{source_name}` + - Returns metadata about the tile source + - Example: `http://localhost:3000/analysis_view` + +- **Tiles**: `http://localhost:3000/{source_name}/{z}/{x}/{y}.pbf` + - Returns vector tile data for a specific tile + - Example: `http://localhost:3000/analysis_view/10/512/512.pbf` + +### Using in React Components + +Add Martin vector tiles to your map using the `Source` and `Layer` components from `react-map-gl`: + +```tsx +import { Source, Layer } from "react-map-gl"; +import { MapProvider } from "react-map-gl"; +import Map from "~/components/map/map"; + +function MyMapWithPoints() { + const martinUrl = window.ENV?.MARTIN_URL || "http://localhost:3000"; + + // Construct the tile URL template directly + // Mapbox GL will replace {z}, {x}, {y} with actual tile coordinates + const tileUrl = `${martinUrl}/analysis_view/{z}/{x}/{y}.pbf`; + + return ( + + + + + + + + ); +} +``` + +## Starting the Services + +1. **Start Docker services**: + ```bash + docker-compose up -d + ``` + This will start both Postgres and Martin. Martin will wait for Postgres to be healthy. + +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** (if not already done): + ```bash + npx tsx ./db/migrate.ts + ``` + This will create the `analysis_view` and other database structures. + +4. **Verify Martin is running and discovering views**: + ```bash + curl http://localhost:3000/catalog + ``` + Should return JSON with available tile sources in the `tiles` object. You should see `analysis_view` listed if it has data with geometry. + + To check if the view is properly configured: + ```bash + docker exec frontend-postgres-1 psql -U postgres -d opensensemap -c "SELECT Find_SRID('public', 'analysis_view', 'geometry');" + ``` + Should return `4326`. + +5. **Start the frontend**: + ```bash + npm run dev + ``` + +## Troubleshooting + +### Martin container keeps restarting + +- **PostGIS not enabled**: Ensure PostGIS extension is created in your database + ```bash + docker exec frontend-postgres-1 psql -U postgres -d opensensemap -c "CREATE EXTENSION IF NOT EXISTS postgis CASCADE;" + ``` +- **Database connection issues**: Check Martin logs for connection errors + ```bash + docker-compose logs martin + ``` +- **Wrong database name**: Ensure `DATABASE_URL` in `docker-compose.yml` matches your database name + +### Martin not accessible + +- Check if Martin container is running: `docker-compose ps` +- Check Martin logs: `docker-compose logs martin` +- Verify database connection in Martin logs + +### Tiles not loading / Catalog is empty + +- **SRID issue**: Martin requires geometry columns to have SRID 4326 (not 0). Check the view: + ```bash + docker exec frontend-postgres-1 psql -U postgres -d opensensemap -c "SELECT Find_SRID('public', 'analysis_view', 'geometry');" + ``` + Should return `4326`. If it returns `0`, the view needs to be updated to ensure proper SRID casting. +- **No data with geometry**: Martin only discovers views/tables that have at least one row with a non-null geometry. Check if the view has data: + ```bash + docker exec frontend-postgres-1 psql -U postgres -d opensensemap -c "SELECT COUNT(*) FROM analysis_view WHERE geometry IS NOT NULL;" + ``` +- Verify the view exists: `docker exec frontend-postgres-1 psql -U postgres -d opensensemap -c "\dv analysis_view"` +- Check Martin catalog: `curl http://localhost:3000/catalog` +- Check browser console for errors +- Verify `MARTIN_URL` environment variable is set correctly +- Check Martin logs for discovery errors: `docker-compose logs martin` + +### Port conflicts + +If port 3000 is already in use: +- Change Martin's port in `docker-compose.yml`: + ```yaml + ports: + - "3001:3000" # Use 3001 on host + ``` +- Update `MARTIN_URL` in `.env` to match: `MARTIN_URL=http://localhost:3001` + +## Direct Martin Access + +Martin is accessible directly and has CORS enabled, so you can use it from your frontend without any proxy: + +- **Catalog**: `http://localhost:3000/catalog` - Lists all available tile sources (automatically discovers views/tables with geometry columns) +- **TileJSON**: `http://localhost:3000/analysis_view` - Metadata for the analysis_view source +- **Tiles**: `http://localhost:3000/analysis_view/{z}/{x}/{y}.pbf` - Vector tile data + +**Important**: Martin only discovers views/tables that: +- Have geometry columns with SRID 4326 +- Contain at least one row with a non-null geometry + +Martin automatically handles CORS, so you can use these URLs directly in your Mapbox GL sources. + +## View Structure + +The `analysis_view` groups measurements by time and device, aggregating all sensor measurements into a JSONB object: + +```sql +SELECT + "createdAt", -- timestamp + "boxId", -- device ID + tags, -- device tags array + geometry, -- PostGIS Point (SRID 4326) + measurements -- JSONB: { "sensor_name": { "value": ..., "unit": ..., "sensor_id": ... } } +FROM analysis_view; +``` + +Each sensor measurement in the `measurements` JSONB object contains: +- `value`: The measurement value +- `unit`: The unit of measurement +- `sensor_id`: The sensor ID + diff --git a/app/utils/env.server.ts b/app/utils/env.server.ts index bc67a6fb..6286a579 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:3000", }; } diff --git a/docker-compose.yml b/docker-compose.yml index aed6c8a7..f46a4b3b 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: + - "3000: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..26e4d18e --- /dev/null +++ b/drizzle/0023_create_analysis_view.sql @@ -0,0 +1,65 @@ +-- Create an analysis view that flattens measurements with device, location, and sensor data +-- This view provides a denormalized structure for data analysis +-- +-- Structure: +-- - createdAt: measurement timestamp +-- - boxId: device ID +-- - tags: device tags array +-- - geometry: location point (SRID 4326) - uses the location from measurement if available +-- - measurements: JSONB object containing all sensor measurements +-- Each sensor is a key with value, unit, and sensor_id metadata +-- +-- 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. +CREATE OR REPLACE VIEW analysis_view AS +WITH grouped_measurements AS ( + SELECT + m.time, + d.id AS device_id, + d.tags, + MAX(m.location_id) AS location_id, + -- JSONB object for all sensor measurements + -- Key: sensor_wiki_phenomenon or sensor_type or title or sensor_id + -- Value: object with value, unit, and sensor_id + COALESCE( + jsonb_object_agg( + COALESCE( + NULLIF(s.sensor_wiki_phenomenon, ''), + NULLIF(s.sensor_type, ''), + NULLIF(s.title, ''), + s.id::text + ), + jsonb_build_object( + 'value', m.value, + 'unit', COALESCE(s.unit, ''), + 'sensor_id', s.id + ) + ), + '{}'::jsonb + ) AS measurements + FROM measurement m + INNER JOIN sensor s ON m.sensor_id = s.id + INNER JOIN device d ON s.device_id = d.id + GROUP BY + m.time, + d.id, + d.tags +) +SELECT + gm.time AS "createdAt", + gm.device_id AS "boxId", + gm.tags, + l.location::geometry(Point, 4326) AS geometry, + gm.measurements +FROM grouped_measurements gm +LEFT JOIN location l ON gm.location_id = l.id; + +-- Add comment to help identify this view +COMMENT ON VIEW analysis_view IS 'Denormalized view for data analysis combining measurements, devices, sensors, and locations. All sensor measurements are stored in a JSONB object with value, unit, and sensor_id metadata.'; + +-- Create index on the view's key columns for better query performance +-- Note: You may want to add indexes on the underlying tables instead: +-- 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 From 367534dce11a5986d9ce4e91c4458a7adaac07bc Mon Sep 17 00:00:00 2001 From: Maria Zadnepryanets Date: Thu, 6 Nov 2025 14:56:49 +0100 Subject: [PATCH 02/12] fix: port routing and add endpoint to expose view data --- MARTIN_SETUP.md | 36 +++++++-------- app/routes/api.analysis.ts | 89 ++++++++++++++++++++++++++++++++++++++ app/utils/env.server.ts | 2 +- docker-compose.yml | 2 +- 4 files changed, 110 insertions(+), 19 deletions(-) create mode 100644 app/routes/api.analysis.ts diff --git a/MARTIN_SETUP.md b/MARTIN_SETUP.md index c9af704e..d97d4f95 100644 --- a/MARTIN_SETUP.md +++ b/MARTIN_SETUP.md @@ -27,7 +27,7 @@ The view provides a denormalized structure with: ### 2. Docker Configuration Martin is configured in `docker-compose.yml`: -- Runs on port `3000` +- Runs on port `3001` (host) mapped to port `3000` (container) - Connects to the database specified in your `DATABASE_URL` (defaults to `opensensemap`) - Uses the same Docker network (`app-network`) - Waits for Postgres to be healthy before starting @@ -36,10 +36,12 @@ Martin is configured in `docker-compose.yml`: Add to your `.env` file (optional): ```bash -MARTIN_URL=http://localhost:3000 +MARTIN_URL=http://localhost:3001 ``` -If not set, it defaults to `http://localhost:3000`. +If not set, it defaults to `http://localhost:3001`. + +**Note**: Martin runs on port `3001` to avoid conflicts with the frontend dev server (port `3000`). **Note**: Martin's `DATABASE_URL` in `docker-compose.yml` should match your application's database name. Currently configured for `opensensemap` database. @@ -47,15 +49,15 @@ If not set, it defaults to `http://localhost:3000`. ### Accessing Martin -Martin is accessible directly at `http://localhost:3000` (or your configured `MARTIN_URL`): +Martin is accessible directly at `http://localhost:3001` (or your configured `MARTIN_URL`): -- **TileJSON**: `http://localhost:3000/{source_name}` +- **TileJSON**: `http://localhost:3001/{source_name}` - Returns metadata about the tile source - - Example: `http://localhost:3000/analysis_view` + - Example: `http://localhost:3001/analysis_view` -- **Tiles**: `http://localhost:3000/{source_name}/{z}/{x}/{y}.pbf` +- **Tiles**: `http://localhost:3001/{source_name}/{z}/{x}/{y}.pbf` - Returns vector tile data for a specific tile - - Example: `http://localhost:3000/analysis_view/10/512/512.pbf` + - Example: `http://localhost:3001/analysis_view/10/512/512.pbf` ### Using in React Components @@ -67,7 +69,7 @@ import { MapProvider } from "react-map-gl"; import Map from "~/components/map/map"; function MyMapWithPoints() { - const martinUrl = window.ENV?.MARTIN_URL || "http://localhost:3000"; + const martinUrl = window.ENV?.MARTIN_URL || "http://localhost:3001"; // Construct the tile URL template directly // Mapbox GL will replace {z}, {x}, {y} with actual tile coordinates @@ -116,7 +118,7 @@ function MyMapWithPoints() { 4. **Verify Martin is running and discovering views**: ```bash - curl http://localhost:3000/catalog + curl http://localhost:3001/catalog ``` Should return JSON with available tile sources in the `tiles` object. You should see `analysis_view` listed if it has data with geometry. @@ -163,28 +165,28 @@ function MyMapWithPoints() { docker exec frontend-postgres-1 psql -U postgres -d opensensemap -c "SELECT COUNT(*) FROM analysis_view WHERE geometry IS NOT NULL;" ``` - Verify the view exists: `docker exec frontend-postgres-1 psql -U postgres -d opensensemap -c "\dv analysis_view"` -- Check Martin catalog: `curl http://localhost:3000/catalog` +- Check Martin catalog: `curl http://localhost:3001/catalog` - Check browser console for errors - Verify `MARTIN_URL` environment variable is set correctly - Check Martin logs for discovery errors: `docker-compose logs martin` ### Port conflicts -If port 3000 is already in use: +If port 3001 is already in use: - Change Martin's port in `docker-compose.yml`: ```yaml ports: - - "3001:3000" # Use 3001 on host + - "3002:3000" # Use 3002 on host ``` -- Update `MARTIN_URL` in `.env` to match: `MARTIN_URL=http://localhost:3001` +- Update `MARTIN_URL` in `.env` to match: `MARTIN_URL=http://localhost:3002` ## Direct Martin Access Martin is accessible directly and has CORS enabled, so you can use it from your frontend without any proxy: -- **Catalog**: `http://localhost:3000/catalog` - Lists all available tile sources (automatically discovers views/tables with geometry columns) -- **TileJSON**: `http://localhost:3000/analysis_view` - Metadata for the analysis_view source -- **Tiles**: `http://localhost:3000/analysis_view/{z}/{x}/{y}.pbf` - Vector tile data +- **Catalog**: `http://localhost:3001/catalog` - Lists all available tile sources (automatically discovers views/tables with geometry columns) +- **TileJSON**: `http://localhost:3001/analysis_view` - Metadata for the analysis_view source +- **Tiles**: `http://localhost:3001/analysis_view/{z}/{x}/{y}.pbf` - Vector tile data **Important**: Martin only discovers views/tables that: - Have geometry columns with SRID 4326 diff --git a/app/routes/api.analysis.ts b/app/routes/api.analysis.ts new file mode 100644 index 00000000..38029b2d --- /dev/null +++ b/app/routes/api.analysis.ts @@ -0,0 +1,89 @@ +import { type LoaderFunctionArgs } from "react-router"; +import { drizzleClient } from "~/db.server"; +import { sql } from "drizzle-orm"; + +export async function loader({ request }: LoaderFunctionArgs) { + try { + const url = new URL(request.url); + const limitParam = url.searchParams.get("limit"); + const offsetParam = url.searchParams.get("offset"); + const boxIdParam = url.searchParams.get("boxId"); + const hasGeometryParam = url.searchParams.get("hasGeometry"); + + const limit = limitParam ? Math.min(parseInt(limitParam, 10), 1000) : 100; + const offset = offsetParam ? parseInt(offsetParam, 10) : 0; + const hasGeometry = hasGeometryParam?.toLowerCase() === "true"; + + let query = sql` + SELECT + "createdAt", + "boxId", + tags, + CASE + WHEN geometry IS NOT NULL + THEN ST_AsGeoJSON(geometry)::jsonb + ELSE NULL + END as geometry, + measurements + FROM analysis_view + WHERE 1=1 + `; + + if (boxIdParam) { + query = sql`${query} AND "boxId" = ${boxIdParam}`; + } + + if (hasGeometry) { + query = sql`${query} AND geometry IS NOT NULL`; + } + + query = sql`${query} ORDER BY "createdAt" DESC LIMIT ${limit} OFFSET ${offset}`; + + const results = await drizzleClient.execute(query); + + // Get total count for pagination + let countQuery = sql`SELECT COUNT(*) as total FROM analysis_view WHERE 1=1`; + if (boxIdParam) { + countQuery = sql`${countQuery} AND "boxId" = ${boxIdParam}`; + } + if (hasGeometry) { + countQuery = sql`${countQuery} AND geometry IS NOT NULL`; + } + const [countResult] = await drizzleClient.execute(countQuery); + const total = Number(countResult.total); + + return Response.json( + { + data: results, + pagination: { + limit, + offset, + total, + hasMore: offset + limit < total, + }, + }, + { + status: 200, + headers: { + "Content-Type": "application/json; charset=utf-8", + }, + }, + ); + } catch (e) { + console.warn(e); + return Response.json( + { + error: "Internal Server Error", + message: + "The server was unable to complete your request. Please try again later.", + }, + { + status: 500, + headers: { + "Content-Type": "application/json; charset=utf-8", + }, + }, + ); + } +} + diff --git a/app/utils/env.server.ts b/app/utils/env.server.ts index 6286a579..00b45be6 100644 --- a/app/utils/env.server.ts +++ b/app/utils/env.server.ts @@ -46,7 +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:3000", + MARTIN_URL: process.env.MARTIN_URL || "http://localhost:3001", }; } diff --git a/docker-compose.yml b/docker-compose.yml index f46a4b3b..cffece0a 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -29,7 +29,7 @@ services: image: ghcr.io/maplibre/martin:latest restart: always ports: - - "3000:3000" + - "3001:3000" environment: - DATABASE_URL=postgresql://postgres:postgres@postgres:5432/opensensemap?sslmode=disable depends_on: From 9d6d49d0adb02f7a4bc78fa1c452deb3c21b37c9 Mon Sep 17 00:00:00 2001 From: Maria Zadnepryanets Date: Thu, 6 Nov 2025 15:10:57 +0100 Subject: [PATCH 03/12] refactor: remove unnecessary documentation --- MARTIN_SETUP.md | 99 ------------------------------------------------- 1 file changed, 99 deletions(-) diff --git a/MARTIN_SETUP.md b/MARTIN_SETUP.md index d97d4f95..cdabb06c 100644 --- a/MARTIN_SETUP.md +++ b/MARTIN_SETUP.md @@ -59,44 +59,6 @@ Martin is accessible directly at `http://localhost:3001` (or your configured `MA - Returns vector tile data for a specific tile - Example: `http://localhost:3001/analysis_view/10/512/512.pbf` -### Using in React Components - -Add Martin vector tiles to your map using the `Source` and `Layer` components from `react-map-gl`: - -```tsx -import { Source, Layer } from "react-map-gl"; -import { MapProvider } from "react-map-gl"; -import Map from "~/components/map/map"; - -function MyMapWithPoints() { - const martinUrl = window.ENV?.MARTIN_URL || "http://localhost:3001"; - - // Construct the tile URL template directly - // Mapbox GL will replace {z}, {x}, {y} with actual tile coordinates - const tileUrl = `${martinUrl}/analysis_view/{z}/{x}/{y}.pbf`; - - return ( - - - - - - - - ); -} -``` - ## Starting the Services 1. **Start Docker services**: @@ -133,67 +95,6 @@ function MyMapWithPoints() { npm run dev ``` -## Troubleshooting - -### Martin container keeps restarting - -- **PostGIS not enabled**: Ensure PostGIS extension is created in your database - ```bash - docker exec frontend-postgres-1 psql -U postgres -d opensensemap -c "CREATE EXTENSION IF NOT EXISTS postgis CASCADE;" - ``` -- **Database connection issues**: Check Martin logs for connection errors - ```bash - docker-compose logs martin - ``` -- **Wrong database name**: Ensure `DATABASE_URL` in `docker-compose.yml` matches your database name - -### Martin not accessible - -- Check if Martin container is running: `docker-compose ps` -- Check Martin logs: `docker-compose logs martin` -- Verify database connection in Martin logs - -### Tiles not loading / Catalog is empty - -- **SRID issue**: Martin requires geometry columns to have SRID 4326 (not 0). Check the view: - ```bash - docker exec frontend-postgres-1 psql -U postgres -d opensensemap -c "SELECT Find_SRID('public', 'analysis_view', 'geometry');" - ``` - Should return `4326`. If it returns `0`, the view needs to be updated to ensure proper SRID casting. -- **No data with geometry**: Martin only discovers views/tables that have at least one row with a non-null geometry. Check if the view has data: - ```bash - docker exec frontend-postgres-1 psql -U postgres -d opensensemap -c "SELECT COUNT(*) FROM analysis_view WHERE geometry IS NOT NULL;" - ``` -- Verify the view exists: `docker exec frontend-postgres-1 psql -U postgres -d opensensemap -c "\dv analysis_view"` -- Check Martin catalog: `curl http://localhost:3001/catalog` -- Check browser console for errors -- Verify `MARTIN_URL` environment variable is set correctly -- Check Martin logs for discovery errors: `docker-compose logs martin` - -### Port conflicts - -If port 3001 is already in use: -- Change Martin's port in `docker-compose.yml`: - ```yaml - ports: - - "3002:3000" # Use 3002 on host - ``` -- Update `MARTIN_URL` in `.env` to match: `MARTIN_URL=http://localhost:3002` - -## Direct Martin Access - -Martin is accessible directly and has CORS enabled, so you can use it from your frontend without any proxy: - -- **Catalog**: `http://localhost:3001/catalog` - Lists all available tile sources (automatically discovers views/tables with geometry columns) -- **TileJSON**: `http://localhost:3001/analysis_view` - Metadata for the analysis_view source -- **Tiles**: `http://localhost:3001/analysis_view/{z}/{x}/{y}.pbf` - Vector tile data - -**Important**: Martin only discovers views/tables that: -- Have geometry columns with SRID 4326 -- Contain at least one row with a non-null geometry - -Martin automatically handles CORS, so you can use these URLs directly in your Mapbox GL sources. - ## View Structure The `analysis_view` groups measurements by time and device, aggregating all sensor measurements into a JSONB object: From b940d3e7a1b471d62e44fbcda0a57a5375ac1a5c Mon Sep 17 00:00:00 2001 From: Maria Zadnepryanets Date: Thu, 6 Nov 2025 15:27:24 +0100 Subject: [PATCH 04/12] feat: add markAsReadParam to clear view once data is read --- app/routes/api.analysis.ts | 35 +++++++++++++++++++- app/routes/api.measurements.ts | 15 +++++++++ drizzle/0023_create_analysis_view.sql | 46 +++++++++++++++++++++++---- 3 files changed, 89 insertions(+), 7 deletions(-) diff --git a/app/routes/api.analysis.ts b/app/routes/api.analysis.ts index 38029b2d..50c4b62b 100644 --- a/app/routes/api.analysis.ts +++ b/app/routes/api.analysis.ts @@ -9,10 +9,12 @@ export async function loader({ request }: LoaderFunctionArgs) { const offsetParam = url.searchParams.get("offset"); const boxIdParam = url.searchParams.get("boxId"); const hasGeometryParam = url.searchParams.get("hasGeometry"); + const markAsReadParam = url.searchParams.get("markAsRead"); const limit = limitParam ? Math.min(parseInt(limitParam, 10), 1000) : 100; const offset = offsetParam ? parseInt(offsetParam, 10) : 0; const hasGeometry = hasGeometryParam?.toLowerCase() === "true"; + const markAsRead = markAsReadParam?.toLowerCase() === "true"; let query = sql` SELECT @@ -52,6 +54,34 @@ export async function loader({ request }: LoaderFunctionArgs) { const [countResult] = await drizzleClient.execute(countQuery); const total = Number(countResult.total); + // If markAsRead is true, mark the returned items as processed + if (markAsRead && results.length > 0) { + // Mark each returned item as processed + // Using individual inserts with ON CONFLICT for reliability + for (const row of results) { + // Convert createdAt to ISO string format for PostgreSQL + const createdAt = row.createdAt instanceof Date + ? row.createdAt.toISOString() + : typeof row.createdAt === 'string' + ? row.createdAt + : new Date(row.createdAt).toISOString(); + + await drizzleClient.execute( + sql` + INSERT INTO processed_measurements (device_id, time, processed_at) + VALUES (${row.boxId}, ${createdAt}::timestamptz, NOW()) + ON CONFLICT (device_id, time) DO NOTHING + ` + ); + } + + // Refresh the materialized view to exclude processed measurements + // Use CONCURRENTLY to avoid locking (requires unique index) + await drizzleClient.execute( + sql`REFRESH MATERIALIZED VIEW CONCURRENTLY analysis_view` + ); + } + return Response.json( { data: results, @@ -61,6 +91,7 @@ export async function loader({ request }: LoaderFunctionArgs) { total, hasMore: offset + limit < total, }, + markedAsRead: markAsRead ? results.length : 0, }, { status: 200, @@ -70,12 +101,14 @@ export async function loader({ request }: LoaderFunctionArgs) { }, ); } catch (e) { - console.warn(e); + console.error("Error in /api/analysis:", e); + const errorMessage = e instanceof Error ? e.message : String(e); return Response.json( { error: "Internal Server Error", message: "The server was unable to complete your request. Please try again later.", + details: process.env.NODE_ENV === "development" ? errorMessage : undefined, }, { status: 500, diff --git a/app/routes/api.measurements.ts b/app/routes/api.measurements.ts index a8f9e825..f5f390ef 100644 --- a/app/routes/api.measurements.ts +++ b/app/routes/api.measurements.ts @@ -1,6 +1,7 @@ import { type ActionFunctionArgs } from "react-router"; import { drizzleClient } from "~/db.server"; import { measurement, type Measurement } from "~/schema"; +import { sql } from "drizzle-orm"; /** * @openapi @@ -97,6 +98,20 @@ export const action = async ({ request }: ActionFunctionArgs) => { await drizzleClient.insert(measurement).values(measurements); + // Refresh the materialized view to include new measurements + // Use CONCURRENTLY to avoid locking (requires unique index) + try { + await drizzleClient.execute( + sql`REFRESH MATERIALIZED VIEW CONCURRENTLY analysis_view` + ); + } catch (refreshError) { + // If concurrent refresh fails (e.g., no unique index), fall back to regular refresh + console.warn("Concurrent refresh failed, using regular refresh:", refreshError); + await drizzleClient.execute( + sql`REFRESH MATERIALIZED VIEW analysis_view` + ); + } + return Response.json({ message: "Measurements successfully stored" }); } catch (error) { diff --git a/drizzle/0023_create_analysis_view.sql b/drizzle/0023_create_analysis_view.sql index 26e4d18e..db631be2 100644 --- a/drizzle/0023_create_analysis_view.sql +++ b/drizzle/0023_create_analysis_view.sql @@ -1,4 +1,16 @@ --- Create an analysis view that flattens measurements with device, location, and sensor data +-- 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 materialized view that flattens measurements with device, location, and sensor data -- This view provides a denormalized structure for data analysis -- -- Structure: @@ -11,7 +23,10 @@ -- -- 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. -CREATE OR REPLACE VIEW analysis_view AS +-- 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 MATERIALIZED VIEW analysis_view AS WITH grouped_measurements AS ( SELECT m.time, @@ -52,13 +67,32 @@ SELECT l.location::geometry(Point, 4326) AS geometry, gm.measurements FROM grouped_measurements gm -LEFT JOIN location l ON gm.location_id = l.id; +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. All sensor measurements are stored in a JSONB object with value, unit, and sensor_id metadata.'; +COMMENT ON MATERIALIZED VIEW analysis_view IS 'Denormalized materialized view for data analysis combining measurements, devices, sensors, and locations. All sensor measurements are stored in a JSONB object with value, unit, and sensor_id metadata. Only includes unprocessed measurements.'; + +-- Create unique index on materialized view for concurrent refresh +CREATE UNIQUE INDEX IF NOT EXISTS analysis_view_created_at_boxid_unique + ON analysis_view("createdAt", "boxId"); + +-- Create indexes on the materialized view for better query performance +CREATE INDEX IF NOT EXISTS idx_analysis_view_created_at + ON analysis_view("createdAt" DESC); +CREATE INDEX IF NOT EXISTS idx_analysis_view_boxid + ON analysis_view("boxId"); +CREATE INDEX IF NOT EXISTS idx_analysis_view_geometry + ON analysis_view USING GIST(geometry) + WHERE geometry IS NOT NULL; + +-- Initial population of the materialized view +REFRESH MATERIALIZED VIEW analysis_view; --- Create index on the view's key columns for better query performance --- Note: You may want to add indexes on the underlying tables instead: +-- 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); From 3d8b2ce41246f74f1cfc1b57978d417be5e32f61 Mon Sep 17 00:00:00 2001 From: Maria Zadnepryanets Date: Mon, 10 Nov 2025 13:30:17 +0100 Subject: [PATCH 05/12] feat: convert measurements from jsonb to columns in analysis_view --- MARTIN_SETUP.md | 38 ++++-- app/routes/api.analysis.ts | 22 +++- drizzle/0023_create_analysis_view.sql | 181 +++++++++++++++++++++----- 3 files changed, 195 insertions(+), 46 deletions(-) diff --git a/MARTIN_SETUP.md b/MARTIN_SETUP.md index cdabb06c..65a1384b 100644 --- a/MARTIN_SETUP.md +++ b/MARTIN_SETUP.md @@ -20,7 +20,8 @@ The view provides a denormalized structure with: - `boxId`: device ID - `tags`: device tags array - `geometry`: location point (SRID 4326) -- `measurements`: JSONB object containing all sensor measurements +- Scalar columns for common phenomena (e.g. `temperature`, `humidity`, `soil_moisture`, `pressure`, `pm1`, `pm2_5`, `pm4`, `pm10`, `wind_speed`, `light_intensity`, `uv_intensity`, `uv_index`, `sound_level`, `sound_level_eq`, `sound_level_min`, `sound_level_max`, `voc`, `co2`) +- `measurements`: JSONB object containing the raw sensor payload (kept for debugging and future extensions) **Note**: Martin automatically discovers tables and views with geometry columns that have SRID 4326. The `analysis_view` geometry column is properly configured for Martin. @@ -100,17 +101,32 @@ Martin is accessible directly at `http://localhost:3001` (or your configured `MA The `analysis_view` groups measurements by time and device, aggregating all sensor measurements into a JSONB object: ```sql -SELECT - "createdAt", -- timestamp - "boxId", -- device ID - tags, -- device tags array - geometry, -- PostGIS Point (SRID 4326) - measurements -- JSONB: { "sensor_name": { "value": ..., "unit": ..., "sensor_id": ... } } +SELECT + "createdAt", -- timestamp + "boxId", -- device ID + tags, -- device tags array + geometry, -- PostGIS Point (SRID 4326) + temperature, + soil_temperature, + humidity, + soil_moisture, + pressure, + pm1, + pm2_5, + pm4, + pm10, + wind_speed, + light_intensity, + uv_intensity, + uv_index, + sound_level, + sound_level_eq, + sound_level_min, + sound_level_max, + voc, + co2 FROM analysis_view; ``` -Each sensor measurement in the `measurements` JSONB object contains: -- `value`: The measurement value -- `unit`: The unit of measurement -- `sensor_id`: The sensor ID +> Martin consumes the scalar columns directly. The JSONB payload remains available in the view for troubleshooting, but it is no longer served through `/api/analysis` and is not used when generating vector tiles. diff --git a/app/routes/api.analysis.ts b/app/routes/api.analysis.ts index 50c4b62b..162dcdb0 100644 --- a/app/routes/api.analysis.ts +++ b/app/routes/api.analysis.ts @@ -26,7 +26,25 @@ export async function loader({ request }: LoaderFunctionArgs) { THEN ST_AsGeoJSON(geometry)::jsonb ELSE NULL END as geometry, - measurements + temperature, + soil_temperature, + humidity, + soil_moisture, + pressure, + pm1, + pm2_5, + pm4, + pm10, + wind_speed, + light_intensity, + uv_intensity, + uv_index, + sound_level, + sound_level_eq, + sound_level_min, + sound_level_max, + voc, + co2 FROM analysis_view WHERE 1=1 `; @@ -41,7 +59,7 @@ export async function loader({ request }: LoaderFunctionArgs) { query = sql`${query} ORDER BY "createdAt" DESC LIMIT ${limit} OFFSET ${offset}`; - const results = await drizzleClient.execute(query); + const results = await drizzleClient.execute>(query); // Get total count for pagination let countQuery = sql`SELECT COUNT(*) as total FROM analysis_view WHERE 1=1`; diff --git a/drizzle/0023_create_analysis_view.sql b/drizzle/0023_create_analysis_view.sql index db631be2..da0fba6b 100644 --- a/drizzle/0023_create_analysis_view.sql +++ b/drizzle/0023_create_analysis_view.sql @@ -14,12 +14,11 @@ CREATE INDEX IF NOT EXISTS idx_processed_measurements_device_time -- This view provides a denormalized structure for data analysis -- -- Structure: --- - createdAt: measurement timestamp --- - boxId: device ID --- - tags: device tags array --- - geometry: location point (SRID 4326) - uses the location from measurement if available --- - measurements: JSONB object containing all sensor measurements --- Each sensor is a key with value, unit, and sensor_id metadata +-- - `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 `/api/analysis` and 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. @@ -27,45 +26,161 @@ CREATE INDEX IF NOT EXISTS idx_processed_measurements_device_time DROP VIEW IF EXISTS analysis_view; DROP MATERIALIZED VIEW IF EXISTS analysis_view; CREATE MATERIALIZED VIEW analysis_view AS -WITH grouped_measurements AS ( - SELECT +WITH sensor_measurements AS ( + SELECT m.time, d.id AS device_id, d.tags, - MAX(m.location_id) AS location_id, - -- JSONB object for all sensor measurements - -- Key: sensor_wiki_phenomenon or sensor_type or title or sensor_id - -- Value: object with value, unit, and sensor_id + 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( - jsonb_object_agg( - COALESCE( - NULLIF(s.sensor_wiki_phenomenon, ''), - NULLIF(s.sensor_type, ''), - NULLIF(s.title, ''), - s.id::text - ), - jsonb_build_object( - 'value', m.value, - 'unit', COALESCE(s.unit, ''), - 'sensor_id', s.id - ) - ), - '{}'::jsonb - ) AS measurements + 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 - GROUP BY - m.time, - d.id, - d.tags +), +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.measurements + 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 @@ -74,7 +189,7 @@ LEFT JOIN processed_measurements pm WHERE pm.device_id IS NULL; -- Only include unprocessed measurements -- Add comment to help identify this view -COMMENT ON MATERIALIZED VIEW analysis_view IS 'Denormalized materialized view for data analysis combining measurements, devices, sensors, and locations. All sensor measurements are stored in a JSONB object with value, unit, and sensor_id metadata. Only includes unprocessed measurements.'; +COMMENT ON MATERIALIZED VIEW analysis_view IS 'Denormalized materialized 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.'; -- Create unique index on materialized view for concurrent refresh CREATE UNIQUE INDEX IF NOT EXISTS analysis_view_created_at_boxid_unique From 5476268bbd0483f309291f812e1a197517810b5f Mon Sep 17 00:00:00 2001 From: Maria Zadnepryanets Date: Mon, 10 Nov 2025 13:32:14 +0100 Subject: [PATCH 06/12] doc: udpate martin_setup.md --- MARTIN_SETUP.md | 6 ++---- 1 file changed, 2 insertions(+), 4 deletions(-) diff --git a/MARTIN_SETUP.md b/MARTIN_SETUP.md index 65a1384b..ace49190 100644 --- a/MARTIN_SETUP.md +++ b/MARTIN_SETUP.md @@ -21,9 +21,8 @@ The view provides a denormalized structure with: - `tags`: device tags array - `geometry`: location point (SRID 4326) - Scalar columns for common phenomena (e.g. `temperature`, `humidity`, `soil_moisture`, `pressure`, `pm1`, `pm2_5`, `pm4`, `pm10`, `wind_speed`, `light_intensity`, `uv_intensity`, `uv_index`, `sound_level`, `sound_level_eq`, `sound_level_min`, `sound_level_max`, `voc`, `co2`) -- `measurements`: JSONB object containing the raw sensor payload (kept for debugging and future extensions) -**Note**: Martin automatically discovers tables and views with geometry columns that have SRID 4326. The `analysis_view` geometry column is properly configured for Martin. +**Note**: Martin automatically discovers tables and views with geometry columns that have SRID 4326, ( `analysis_view` in our case). ### 2. Docker Configuration @@ -33,7 +32,7 @@ Martin is configured in `docker-compose.yml`: - Uses the same Docker network (`app-network`) - Waits for Postgres to be healthy before starting -### 3. Environment Variables +### 3. Local Environment Variables Add to your `.env` file (optional): ```bash @@ -128,5 +127,4 @@ SELECT FROM analysis_view; ``` -> Martin consumes the scalar columns directly. The JSONB payload remains available in the view for troubleshooting, but it is no longer served through `/api/analysis` and is not used when generating vector tiles. From d9bbb0d74a6754f4fe648ec0711ff5fdf273da68 Mon Sep 17 00:00:00 2001 From: Maria Zadnepryanets Date: Mon, 17 Nov 2025 14:32:05 +0100 Subject: [PATCH 07/12] chore: remove endpoints and update martin setup doc --- MARTIN_SETUP.md | 124 ++++++++--------------- app/routes/api.analysis.ts | 140 -------------------------- app/routes/api.measurements.ts | 120 ---------------------- drizzle/0023_create_analysis_view.sql | 2 +- 4 files changed, 41 insertions(+), 345 deletions(-) delete mode 100644 app/routes/api.analysis.ts delete mode 100644 app/routes/api.measurements.ts diff --git a/MARTIN_SETUP.md b/MARTIN_SETUP.md index ace49190..78408a2c 100644 --- a/MARTIN_SETUP.md +++ b/MARTIN_SETUP.md @@ -1,130 +1,86 @@ # Martin Tile Server Setup -This document explains how to use Martin tile server to serve vector tiles from your PostGIS database. +Martin tile server serves vector tiles from PostGIS database views. ## Overview -Martin is a tile server that generates and serves vector tiles on the fly from PostGIS databases. It's configured to: -- Run in the same Docker network as your PostGIS database -- Automatically discover tables and views with geometry columns (SRID 4326) -- Serve them as Mapbox Vector Tiles +Martin automatically discovers tables and views with geometry columns (SRID 4326) and serves them as Mapbox Vector Tiles. ## Setup -### 1. Database Views - -**Analysis View**: A database view `analysis_view` has been created for data analysis. The migration is in `drizzle/0023_create_analysis_view.sql`. - -The view provides a denormalized structure with: -- `createdAt`: measurement timestamp -- `boxId`: device ID -- `tags`: device tags array -- `geometry`: location point (SRID 4326) -- Scalar columns for common phenomena (e.g. `temperature`, `humidity`, `soil_moisture`, `pressure`, `pm1`, `pm2_5`, `pm4`, `pm10`, `wind_speed`, `light_intensity`, `uv_intensity`, `uv_index`, `sound_level`, `sound_level_eq`, `sound_level_min`, `sound_level_max`, `voc`, `co2`) - -**Note**: Martin automatically discovers tables and views with geometry columns that have SRID 4326, ( `analysis_view` in our case). - -### 2. Docker Configuration +### 1. Docker Configuration Martin is configured in `docker-compose.yml`: - Runs on port `3001` (host) mapped to port `3000` (container) -- Connects to the database specified in your `DATABASE_URL` (defaults to `opensensemap`) -- Uses the same Docker network (`app-network`) +- Connects to the `opensensemap` database - Waits for Postgres to be healthy before starting -### 3. Local Environment Variables +### 2. Environment Variables -Add to your `.env` file (optional): +Optional `.env` variable: ```bash MARTIN_URL=http://localhost:3001 ``` -If not set, it defaults to `http://localhost:3001`. +Defaults to `http://localhost:3001` if not set. -**Note**: Martin runs on port `3001` to avoid conflicts with the frontend dev server (port `3000`). +### 3. Database View -**Note**: Martin's `DATABASE_URL` in `docker-compose.yml` should match your application's database name. Currently configured for `opensensemap` database. +The `analysis_view` materialized view (created by migration `drizzle/0023_create_analysis_view.sql`) is automatically discovered by Martin. -## Usage - -### Accessing Martin +The view includes: +- `createdAt`, `boxId`, `tags` +- `geometry` (PostGIS Point, SRID 4326) +- Sensor data columns (temperature, humidity, PM values, etc.) -Martin is accessible directly at `http://localhost:3001` (or your configured `MARTIN_URL`): +## Usage -- **TileJSON**: `http://localhost:3001/{source_name}` - - Returns metadata about the tile source - - Example: `http://localhost:3001/analysis_view` +### Endpoints -- **Tiles**: `http://localhost:3001/{source_name}/{z}/{x}/{y}.pbf` - - Returns vector tile data for a specific tile - - Example: `http://localhost:3001/analysis_view/10/512/512.pbf` +- **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 the Services +### Starting Services -1. **Start Docker services**: +1. Start Docker services: ```bash docker-compose up -d ``` - This will start both Postgres and Martin. Martin will wait for Postgres to be healthy. -2. **Ensure PostGIS is enabled**: +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** (if not already done): +3. Run migrations: ```bash npx tsx ./db/migrate.ts ``` - This will create the `analysis_view` and other database structures. -4. **Verify Martin is running and discovering views**: +4. Verify Martin is running: ```bash curl http://localhost:3001/catalog ``` - Should return JSON with available tile sources in the `tiles` object. You should see `analysis_view` listed if it has data with geometry. - - To check if the view is properly configured: - ```bash - docker exec frontend-postgres-1 psql -U postgres -d opensensemap -c "SELECT Find_SRID('public', 'analysis_view', 'geometry');" - ``` - Should return `4326`. -5. **Start the frontend**: - ```bash - npm run dev - ``` +### Adding Data + +Use `/api/boxes/{deviceId}/{sensorId}` to add measurements with optional location: -## View Structure - -The `analysis_view` groups measurements by time and device, aggregating all sensor measurements into a JSONB object: - -```sql -SELECT - "createdAt", -- timestamp - "boxId", -- device ID - tags, -- device tags array - geometry, -- PostGIS Point (SRID 4326) - temperature, - soil_temperature, - humidity, - soil_moisture, - pressure, - pm1, - pm2_5, - pm4, - pm10, - wind_speed, - light_intensity, - uv_intensity, - uv_index, - sound_level, - sound_level_eq, - sound_level_min, - sound_level_max, - voc, - co2 -FROM analysis_view; +```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/routes/api.analysis.ts b/app/routes/api.analysis.ts deleted file mode 100644 index 162dcdb0..00000000 --- a/app/routes/api.analysis.ts +++ /dev/null @@ -1,140 +0,0 @@ -import { type LoaderFunctionArgs } from "react-router"; -import { drizzleClient } from "~/db.server"; -import { sql } from "drizzle-orm"; - -export async function loader({ request }: LoaderFunctionArgs) { - try { - const url = new URL(request.url); - const limitParam = url.searchParams.get("limit"); - const offsetParam = url.searchParams.get("offset"); - const boxIdParam = url.searchParams.get("boxId"); - const hasGeometryParam = url.searchParams.get("hasGeometry"); - const markAsReadParam = url.searchParams.get("markAsRead"); - - const limit = limitParam ? Math.min(parseInt(limitParam, 10), 1000) : 100; - const offset = offsetParam ? parseInt(offsetParam, 10) : 0; - const hasGeometry = hasGeometryParam?.toLowerCase() === "true"; - const markAsRead = markAsReadParam?.toLowerCase() === "true"; - - let query = sql` - SELECT - "createdAt", - "boxId", - tags, - CASE - WHEN geometry IS NOT NULL - THEN ST_AsGeoJSON(geometry)::jsonb - ELSE NULL - END as geometry, - temperature, - soil_temperature, - humidity, - soil_moisture, - pressure, - pm1, - pm2_5, - pm4, - pm10, - wind_speed, - light_intensity, - uv_intensity, - uv_index, - sound_level, - sound_level_eq, - sound_level_min, - sound_level_max, - voc, - co2 - FROM analysis_view - WHERE 1=1 - `; - - if (boxIdParam) { - query = sql`${query} AND "boxId" = ${boxIdParam}`; - } - - if (hasGeometry) { - query = sql`${query} AND geometry IS NOT NULL`; - } - - query = sql`${query} ORDER BY "createdAt" DESC LIMIT ${limit} OFFSET ${offset}`; - - const results = await drizzleClient.execute>(query); - - // Get total count for pagination - let countQuery = sql`SELECT COUNT(*) as total FROM analysis_view WHERE 1=1`; - if (boxIdParam) { - countQuery = sql`${countQuery} AND "boxId" = ${boxIdParam}`; - } - if (hasGeometry) { - countQuery = sql`${countQuery} AND geometry IS NOT NULL`; - } - const [countResult] = await drizzleClient.execute(countQuery); - const total = Number(countResult.total); - - // If markAsRead is true, mark the returned items as processed - if (markAsRead && results.length > 0) { - // Mark each returned item as processed - // Using individual inserts with ON CONFLICT for reliability - for (const row of results) { - // Convert createdAt to ISO string format for PostgreSQL - const createdAt = row.createdAt instanceof Date - ? row.createdAt.toISOString() - : typeof row.createdAt === 'string' - ? row.createdAt - : new Date(row.createdAt).toISOString(); - - await drizzleClient.execute( - sql` - INSERT INTO processed_measurements (device_id, time, processed_at) - VALUES (${row.boxId}, ${createdAt}::timestamptz, NOW()) - ON CONFLICT (device_id, time) DO NOTHING - ` - ); - } - - // Refresh the materialized view to exclude processed measurements - // Use CONCURRENTLY to avoid locking (requires unique index) - await drizzleClient.execute( - sql`REFRESH MATERIALIZED VIEW CONCURRENTLY analysis_view` - ); - } - - return Response.json( - { - data: results, - pagination: { - limit, - offset, - total, - hasMore: offset + limit < total, - }, - markedAsRead: markAsRead ? results.length : 0, - }, - { - status: 200, - headers: { - "Content-Type": "application/json; charset=utf-8", - }, - }, - ); - } catch (e) { - console.error("Error in /api/analysis:", e); - const errorMessage = e instanceof Error ? e.message : String(e); - return Response.json( - { - error: "Internal Server Error", - message: - "The server was unable to complete your request. Please try again later.", - details: process.env.NODE_ENV === "development" ? errorMessage : undefined, - }, - { - status: 500, - headers: { - "Content-Type": "application/json; charset=utf-8", - }, - }, - ); - } -} - diff --git a/app/routes/api.measurements.ts b/app/routes/api.measurements.ts deleted file mode 100644 index f5f390ef..00000000 --- a/app/routes/api.measurements.ts +++ /dev/null @@ -1,120 +0,0 @@ -import { type ActionFunctionArgs } from "react-router"; -import { drizzleClient } from "~/db.server"; -import { measurement, type Measurement } from "~/schema"; -import { sql } from "drizzle-orm"; - -/** - * @openapi - * /api/measurements: - * post: - * tags: - * - Measurements - * summary: Create new measurements - * description: Accepts an array of measurement data and stores it in the database - * requestBody: - * required: true - * content: - * application/json: - * schema: - * type: array - * items: - * $ref: '#/components/schemas/Measurement' - * example: - * - sensorId: "sensor-123" - * time: "2023-05-15T10:00:00Z" - * value: 25.4 - * - sensorId: "sensor-456" - * time: "2023-05-15T10:01:00Z" - * value: 22.1 - * responses: - * 200: - * description: Measurements successfully stored - * content: - * application/json: - * schema: - * type: object - * properties: - * message: - * type: string - * example: "Measurements successfully stored" - * 400: - * description: Invalid data format - * content: - * application/json: - * schema: - * type: object - * properties: - * message: - * type: string - * example: "Invalid data format" - * 405: - * description: Method not allowed - * content: - * application/json: - * schema: - * type: object - * properties: - * message: - * type: string - * example: "Method not allowed" - * - * components: - * schemas: - * Measurement: - * type: object - * required: - * - sensorId - * - time - * - value - * properties: - * sensorId: - * type: string - * description: Unique identifier for the sensor - * example: "sensor-123" - * time: - * type: string - * format: date-time - * description: Timestamp of the measurement - * example: "2023-05-15T10:00:00Z" - * value: - * type: number - * format: float - * description: Measured value - * example: 25.4 - */ -export const action = async ({ request }: ActionFunctionArgs) => { - if (request.method !== "POST") { - return Response.json({ message: "Method not allowed" }, { status: 405 }); - } - - try { - const payload: Measurement[] = await request.json(); - - const measurements = payload.map((data) => ({ - sensorId: data.sensorId, - time: new Date(data.time), - value: Number(data.value), - })); - - await drizzleClient.insert(measurement).values(measurements); - - // Refresh the materialized view to include new measurements - // Use CONCURRENTLY to avoid locking (requires unique index) - try { - await drizzleClient.execute( - sql`REFRESH MATERIALIZED VIEW CONCURRENTLY analysis_view` - ); - } catch (refreshError) { - // If concurrent refresh fails (e.g., no unique index), fall back to regular refresh - console.warn("Concurrent refresh failed, using regular refresh:", refreshError); - await drizzleClient.execute( - sql`REFRESH MATERIALIZED VIEW analysis_view` - ); - } - - return Response.json({ message: "Measurements successfully stored" }); - - } catch (error) { - return Response.json({ message: error }, { status: 400 }); - } -}; \ No newline at end of file diff --git a/drizzle/0023_create_analysis_view.sql b/drizzle/0023_create_analysis_view.sql index da0fba6b..83d0be2a 100644 --- a/drizzle/0023_create_analysis_view.sql +++ b/drizzle/0023_create_analysis_view.sql @@ -18,7 +18,7 @@ CREATE INDEX IF NOT EXISTS idx_processed_measurements_device_time -- - `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 `/api/analysis` and Martin tiles +-- 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. From a2019509cb28e0abc23808327c7d17ae7440aa45 Mon Sep 17 00:00:00 2001 From: Maria Zadnepryanets Date: Mon, 17 Nov 2025 14:34:58 +0100 Subject: [PATCH 08/12] fix: return api.measurements.ts deleted by mistake --- app/routes/api.measurements.ts | 106 +++++++++++++++++++++++++++++++++ 1 file changed, 106 insertions(+) create mode 100644 app/routes/api.measurements.ts diff --git a/app/routes/api.measurements.ts b/app/routes/api.measurements.ts new file mode 100644 index 00000000..b5c8dec2 --- /dev/null +++ b/app/routes/api.measurements.ts @@ -0,0 +1,106 @@ +import { type ActionFunctionArgs } from "react-router"; +import { drizzleClient } from "~/db.server"; +import { measurement, type Measurement } from "~/schema"; + +/** + * @openapi + * /api/measurements: + * post: + * tags: + * - Measurements + * summary: Create new measurements + * description: Accepts an array of measurement data and stores it in the database + * requestBody: + * required: true + * content: + * application/json: + * schema: + * type: array + * items: + * $ref: '#/components/schemas/Measurement' + * example: + * - sensorId: "sensor-123" + * time: "2023-05-15T10:00:00Z" + * value: 25.4 + * - sensorId: "sensor-456" + * time: "2023-05-15T10:01:00Z" + * value: 22.1 + * responses: + * 200: + * description: Measurements successfully stored + * content: + * application/json: + * schema: + * type: object + * properties: + * message: + * type: string + * example: "Measurements successfully stored" + * 400: + * description: Invalid data format + * content: + * application/json: + * schema: + * type: object + * properties: + * message: + * type: string + * example: "Invalid data format" + * 405: + * description: Method not allowed + * content: + * application/json: + * schema: + * type: object + * properties: + * message: + * type: string + * example: "Method not allowed" + * + * components: + * schemas: + * Measurement: + * type: object + * required: + * - sensorId + * - time + * - value + * properties: + * sensorId: + * type: string + * description: Unique identifier for the sensor + * example: "sensor-123" + * time: + * type: string + * format: date-time + * description: Timestamp of the measurement + * example: "2023-05-15T10:00:00Z" + * value: + * type: number + * format: float + * description: Measured value + * example: 25.4 + */ +export const action = async ({ request }: ActionFunctionArgs) => { + if (request.method !== "POST") { + return Response.json({ message: "Method not allowed" }, { status: 405 }); + } + + try { + const payload: Measurement[] = await request.json(); + + const measurements = payload.map((data) => ({ + sensorId: data.sensorId, + time: new Date(data.time), + value: Number(data.value), + })); + + await drizzleClient.insert(measurement).values(measurements); + + return Response.json({ message: "Measurements successfully stored" }); + + } catch (error) { + return Response.json({ message: error }, { status: 400 }); + } +}; + From 2a7ceb5a1cceeecb22ee0c6f5030ec1e5d25bee0 Mon Sep 17 00:00:00 2001 From: Maria Zadnepryanets Date: Mon, 17 Nov 2025 14:35:11 +0100 Subject: [PATCH 09/12] doc: highlight that it's a local setup --- MARTIN_SETUP.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/MARTIN_SETUP.md b/MARTIN_SETUP.md index 78408a2c..3bcab7e5 100644 --- a/MARTIN_SETUP.md +++ b/MARTIN_SETUP.md @@ -6,7 +6,7 @@ Martin tile server serves vector tiles from PostGIS database views. Martin automatically discovers tables and views with geometry columns (SRID 4326) and serves them as Mapbox Vector Tiles. -## Setup +## Local Setup ### 1. Docker Configuration From 63db8aa59f4d95754ead98835084f5508f714f3b Mon Sep 17 00:00:00 2001 From: Maria Zadnepryanets Date: Mon, 17 Nov 2025 14:36:18 +0100 Subject: [PATCH 10/12] fix: remove last line from api.measurements.ts --- app/routes/api.measurements.ts | 1 - 1 file changed, 1 deletion(-) diff --git a/app/routes/api.measurements.ts b/app/routes/api.measurements.ts index b5c8dec2..d579908f 100644 --- a/app/routes/api.measurements.ts +++ b/app/routes/api.measurements.ts @@ -103,4 +103,3 @@ export const action = async ({ request }: ActionFunctionArgs) => { return Response.json({ message: error }, { status: 400 }); } }; - From 9d81dc4edcf8c0c9c50a38cc84afac69b741d31f Mon Sep 17 00:00:00 2001 From: Maria Zadnepryanets Date: Mon, 17 Nov 2025 14:37:18 +0100 Subject: [PATCH 11/12] fix: one more --- app/routes/api.measurements.ts | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/app/routes/api.measurements.ts b/app/routes/api.measurements.ts index d579908f..a8f9e825 100644 --- a/app/routes/api.measurements.ts +++ b/app/routes/api.measurements.ts @@ -102,4 +102,4 @@ export const action = async ({ request }: ActionFunctionArgs) => { } catch (error) { return Response.json({ message: error }, { status: 400 }); } -}; +}; \ No newline at end of file From 3fffcf07b4a65e9dd4c64819763643b5a931d95c Mon Sep 17 00:00:00 2001 From: Maria Zadnepryanets Date: Mon, 17 Nov 2025 14:52:37 +0100 Subject: [PATCH 12/12] feat: convert analysis_view to regular view to allow automatic refresh when new data arrives --- drizzle/0023_create_analysis_view.sql | 23 ++++------------------- 1 file changed, 4 insertions(+), 19 deletions(-) diff --git a/drizzle/0023_create_analysis_view.sql b/drizzle/0023_create_analysis_view.sql index 83d0be2a..cb58ffa8 100644 --- a/drizzle/0023_create_analysis_view.sql +++ b/drizzle/0023_create_analysis_view.sql @@ -10,8 +10,9 @@ CREATE TABLE IF NOT EXISTS processed_measurements ( CREATE INDEX IF NOT EXISTS idx_processed_measurements_device_time ON processed_measurements(device_id, time); --- Create a materialized view that flattens measurements with device, location, and sensor data +-- 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 @@ -25,7 +26,7 @@ CREATE INDEX IF NOT EXISTS idx_processed_measurements_device_time -- 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 MATERIALIZED VIEW analysis_view AS +CREATE VIEW analysis_view AS WITH sensor_measurements AS ( SELECT m.time, @@ -189,23 +190,7 @@ LEFT JOIN processed_measurements pm WHERE pm.device_id IS NULL; -- Only include unprocessed measurements -- Add comment to help identify this view -COMMENT ON MATERIALIZED VIEW analysis_view IS 'Denormalized materialized 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.'; - --- Create unique index on materialized view for concurrent refresh -CREATE UNIQUE INDEX IF NOT EXISTS analysis_view_created_at_boxid_unique - ON analysis_view("createdAt", "boxId"); - --- Create indexes on the materialized view for better query performance -CREATE INDEX IF NOT EXISTS idx_analysis_view_created_at - ON analysis_view("createdAt" DESC); -CREATE INDEX IF NOT EXISTS idx_analysis_view_boxid - ON analysis_view("boxId"); -CREATE INDEX IF NOT EXISTS idx_analysis_view_geometry - ON analysis_view USING GIST(geometry) - WHERE geometry IS NOT NULL; - --- Initial population of the materialized view -REFRESH MATERIALIZED VIEW analysis_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);