diff --git a/server/migrations/20240814012328_indoor-features.down.sql b/server/migrations/20240814012328_indoor-features.down.sql new file mode 100644 index 000000000..df1809afa --- /dev/null +++ b/server/migrations/20240814012328_indoor-features.down.sql @@ -0,0 +1,3 @@ +-- Add down migration script here + +drop materialized view if exists indoor_features cascade; diff --git a/server/migrations/20240814012328_indoor-features.up.sql b/server/migrations/20240814012328_indoor-features.up.sql new file mode 100644 index 000000000..9b63e2eb3 --- /dev/null +++ b/server/migrations/20240814012328_indoor-features.up.sql @@ -0,0 +1,40 @@ +-- Add up migration script here +CREATE materialized VIEW indoor_features as +with geometry(gid, geom, tags) as (SELECT way_id as gid, geom, tags + from indoor_ways + union + DISTINCT + SELECT area_id as gid, geom, tags + from indoor_polygons + union + DISTINCT + SELECT node_id as gid, geom, tags + from indoor_nodes), + geometry_in_lat_lon(gid, geom, tags) as (SELECT gid, ST_Transform(geom, 4326), tags from geometry), + -- clustered to within about ~2m of non-overlapping distance + clustered_geometry(gid, group_id, geom, tags) + as (SELECT gid, + ST_ClusterWithinWin(geom, 0.00001) OVER () AS group_id, + geom, + tags + from geometry_in_lat_lon), + clustered_features(group_id, features) AS (SELECT group_id, + jsonb_build_object( + 'type', 'Feature', + 'id', gid, + 'geometry', ST_AsGeoJSON(geom)::jsonb, + 'properties', tags + ), + geom + from clustered_geometry), + grouped_features(group_id, features, convex_hull) as (SELECT group_id, + jsonb_agg(features), + ST_ConvexHull(ST_Collect(array_agg(geom)))::geometry + from clustered_features + group by group_id + order by group_id) +SELECT group_id, features, convex_hull +from grouped_features; + +CREATE index indoor_features_hull_idx ON indoor_features USING GIST (convex_hull); +CREATE unique index indoor_features_group_idx ON indoor_features(group_id);