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.
103 lines
3.5 KiB
PL/PgSQL
103 lines
3.5 KiB
PL/PgSQL
-- 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
|
|
DO
|
|
$$
|
|
BEGIN
|
|
DROP TABLE IF EXISTS osm_ocean_polygon_gen1 CASCADE;
|
|
EXCEPTION
|
|
WHEN wrong_object_type THEN
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- etldoc: osm_ocean_polygon_union -> osm_ocean_polygon_gen1
|
|
DROP MATERIALIZED VIEW IF EXISTS osm_ocean_polygon_gen1 CASCADE;
|
|
CREATE MATERIALIZED VIEW osm_ocean_polygon_gen1 AS
|
|
(
|
|
SELECT ST_Simplify(geometry, 20) AS geometry
|
|
FROM osm_ocean_polygon_union
|
|
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
|
CREATE INDEX IF NOT EXISTS osm_ocean_polygon_gen1_idx ON osm_ocean_polygon_gen1 USING gist (geometry);
|
|
|
|
|
|
-- This statement can be deleted after the water importer image stops creating this object as a table
|
|
DO
|
|
$$
|
|
BEGIN
|
|
DROP TABLE IF EXISTS osm_ocean_polygon_gen2 CASCADE;
|
|
EXCEPTION
|
|
WHEN wrong_object_type THEN
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- etldoc: osm_ocean_polygon_union -> osm_ocean_polygon_gen2
|
|
DROP MATERIALIZED VIEW IF EXISTS osm_ocean_polygon_gen2 CASCADE;
|
|
CREATE MATERIALIZED VIEW osm_ocean_polygon_gen2 AS
|
|
(
|
|
SELECT ST_Simplify(geometry, 40) AS geometry
|
|
FROM osm_ocean_polygon_union
|
|
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
|
CREATE INDEX IF NOT EXISTS osm_ocean_polygon_gen2_idx ON osm_ocean_polygon_gen2 USING gist (geometry);
|
|
|
|
|
|
-- This statement can be deleted after the water importer image stops creating this object as a table
|
|
DO
|
|
$$
|
|
BEGIN
|
|
DROP TABLE IF EXISTS osm_ocean_polygon_gen3 CASCADE;
|
|
EXCEPTION
|
|
WHEN wrong_object_type THEN
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- etldoc: osm_ocean_polygon_union -> osm_ocean_polygon_gen3
|
|
DROP MATERIALIZED VIEW IF EXISTS osm_ocean_polygon_gen3 CASCADE;
|
|
CREATE MATERIALIZED VIEW osm_ocean_polygon_gen3 AS
|
|
(
|
|
SELECT ST_Simplify(geometry, 80) AS geometry
|
|
FROM osm_ocean_polygon_union
|
|
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
|
CREATE INDEX IF NOT EXISTS osm_ocean_polygon_gen3_idx ON osm_ocean_polygon_gen3 USING gist (geometry);
|
|
|
|
|
|
-- This statement can be deleted after the water importer image stops creating this object as a table
|
|
DO
|
|
$$
|
|
BEGIN
|
|
DROP TABLE IF EXISTS osm_ocean_polygon_gen4 CASCADE;
|
|
EXCEPTION
|
|
WHEN wrong_object_type THEN
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- etldoc: osm_ocean_polygon_union -> osm_ocean_polygon_gen4
|
|
DROP MATERIALIZED VIEW IF EXISTS osm_ocean_polygon_gen4 CASCADE;
|
|
CREATE MATERIALIZED VIEW osm_ocean_polygon_gen4 AS
|
|
(
|
|
SELECT ST_Simplify(geometry, 160) AS geometry
|
|
FROM osm_ocean_polygon_union
|
|
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
|
CREATE INDEX IF NOT EXISTS osm_ocean_polygon_gen4_idx ON osm_ocean_polygon_gen4 USING gist (geometry);
|