From 0cff3449b5f26ff20922f53da0509a1ab666bd65 Mon Sep 17 00:00:00 2001 From: Brian Sperlongano Date: Wed, 24 Nov 2021 05:17:29 -0500 Subject: [PATCH] Implement non-blocking refresh (#1308) This PR implements non-blocking updates in the park layer. The approach was to use the `REFRESH MATERIALIZED VIEW CONCURRENTLY` feature in postgres. In order to achieve this, a unique index was added on the z4 dissolved park area table. The `ST_Union` / `ST_Dump` sequence was changed to an explicit cluster DB scan (an equivalent operation) so that a unique osm ID could be generated from each dissolved polygon. Below is a screen shot from Idaho, USA showing that the dissolved z4 still works as expected. ![image](https://user-images.githubusercontent.com/3254090/142341513-588045f0-7757-4acd-99e5-a50bbe6b0682.png) --- layers/park/update_park_polygon.sql | 16 +++++++++++----- 1 file changed, 11 insertions(+), 5 deletions(-) diff --git a/layers/park/update_park_polygon.sql b/layers/park/update_park_polygon.sql index 9272760..6949269 100644 --- a/layers/park/update_park_polygon.sql +++ b/layers/park/update_park_polygon.sql @@ -23,11 +23,17 @@ ALTER TABLE osm_park_polygon_gen_z5 DROP MATERIALIZED VIEW IF EXISTS osm_park_polygon_dissolve_z4 CASCADE; CREATE MATERIALIZED VIEW osm_park_polygon_dissolve_z4 AS ( - SELECT - (ST_Dump( - ST_Union(geometry))).geom AS geometry - FROM osm_park_polygon_gen_z4 + SELECT min(osm_id) AS osm_id, + ST_Union(geometry) AS geometry + FROM ( + SELECT ST_ClusterDBSCAN(geometry, 0, 1) OVER() AS cluster, + osm_id, + geometry + FROM osm_park_polygon_gen_z4 + ) park_cluster + GROUP BY cluster ); +CREATE UNIQUE INDEX IF NOT EXISTS osm_park_polygon_dissolve_idx ON osm_park_polygon_dissolve_z4 (osm_id); DROP TRIGGER IF EXISTS update_row ON osm_park_polygon; DROP TRIGGER IF EXISTS update_row ON osm_park_polygon_gen_z13; @@ -95,7 +101,7 @@ BEGIN SET tags = update_tags(tags, geometry), geometry_point = st_centroid(geometry); - REFRESH MATERIALIZED VIEW osm_park_polygon_dissolve_z4; + REFRESH MATERIALIZED VIEW CONCURRENTLY osm_park_polygon_dissolve_z4; END; $$ LANGUAGE plpgsql;