union ocean regular squares into complex polygon (#1021)

The ocean layer (table osm_ocean_polygon insert by `make import-data`) is made from squares that have a 10m buffer. 

This creates extra geometry in vector tiles as:

Union of full ocean squares should decrease the size of the water layer.

there are 8042 polygons (squares, 5 points, more then 100km<sup>2</sup>), which was reduced to 22 polygons - 1184kB vs 40kB respectively. 

In mbtiles should be the size reduction even more significant, due to the creation of more polygons based on a 10m buffer of each square.
This commit is contained in:
Tomas Pohanka 2020-10-14 13:56:04 +02:00 committed by GitHub
parent 72165933be
commit b7429ce6f5
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
3 changed files with 38 additions and 14 deletions

Binary file not shown.

Before

Width:  |  Height:  |  Size: 298 KiB

After

Width:  |  Height:  |  Size: 323 KiB

View File

@ -1,3 +1,27 @@
-- Recreate ocean layer by union regular squares into larger polygons
-- etldoc: osm_ocean_polygon -> osm_ocean_polygon_union
CREATE TABLE IF NOT EXISTS osm_ocean_polygon_union AS
(
SELECT (ST_Dump(ST_Union(ST_MakeValid(geometry)))).geom::geometry(Polygon, 3857) AS geometry
FROM osm_ocean_polygon
--for union select just full square (not big triangles)
WHERE ST_Area(geometry) > 100000000 AND
ST_NPoints(geometry) = 5
UNION ALL
SELECT geometry
FROM osm_ocean_polygon
-- as 321 records have less then 5 coordinates (triangle)
-- bigger then 5 coordinates have squares with holes from island and coastline
WHERE ST_NPoints(geometry) <> 5
);
CREATE INDEX IF NOT EXISTS osm_ocean_polygon_union_geom_idx
ON osm_ocean_polygon_union
USING GIST (geometry);
--Drop data from original table but keep table as `CREATE TABLE IF NOT EXISTS` still test if query is valid
TRUNCATE TABLE osm_ocean_polygon;
-- This statement can be deleted after the water importer image stops creating this object as a table -- This statement can be deleted after the water importer image stops creating this object as a table
DO DO
$$ $$
@ -8,12 +32,12 @@ $$
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
-- etldoc: osm_ocean_polygon -> osm_ocean_polygon_gen1 -- etldoc: osm_ocean_polygon_union -> osm_ocean_polygon_gen1
DROP MATERIALIZED VIEW IF EXISTS osm_ocean_polygon_gen1 CASCADE; DROP MATERIALIZED VIEW IF EXISTS osm_ocean_polygon_gen1 CASCADE;
CREATE MATERIALIZED VIEW osm_ocean_polygon_gen1 AS CREATE MATERIALIZED VIEW osm_ocean_polygon_gen1 AS
( (
SELECT ST_Simplify(geometry, 20) AS geometry SELECT ST_Simplify(geometry, 20) AS geometry
FROM osm_ocean_polygon FROM osm_ocean_polygon_union
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ; ) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_ocean_polygon_gen1_idx ON osm_ocean_polygon_gen1 USING gist (geometry); CREATE INDEX IF NOT EXISTS osm_ocean_polygon_gen1_idx ON osm_ocean_polygon_gen1 USING gist (geometry);
@ -28,12 +52,12 @@ $$
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
-- etldoc: osm_ocean_polygon -> osm_ocean_polygon_gen2 -- etldoc: osm_ocean_polygon_union -> osm_ocean_polygon_gen2
DROP MATERIALIZED VIEW IF EXISTS osm_ocean_polygon_gen2 CASCADE; DROP MATERIALIZED VIEW IF EXISTS osm_ocean_polygon_gen2 CASCADE;
CREATE MATERIALIZED VIEW osm_ocean_polygon_gen2 AS CREATE MATERIALIZED VIEW osm_ocean_polygon_gen2 AS
( (
SELECT ST_Simplify(geometry, 40) AS geometry SELECT ST_Simplify(geometry, 40) AS geometry
FROM osm_ocean_polygon FROM osm_ocean_polygon_union
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ; ) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_ocean_polygon_gen2_idx ON osm_ocean_polygon_gen2 USING gist (geometry); CREATE INDEX IF NOT EXISTS osm_ocean_polygon_gen2_idx ON osm_ocean_polygon_gen2 USING gist (geometry);
@ -48,12 +72,12 @@ $$
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
-- etldoc: osm_ocean_polygon -> osm_ocean_polygon_gen3 -- etldoc: osm_ocean_polygon_union -> osm_ocean_polygon_gen3
DROP MATERIALIZED VIEW IF EXISTS osm_ocean_polygon_gen3 CASCADE; DROP MATERIALIZED VIEW IF EXISTS osm_ocean_polygon_gen3 CASCADE;
CREATE MATERIALIZED VIEW osm_ocean_polygon_gen3 AS CREATE MATERIALIZED VIEW osm_ocean_polygon_gen3 AS
( (
SELECT ST_Simplify(geometry, 80) AS geometry SELECT ST_Simplify(geometry, 80) AS geometry
FROM osm_ocean_polygon FROM osm_ocean_polygon_union
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ; ) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_ocean_polygon_gen3_idx ON osm_ocean_polygon_gen3 USING gist (geometry); CREATE INDEX IF NOT EXISTS osm_ocean_polygon_gen3_idx ON osm_ocean_polygon_gen3 USING gist (geometry);
@ -68,11 +92,11 @@ $$
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
-- etldoc: osm_ocean_polygon -> osm_ocean_polygon_gen4 -- etldoc: osm_ocean_polygon_union -> osm_ocean_polygon_gen4
DROP MATERIALIZED VIEW IF EXISTS osm_ocean_polygon_gen4 CASCADE; DROP MATERIALIZED VIEW IF EXISTS osm_ocean_polygon_gen4 CASCADE;
CREATE MATERIALIZED VIEW osm_ocean_polygon_gen4 AS CREATE MATERIALIZED VIEW osm_ocean_polygon_gen4 AS
( (
SELECT ST_Simplify(geometry, 160) AS geometry SELECT ST_Simplify(geometry, 160) AS geometry
FROM osm_ocean_polygon FROM osm_ocean_polygon_union
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ; ) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_ocean_polygon_gen4_idx ON osm_ocean_polygon_gen4 USING gist (geometry); CREATE INDEX IF NOT EXISTS osm_ocean_polygon_gen4_idx ON osm_ocean_polygon_gen4 USING gist (geometry);

View File

@ -237,13 +237,13 @@ WHERE "natural" != 'bay'
CREATE OR REPLACE VIEW water_z12 AS CREATE OR REPLACE VIEW water_z12 AS
( (
-- etldoc: osm_ocean_polygon_gen1 -> water_z12 -- etldoc: osm_ocean_polygon_union -> water_z12
SELECT geometry, SELECT geometry,
'ocean'::text AS class, 'ocean'::text AS class,
NULL::boolean AS is_intermittent, NULL::boolean AS is_intermittent,
NULL::boolean AS is_bridge, NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel NULL::boolean AS is_tunnel
FROM osm_ocean_polygon FROM osm_ocean_polygon_union
UNION ALL UNION ALL
-- etldoc: osm_water_polygon -> water_z12 -- etldoc: osm_water_polygon -> water_z12
SELECT geometry, SELECT geometry,
@ -257,13 +257,13 @@ WHERE "natural" != 'bay'
CREATE OR REPLACE VIEW water_z13 AS CREATE OR REPLACE VIEW water_z13 AS
( (
-- etldoc: osm_ocean_polygon -> water_z13 -- etldoc: osm_ocean_polygon_union -> water_z13
SELECT geometry, SELECT geometry,
'ocean'::text AS class, 'ocean'::text AS class,
NULL::boolean AS is_intermittent, NULL::boolean AS is_intermittent,
NULL::boolean AS is_bridge, NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel NULL::boolean AS is_tunnel
FROM osm_ocean_polygon FROM osm_ocean_polygon_union
UNION ALL UNION ALL
-- etldoc: osm_water_polygon -> water_z13 -- etldoc: osm_water_polygon -> water_z13
SELECT geometry, SELECT geometry,
@ -277,13 +277,13 @@ WHERE "natural" != 'bay'
CREATE OR REPLACE VIEW water_z14 AS CREATE OR REPLACE VIEW water_z14 AS
( (
-- etldoc: osm_ocean_polygon -> water_z14 -- etldoc: osm_ocean_polygon_union -> water_z14
SELECT geometry, SELECT geometry,
'ocean'::text AS class, 'ocean'::text AS class,
NULL::boolean AS is_intermittent, NULL::boolean AS is_intermittent,
NULL::boolean AS is_bridge, NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel NULL::boolean AS is_tunnel
FROM osm_ocean_polygon FROM osm_ocean_polygon_union
UNION ALL UNION ALL
-- etldoc: osm_water_polygon -> water_z14 -- etldoc: osm_water_polygon -> water_z14
SELECT geometry, SELECT geometry,