Skip to content

Commit

Permalink
build: geometrylog table geom type to jsonb, int id to uuid (#2063)
Browse files Browse the repository at this point in the history
* feat: update geom type to jsonb, int id to uuid in geometrylog table

* refactor: use gist index over gin for simple geom table

---------

Co-authored-by: spwoodcock <[email protected]>
  • Loading branch information
Sujanadh and spwoodcock authored Jan 9, 2025
1 parent 19a7eed commit 35939f1
Show file tree
Hide file tree
Showing 5 changed files with 70 additions and 7 deletions.
7 changes: 3 additions & 4 deletions src/backend/app/db/models.py
Original file line number Diff line number Diff line change
Expand Up @@ -1789,7 +1789,7 @@ async def create(
for key in model_dump.keys():
columns.append(key)
if key == "geom":
value_placeholders.append(f"ST_GeomFromGeoJSON(%({key})s)")
value_placeholders.append(f"%({key})s::jsonb")
# Must be string json for db input
model_dump[key] = json.dumps(model_dump[key])
else:
Expand All @@ -1802,8 +1802,7 @@ async def create(
VALUES
({", ".join(value_placeholders)})
RETURNING
*,
ST_AsGeoJSON(geom)::jsonb AS geom;
*
""",
model_dump,
)
Expand All @@ -1815,7 +1814,7 @@ async def delete(
cls,
db: Connection,
project_id: int,
id: int,
id: str,
) -> bool:
"""Delete a geometry."""
async with db.cursor() as cur:
Expand Down
2 changes: 1 addition & 1 deletion src/backend/app/projects/project_routes.py
Original file line number Diff line number Diff line change
Expand Up @@ -1303,7 +1303,7 @@ async def create_geom_log(

@router.delete("/{project_id}/geometries")
async def delete_geom_log(
geom_id: int,
geom_id: str,
project_user: Annotated[
ProjectUserDict, Depends(project_manager)
], # later change this to validator
Expand Down
27 changes: 27 additions & 0 deletions src/backend/migrations/003-jsonb-geom-geometry-log.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,27 @@
-- ## Migration to update geom column to jsonb type and int id to uuid.

-- Start a transaction

BEGIN;
-- drop existing indexes
DROP INDEX IF EXISTS idx_geometrylog;

-- Change the 'geom' column to jsonb type
ALTER TABLE geometrylog
ALTER COLUMN geom TYPE jsonb USING geom::jsonb;

-- Alter the 'id' column to UUID
-- set the default value using gen_random_uuid()
-- First, drop the default if it's currently not a UUID
ALTER TABLE geometrylog
ALTER COLUMN id DROP DEFAULT;

-- Change the column type to UUID and set the default value
ALTER TABLE geometrylog
ALTER COLUMN id TYPE UUID USING gen_random_uuid(),
ALTER COLUMN id SET DEFAULT gen_random_uuid();

CREATE INDEX IF NOT EXISTS idx_geom_gin ON geometrylog USING gist (geom);

-- Commit the transaction
COMMIT;
4 changes: 2 additions & 2 deletions src/backend/migrations/init/fmtm_base_schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -392,8 +392,8 @@ ALTER SEQUENCE public.submission_photos_id_seq
OWNED BY public.submission_photos.id;

CREATE TABLE geometrylog (
id SERIAL PRIMARY KEY,
geom GEOMETRY NOT NULL,
id uuid DEFAULT gen_random_uuid() PRIMARY KEY,
geom JSONB NOT NULL,
status geomstatus,
project_id int,
task_id int
Expand Down
37 changes: 37 additions & 0 deletions src/backend/migrations/revert/003-jsonb-geom-geometry-log.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,37 @@
-- Start a transaction
BEGIN;

-- Drop the newly created index if needed
DROP INDEX IF EXISTS idx_geom_gin;

-- Change the 'geom' column back to its original type (geometry)
-- Using ST_GeomFromGeoJSON() to convert jsonb (GeoJSON) back to geometry
ALTER TABLE geometrylog
ALTER COLUMN geom TYPE geometry USING ST_GEOMFROMGEOJSON(geom::text);

-- This step creates a new temporary 'id_int' column to store the integer IDs
ALTER TABLE geometrylog ADD COLUMN id_int INTEGER;

WITH numbered_rows AS (
SELECT
id,
ROW_NUMBER() OVER () AS new_id
FROM geometrylog
)

UPDATE geometrylog
SET id_int = numbered_rows.new_id
FROM numbered_rows
WHERE geometrylog.id = numbered_rows.id;

-- Now, drop the old UUID 'id' column
ALTER TABLE geometrylog DROP COLUMN id;

-- Rename the new 'id_int' column back to 'id'
ALTER TABLE geometrylog RENAME COLUMN id_int TO id;
ALTER TABLE geometrylog ADD PRIMARY KEY (id);

CREATE INDEX IF NOT EXISTS idx_geometrylog ON geometrylog USING gist (geom);

-- Commit the transaction
COMMIT;

0 comments on commit 35939f1

Please sign in to comment.