Skip to content

Commit

Permalink
try to run migration from introspection
Browse files Browse the repository at this point in the history
  • Loading branch information
TangoYankee committed Jul 8, 2024
1 parent e4a4110 commit f7226d1
Show file tree
Hide file tree
Showing 16 changed files with 219 additions and 226 deletions.
1 change: 1 addition & 0 deletions drizzle/api.config.ts
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,7 @@ export default {
schema: "./drizzle/schema/*",
dialect: "postgresql",
out: "./drizzle/migration",
extensionsFilters: ["postgis"],
dbCredentials: {
host: process.env.API_DATABASE_HOST!,
port: parseInt(process.env.API_DATABASE_PORT!),
Expand Down
41 changes: 41 additions & 0 deletions drizzle/drizzle-pgis/geography.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,41 @@
import { SimpleFeature } from "./types";
import { customType } from ".";
import {
Geometry,
GeometryCollection,
LineString,
MultiLineString,
MultiPoint,
MultiPolygon,
Point,
Polygon,
} from "geojson";

export const geography =
<T extends Geometry>(sf: SimpleFeature) =>
(name: string, srid = 4326) =>
customType<{ data: T }>({
dataType() {
return `geography(${sf}, ${srid})`;
},
})(name);

export const pointGeog = geography<Point>(SimpleFeature.POINT);

export const multiPointGeog = geography<MultiPoint>(SimpleFeature.MULTI_POINT);

export const lineStringGeog = geography<LineString>(SimpleFeature.LINE_STRING);

export const multiLineStringGeog = geography<MultiLineString>(
SimpleFeature.MULTI_LINE_STRING,
);

export const polygonGeog = geography<Polygon>(SimpleFeature.POLYGON);

export const multiPolygonGeog = geography<MultiPolygon>(
SimpleFeature.MULTI_POLYGON,
);

export const geometryCollectionGeog = geography<GeometryCollection>(
SimpleFeature.GEOMETRY_COLLECTION,
);
41 changes: 41 additions & 0 deletions drizzle/drizzle-pgis/geometry.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,41 @@
import { customType } from ".";
import {
Geometry,
Point,
LineString,
MultiLineString,
GeometryCollection,
MultiPolygon,
Polygon,
MultiPoint,
} from "geojson";
import { SimpleFeature } from "./types";

export const geometry =
<T extends Geometry>(sf: SimpleFeature) =>
(name: string, srid = 3857) =>
customType<{ data: T }>({
dataType() {
return `geometry(${sf},${srid})`;
},
})(name);

export const pointGeom = geometry<Point>(SimpleFeature.POINT);

export const multiPointGeom = geometry<MultiPoint>(SimpleFeature.MULTI_POINT);

export const lineStringGeom = geometry<LineString>(SimpleFeature.LINE_STRING);

export const multiLineStringGeom = geometry<MultiLineString>(
SimpleFeature.MULTI_LINE_STRING,
);

export const polygonGeom = geometry<Polygon>(SimpleFeature.POLYGON);

export const multiPolygonGeom = geometry<MultiPolygon>(
SimpleFeature.MULTI_POLYGON,
);

export const geometryCollectionGeom = geometry<GeometryCollection>(
SimpleFeature.GEOMETRY_COLLECTION,
);
25 changes: 25 additions & 0 deletions drizzle/drizzle-pgis/index.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
export { customType } from "drizzle-orm/pg-core";

export {
geometry,
pointGeom,
multiPointGeom,
lineStringGeom,
multiLineStringGeom,
polygonGeom,
multiPolygonGeom,
geometryCollectionGeom,
} from "./geometry";

export {
geography,
pointGeog,
multiPointGeog,
lineStringGeog,
multiLineStringGeog,
polygonGeog,
multiPolygonGeog,
geometryCollectionGeog,
} from "./geography";

export { ST_AsGeoJSON } from "./spatial-type";
24 changes: 24 additions & 0 deletions drizzle/drizzle-pgis/readme.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,24 @@
## Overview
Custom types for postgis

## Context for terms
Geometry has slightly different meanings between the broader mapping community and the specific PostGIS typing system. The geojson specification uses Geometry to refer to any coordinates, regardless of whether those coordinates model the Earth as an ellipsoid or a plane.

In contrast, PostGIS uses Geometry to refer specifically to coordinates that model the Earth as a plane. It uses Geography to refer specifically to coordinates that model the Earth as an ellipsoid.

## Guidelines for using the types
Within PostGIS, projected coordinate systems typically should be stored in Geometry columns. Conversely, geodetic coordinate systems should be stored in Geography columns.

Following this guidance, WGS84 (EPSG:4326) should be stored in a Geography column.
Its projected counterpart, Pseudo-Mercator (EPSG:3857), should be stored in a Geometry Column. This package encourages this convention by setting the default srid for geomtry types to 3857 and geography types to 4326.

## WGS84 is special
The Geometry type predates the Geography type in PostGIS. It also evolved with GeoJSON. GeoJSON uses WSG84 as the default spatial reference system for sharing coordinates. Consequently, the Geometry type historically supported WSG84 by applying [Plate Carée](https://en.wikipedia.org/wiki/Equirectangular_projection) projection.

Converting from GeoJSON to Geometry types is also easier, thanks to the `ST_GeomFromGeoJSON` PostGIS function. There exists no equivalent function for converting directly from GeoJSON to Geography. Fortunately, the same effect can be achieved by casting the geometry to a geography:
```
ST_GeomFromGeoJSON(geojson_feature)::geography
```

## WGS84 isn't special
Despite Geometry's historical support for WSG84, it is generally safer to move coordinates in this system to a Geography column. Spatial functions for Geometry types assume a flat surface for its calculations. PostGIS will not check whether the coordinates actually satisfy this assumption. Consequently, applying geometry functions to WGS84 coordinates will return meaningless results and PostGIS will fail to emit errors to flag these issues.
23 changes: 23 additions & 0 deletions drizzle/drizzle-pgis/spatial-type.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
import { PgColumn } from "drizzle-orm/pg-core";
import { Geometry } from "geojson";
import { sql } from "drizzle-orm";

/**
* https://postgis.net/docs/ST_AsGeoJSON.html
* @returns a geometry or geography as a GeoJSON "geometry"
*/
export const ST_AsGeoJSON = (
feature: PgColumn<{
name: string;
tableName: string;
dataType: "custom";
columnType: "PgCustomColumn";
data: Geometry;
driverParam: unknown;
notNull: false;
hasDefault: false;
enumValues: undefined;
baseColumn: never;
}>,
maxDecimalDigits = 9,
) => sql<string>`ST_AsGeoJSON(${feature}, ${maxDecimalDigits})`;
9 changes: 9 additions & 0 deletions drizzle/drizzle-pgis/types.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,9 @@
export enum SimpleFeature {
POINT = "point",
MULTI_POINT = "multiPoint",
LINE_STRING = "lineString",
MULTI_LINE_STRING = "multiLineString",
POLYGON = "polygon",
MULTI_POLYGON = "multiPolygon",
GEOMETRY_COLLECTION = "geometryCollection",
}
18 changes: 18 additions & 0 deletions drizzle/flow.config.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,18 @@
// Drizzle kit configuration
import type { Config } from "drizzle-kit";

export default {
schema: "./drizzle/migration/schema.ts",
dialect: "postgresql",
out: "./drizzle/migration",
dbCredentials: {
host: process.env.FLOW_DATABASE_HOST!,
port: parseInt(process.env.FLOW_DATABASE_PORT!),
user: process.env.FLOW_DATABASE_USER,
password: process.env.FLOW_DATABASE_PASSWORD,
database: process.env.FLOW_DATABASE_NAME!,
ssl: process.env.FLOW_DATABASE_ENV !== "development" && {
rejectUnauthorized: false,
},
},
} satisfies Config;
Original file line number Diff line number Diff line change
@@ -1,6 +1,5 @@
-- Current sql file was generated after introspecting the database
-- If you want to run this migration please uncomment this code before executing migrations
/*
DO $$ BEGIN
CREATE TYPE "public"."capital_fund_category" AS ENUM('city-non-exempt', 'city-exempt', 'city-cost', 'non-city-state', 'non-city-federal', 'non-city-other', 'non-city-cost', 'total');
EXCEPTION
Expand All @@ -25,34 +24,6 @@ EXCEPTION
WHEN duplicate_object THEN null;
END $$;
--> statement-breakpoint
CREATE TABLE IF NOT EXISTS "geography_columns" (
"f_table_catalog" "name",
"f_table_schema" "name",
"f_table_name" "name",
"f_geography_column" "name",
"coord_dimension" integer,
"srid" integer,
"type" text
);
--> statement-breakpoint
CREATE TABLE IF NOT EXISTS "geometry_columns" (
"f_table_catalog" varchar(256),
"f_table_schema" "name",
"f_table_name" "name",
"f_geometry_column" "name",
"coord_dimension" integer,
"srid" integer,
"type" varchar(30)
);
--> statement-breakpoint
CREATE TABLE IF NOT EXISTS "spatial_ref_sys" (
"srid" integer PRIMARY KEY NOT NULL,
"auth_name" varchar(256),
"auth_srid" integer,
"srtext" varchar(2048),
"proj4text" varchar(2048)
);
--> statement-breakpoint
CREATE TABLE IF NOT EXISTS "agency_budget" (
"code" text PRIMARY KEY NOT NULL,
"type" text,
Expand Down Expand Up @@ -119,7 +90,8 @@ CREATE TABLE IF NOT EXISTS "tax_lot" (
"lot" text NOT NULL,
"address" text,
"land_use_id" char(2),
"wgs84" "geography" NOT NULL,
-- Caution: hand updated
"wgs84" geography(MultiPolygon,4326) NOT NULL,
"li_ft" geometry(MultiPolygon,2263) NOT NULL
);
--> statement-breakpoint
Expand Down Expand Up @@ -152,7 +124,8 @@ CREATE TABLE IF NOT EXISTS "zoning_district_zoning_district_class" (
CREATE TABLE IF NOT EXISTS "zoning_district" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"label" text NOT NULL,
"wgs84" "geography" NOT NULL,
-- Caution: hand updated
"wgs84" geography(MultiPolygon,4326) NOT NULL,
"li_ft" geometry(MultiPolygon,2263) NOT NULL
);
--> statement-breakpoint
Expand Down Expand Up @@ -286,5 +259,4 @@ CREATE INDEX IF NOT EXISTS "community_district_mercator_label_index" ON "communi
CREATE INDEX IF NOT EXISTS "capital_project_li_ft_m_pnt_index" ON "capital_project" USING gist ("li_ft_m_pnt" gist_geometry_ops_2d);--> statement-breakpoint
CREATE INDEX IF NOT EXISTS "capital_project_li_ft_m_poly_index" ON "capital_project" USING gist ("li_ft_m_poly" gist_geometry_ops_2d);--> statement-breakpoint
CREATE INDEX IF NOT EXISTS "capital_project_mercator_fill_m_pnt_index" ON "capital_project" USING gist ("mercator_fill_m_pnt" gist_geometry_ops_2d);--> statement-breakpoint
CREATE INDEX IF NOT EXISTS "capital_project_mercator_fill_m_poly_index" ON "capital_project" USING gist ("mercator_fill_m_poly" gist_geometry_ops_2d);
*/
CREATE INDEX IF NOT EXISTS "capital_project_mercator_fill_m_poly_index" ON "capital_project" USING gist ("mercator_fill_m_poly" gist_geometry_ops_2d);
Loading

0 comments on commit f7226d1

Please sign in to comment.