From d72009053144d503101edef05fc60ecdf2d80b15 Mon Sep 17 00:00:00 2001 From: Joaquim d'Souza Date: Thu, 5 Feb 2026 15:40:54 +0100 Subject: [PATCH] feat: add generated area.geom column for improved geocode perfomance --- migrations/1770299199726_area_geom.ts | 29 ++++++++++++++++++++++++++ src/server/repositories/Area.ts | 4 +++- src/server/services/database/schema.ts | 9 +++++--- 3 files changed, 38 insertions(+), 4 deletions(-) create mode 100644 migrations/1770299199726_area_geom.ts diff --git a/migrations/1770299199726_area_geom.ts b/migrations/1770299199726_area_geom.ts new file mode 100644 index 00000000..f19f5ef2 --- /dev/null +++ b/migrations/1770299199726_area_geom.ts @@ -0,0 +1,29 @@ +/* eslint-disable @typescript-eslint/no-explicit-any */ +import { type Kysely, sql } from "kysely"; + +/** + * Add a generated `area.geom` column that is the `geometry` version + * of the source `geography` column. At the time of writing, this column + * is only used for one query (repositories/Area.ts/findAreasByPoint), as + * it is *slightly* less accurate to use geometry columns when working with + * geographical data, so should be avoided. However, this function is the + * bottleneck when geocoding data records, and using geometry leads to a + * 10x speedup, so the accuracy/performance tradeoff works out. + */ + +export async function up(db: Kysely): Promise { + await sql` + ALTER TABLE area + ADD COLUMN geom geometry(MultiPolygon, 4326) NOT NULL + GENERATED ALWAYS AS (geography::geometry) STORED + `.execute(db); + + await sql`CREATE INDEX area_area_set_id_geom_gist ON area USING GIST (area_set_id, geom)`.execute( + db, + ); +} + +export async function down(db: Kysely): Promise { + await sql`ALTER TABLE area DROP COLUMN geom`.execute(db); + await sql`DROP INDEX IF EXISTS area_area_set_id_geom_gist`.execute(db); +} diff --git a/src/server/repositories/Area.ts b/src/server/repositories/Area.ts index 7f6bada0..2cfe2e69 100644 --- a/src/server/repositories/Area.ts +++ b/src/server/repositories/Area.ts @@ -73,6 +73,8 @@ const applyAreaWithPointsSelect = ( ]); }; +// Uses the generated `geom` column for 10x performance improvement, +// at the loss of some (potentially negligible) accuracy. export async function findAreasByPoint({ point, excludeAreaSetCode, @@ -93,7 +95,7 @@ export async function findAreasByPoint({ query = query.where("areaSet.code", "=", includeAreaSetCode); } return query - .where(sql`ST_Intersects(geography, ST_GeomFromGeoJson(${point}))`) + .where(sql`ST_Covers(geom, ST_GeomFromGeoJson(${point}))`) .select([ "area.id", "area.code", diff --git a/src/server/services/database/schema.ts b/src/server/services/database/schema.ts index b006af41..b340b4c5 100644 --- a/src/server/services/database/schema.ts +++ b/src/server/services/database/schema.ts @@ -4,7 +4,7 @@ * This file represents the complete database schema as defined by all migrations. * It includes all tables, columns, types, constraints, and relationships. * - * Last updated: 2026-01-15 + * Last updated: 2026-02-05 * Based on migrations up to: 1764611637231_map_view_inspector_config.ts */ @@ -39,6 +39,7 @@ export interface Area { name: string; // text, NOT NULL geography: unknown; // geography (PostGIS), NOT NULL areaSetId: number; // bigint, NOT NULL + geom: unknown; // geometry(MultiPolygon,4326), GENERATED ALWAYS AS ((geography)::geometry) STORED, NOT NULL // CONSTRAINTS: // - UNIQUE (code, areaSetId) @@ -46,6 +47,8 @@ export interface Area { // - areaSetId -> areaSet.id (CASCADE DELETE, CASCADE UPDATE) // INDEXES: // - area_geography_gist USING GIST (geography) + // - area_area_set_id_geography_gist USING GIST (area_set_id, geography) + // - area_area_set_id_geom_gist USING GIST (area_set_id, geom) } // ============================================================================ @@ -82,8 +85,8 @@ export interface Organisation { */ export interface OrganisationUser { id: number; // bigserial, NOT NULL - organisationId: string; // uuid, NOT NULL - userId: string; // uuid, NOT NULL + organisationId: string | null; // uuid, NULL + userId: string | null; // uuid, NULL // CONSTRAINTS: // - UNIQUE (organisationId, userId)