Add OSM ID to the lakes (#1383)

This PR adding OSM ID to the lakes

OSM lakes are used from zoom 6
From zoom 0 to zoom 5 are used Natural Earth lakes. 
  - There is a new joining mat. view (`match_osm_ne_id`) contains which Natural Earth ID should convert to OSM ID. This logic is used to keep a consistent ID between switching between NE (zooms 0 - 5) and OSM (zooms 6 - 12). For smaller areas (not the whole planet), where are not available OSM lakes, the NE lakes keep their NE ID.
  - There are also switch the final views to the mat. views - this should slightly increase performance (get rid of multipolygons).
  - FIX typo for zooms 0 - 3 (`lakes` instead of `lake`).
This commit is contained in:
Tomas Pohanka 2022-05-05 14:26:57 +02:00 committed by GitHub
parent ef9a68b19a
commit 51751b5b78
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
2 changed files with 171 additions and 55 deletions

View File

@ -19,12 +19,71 @@ $$ LANGUAGE SQL IMMUTABLE
STRICT STRICT
PARALLEL SAFE; PARALLEL SAFE;
-- Add ne_id for missing ne_50m_lakes.
UPDATE ne_50m_lakes SET ne_id = ne_10m_lakes.ne_id
FROM ne_50m_lakes lakes
LEFT JOIN ne_10m_lakes USING (wikidataid)
WHERE ne_50m_lakes.wikidataid = ne_10m_lakes.wikidataid
AND ne_50m_lakes.ne_id = 0;
-- Update ne_110_lakes ne_id where two lakes (Lake Onega) have identical attributes.
-- New ne_id is taken from ne_50m_lakes
UPDATE ne_110m_lakes SET ne_id = 1159126421
WHERE ne_id = 1159113251
AND ST_Area(geometry) < 10000000000;
-- Get matching osm id for natural earth id.
DROP MATERIALIZED VIEW IF EXISTS match_osm_ne_id CASCADE;
CREATE MATERIALIZED VIEW match_osm_ne_id AS
(
WITH name_match AS
(
-- Distinct on keeps just the first occurence -> order by 'area_ratio DESC'.
SELECT DISTINCT ON (ne.ne_id)
ne.ne_id,
osm.osm_id,
(ST_Area(ST_Intersection(ne.geometry, osm.geometry))/ST_Area(ne.geometry)) AS area_ratio
FROM ne_10m_lakes ne, osm_water_polygon_gen_z6 osm
WHERE ne.name = osm.name
AND ST_Intersects(ne.geometry, osm.geometry)
ORDER BY ne_id,
area_ratio DESC
),
-- Add lakes which are not match by name, but intersects.
-- Duplicity solves 'DISTICT ON' with 'area_ratio'.
geom_match AS
(SELECT DISTINCT ON (ne.ne_id)
ne.ne_id,
osm.osm_id,
(ST_Area(ST_Intersection(ne.geometry, osm.geometry))/ST_Area(ne.geometry)) AS area_ratio
FROM ne_10m_lakes ne, osm_water_polygon_gen_z6 osm
WHERE ST_Intersects(ne.geometry, osm.geometry)
AND ne.ne_id NOT IN
( SELECT ne_id
FROM name_match
)
ORDER BY ne_id,
area_ratio DESC
)
SELECT ne_id,
osm_id
FROM name_match
UNION
SELECT ne_id,
osm_id
FROM geom_match
);
-- ne_10m_ocean -- ne_10m_ocean
-- etldoc: ne_10m_ocean -> ne_10m_ocean_gen_z5 -- etldoc: ne_10m_ocean -> ne_10m_ocean_gen_z5
DROP MATERIALIZED VIEW IF EXISTS ne_10m_ocean_gen_z5 CASCADE; DROP MATERIALIZED VIEW IF EXISTS ne_10m_ocean_gen_z5 CASCADE;
CREATE MATERIALIZED VIEW ne_10m_ocean_gen_z5 AS CREATE MATERIALIZED VIEW ne_10m_ocean_gen_z5 AS
( (
SELECT ST_Simplify(geometry, ZRes(7)) AS geometry, SELECT NULL::integer AS id,
(ST_Dump(ST_Simplify(geometry, ZRes(7)))).geom AS 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,
@ -38,13 +97,16 @@ CREATE INDEX IF NOT EXISTS ne_10m_ocean_gen_z5_idx ON ne_10m_ocean_gen_z5 USING
DROP MATERIALIZED VIEW IF EXISTS ne_10m_lakes_gen_z5 CASCADE; DROP MATERIALIZED VIEW IF EXISTS ne_10m_lakes_gen_z5 CASCADE;
CREATE MATERIALIZED VIEW ne_10m_lakes_gen_z5 AS CREATE MATERIALIZED VIEW ne_10m_lakes_gen_z5 AS
( (
SELECT ogc_fid, SELECT COALESCE(osm.osm_id, ne_id) AS id,
ST_MakeValid(ST_Simplify(geometry, ZRes(7))) AS geometry, -- Union fixing e.g. Lake Huron and Georgian Bay duplicity
(ST_Dump(ST_MakeValid(ST_Simplify(ST_Union(geometry), ZRes(7))))).geom AS geometry,
'lake'::text AS class, 'lake'::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 ne_10m_lakes FROM ne_10m_lakes
LEFT JOIN match_osm_ne_id osm USING (ne_id)
GROUP BY COALESCE(osm.osm_id, ne_id), is_intermittent, is_bridge, is_tunnel
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ; ) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_10m_lakes_gen_z5_idx ON ne_10m_lakes_gen_z5 USING gist (geometry); CREATE INDEX IF NOT EXISTS ne_10m_lakes_gen_z5_idx ON ne_10m_lakes_gen_z5 USING gist (geometry);
@ -52,8 +114,8 @@ CREATE INDEX IF NOT EXISTS ne_10m_lakes_gen_z5_idx ON ne_10m_lakes_gen_z5 USING
DROP MATERIALIZED VIEW IF EXISTS ne_10m_lakes_gen_z4 CASCADE; DROP MATERIALIZED VIEW IF EXISTS ne_10m_lakes_gen_z4 CASCADE;
CREATE MATERIALIZED VIEW ne_10m_lakes_gen_z4 AS CREATE MATERIALIZED VIEW ne_10m_lakes_gen_z4 AS
( (
SELECT ogc_fid, SELECT id,
ST_MakeValid(ST_Simplify(geometry, ZRes(6))) AS geometry, (ST_Dump(ST_MakeValid(ST_Simplify(geometry, ZRes(6))))).geom AS geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -67,7 +129,8 @@ CREATE INDEX IF NOT EXISTS ne_10m_lakes_gen_z4_idx ON ne_10m_lakes_gen_z4 USING
DROP MATERIALIZED VIEW IF EXISTS ne_50m_ocean_gen_z4 CASCADE; DROP MATERIALIZED VIEW IF EXISTS ne_50m_ocean_gen_z4 CASCADE;
CREATE MATERIALIZED VIEW ne_50m_ocean_gen_z4 AS CREATE MATERIALIZED VIEW ne_50m_ocean_gen_z4 AS
( (
SELECT ST_Simplify(geometry, ZRes(6)) AS geometry, SELECT NULL::integer AS id,
(ST_Dump(ST_Simplify(geometry, ZRes(6)))).geom AS 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,
@ -80,7 +143,8 @@ CREATE INDEX IF NOT EXISTS ne_50m_ocean_gen_z4_idx ON ne_50m_ocean_gen_z4 USING
DROP MATERIALIZED VIEW IF EXISTS ne_50m_ocean_gen_z3 CASCADE; DROP MATERIALIZED VIEW IF EXISTS ne_50m_ocean_gen_z3 CASCADE;
CREATE MATERIALIZED VIEW ne_50m_ocean_gen_z3 AS CREATE MATERIALIZED VIEW ne_50m_ocean_gen_z3 AS
( (
SELECT ST_Simplify(geometry, ZRes(5)) AS geometry, SELECT id,
ST_Simplify(geometry, ZRes(5)) AS geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -93,7 +157,8 @@ CREATE INDEX IF NOT EXISTS ne_50m_ocean_gen_z3_idx ON ne_50m_ocean_gen_z3 USING
DROP MATERIALIZED VIEW IF EXISTS ne_50m_ocean_gen_z2 CASCADE; DROP MATERIALIZED VIEW IF EXISTS ne_50m_ocean_gen_z2 CASCADE;
CREATE MATERIALIZED VIEW ne_50m_ocean_gen_z2 AS CREATE MATERIALIZED VIEW ne_50m_ocean_gen_z2 AS
( (
SELECT ST_Simplify(geometry, ZRes(4)) AS geometry, SELECT id,
ST_Simplify(geometry, ZRes(4)) AS geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -107,13 +172,14 @@ CREATE INDEX IF NOT EXISTS ne_50m_ocean_gen_z2_idx ON ne_50m_ocean_gen_z2 USING
DROP MATERIALIZED VIEW IF EXISTS ne_50m_lakes_gen_z3 CASCADE; DROP MATERIALIZED VIEW IF EXISTS ne_50m_lakes_gen_z3 CASCADE;
CREATE MATERIALIZED VIEW ne_50m_lakes_gen_z3 AS CREATE MATERIALIZED VIEW ne_50m_lakes_gen_z3 AS
( (
SELECT ogc_fid, SELECT COALESCE(osm.osm_id, ne_id) AS id,
ST_MakeValid(ST_Simplify(geometry, ZRes(5))) AS geometry, (ST_Dump(ST_MakeValid(ST_Simplify(geometry, ZRes(5))))).geom AS geometry,
'lakes'::text AS class, 'lake'::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 ne_50m_lakes FROM ne_50m_lakes
LEFT JOIN match_osm_ne_id osm USING (ne_id)
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ; ) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_50m_lakes_gen_z3_idx ON ne_50m_lakes_gen_z3 USING gist (geometry); CREATE INDEX IF NOT EXISTS ne_50m_lakes_gen_z3_idx ON ne_50m_lakes_gen_z3 USING gist (geometry);
@ -121,8 +187,8 @@ CREATE INDEX IF NOT EXISTS ne_50m_lakes_gen_z3_idx ON ne_50m_lakes_gen_z3 USING
DROP MATERIALIZED VIEW IF EXISTS ne_50m_lakes_gen_z2 CASCADE; DROP MATERIALIZED VIEW IF EXISTS ne_50m_lakes_gen_z2 CASCADE;
CREATE MATERIALIZED VIEW ne_50m_lakes_gen_z2 AS CREATE MATERIALIZED VIEW ne_50m_lakes_gen_z2 AS
( (
SELECT ogc_fid, SELECT id,
ST_MakeValid(ST_Simplify(geometry, ZRes(4))) AS geometry, (ST_Dump(ST_MakeValid(ST_Simplify(geometry, ZRes(4))))).geom AS geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -136,7 +202,8 @@ CREATE INDEX IF NOT EXISTS ne_50m_lakes_gen_z2_idx ON ne_50m_lakes_gen_z2 USING
DROP MATERIALIZED VIEW IF EXISTS ne_110m_ocean_gen_z1 CASCADE; DROP MATERIALIZED VIEW IF EXISTS ne_110m_ocean_gen_z1 CASCADE;
CREATE MATERIALIZED VIEW ne_110m_ocean_gen_z1 AS CREATE MATERIALIZED VIEW ne_110m_ocean_gen_z1 AS
( (
SELECT ST_Simplify(geometry, ZRes(3)) AS geometry, SELECT NULL::integer AS id,
ST_Simplify(geometry, ZRes(3)) AS 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,
@ -149,7 +216,8 @@ CREATE INDEX IF NOT EXISTS ne_110m_ocean_gen_z1_idx ON ne_110m_ocean_gen_z1 USIN
DROP MATERIALIZED VIEW IF EXISTS ne_110m_ocean_gen_z0 CASCADE; DROP MATERIALIZED VIEW IF EXISTS ne_110m_ocean_gen_z0 CASCADE;
CREATE MATERIALIZED VIEW ne_110m_ocean_gen_z0 AS CREATE MATERIALIZED VIEW ne_110m_ocean_gen_z0 AS
( (
SELECT ST_Simplify(geometry, ZRes(2)) AS geometry, SELECT id,
ST_Simplify(geometry, ZRes(2)) AS geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -164,13 +232,14 @@ CREATE INDEX IF NOT EXISTS ne_110m_ocean_gen_z0_idx ON ne_110m_ocean_gen_z0 USIN
DROP MATERIALIZED VIEW IF EXISTS ne_110m_lakes_gen_z1 CASCADE; DROP MATERIALIZED VIEW IF EXISTS ne_110m_lakes_gen_z1 CASCADE;
CREATE MATERIALIZED VIEW ne_110m_lakes_gen_z1 AS CREATE MATERIALIZED VIEW ne_110m_lakes_gen_z1 AS
( (
SELECT ogc_fid, SELECT COALESCE(osm.osm_id, ne_id) AS id,
ST_Simplify(geometry, ZRes(3)) AS geometry, (ST_Dump(ST_Simplify(geometry, ZRes(3)))).geom AS geometry,
'lakes'::text AS class, 'lake'::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 ne_110m_lakes FROM ne_110m_lakes
LEFT JOIN match_osm_ne_id osm USING (ne_id)
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ; ) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_110m_lakes_gen_z1_idx ON ne_110m_lakes_gen_z1 USING gist (geometry); CREATE INDEX IF NOT EXISTS ne_110m_lakes_gen_z1_idx ON ne_110m_lakes_gen_z1 USING gist (geometry);
@ -178,8 +247,8 @@ CREATE INDEX IF NOT EXISTS ne_110m_lakes_gen_z1_idx ON ne_110m_lakes_gen_z1 USIN
DROP MATERIALIZED VIEW IF EXISTS ne_110m_lakes_gen_z0 CASCADE; DROP MATERIALIZED VIEW IF EXISTS ne_110m_lakes_gen_z0 CASCADE;
CREATE MATERIALIZED VIEW ne_110m_lakes_gen_z0 AS CREATE MATERIALIZED VIEW ne_110m_lakes_gen_z0 AS
( (
SELECT ogc_fid, SELECT id,
ST_Simplify(geometry, ZRes(2)) AS geometry, (ST_Dump(ST_Simplify(geometry, ZRes(2)))).geom AS geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -188,11 +257,19 @@ FROM ne_110m_lakes_gen_z1
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ; ) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_110m_lakes_gen_z0_idx ON ne_110m_lakes_gen_z0 USING gist (geometry); CREATE INDEX IF NOT EXISTS ne_110m_lakes_gen_z0_idx ON ne_110m_lakes_gen_z0 USING gist (geometry);
DROP MATERIALIZED VIEW IF EXISTS water_z6;
DROP MATERIALIZED VIEW IF EXISTS water_z7;
DROP MATERIALIZED VIEW IF EXISTS water_z8;
DROP MATERIALIZED VIEW IF EXISTS water_z9;
DROP MATERIALIZED VIEW IF EXISTS water_z10;
DROP MATERIALIZED VIEW IF EXISTS water_z11;
DROP MATERIALIZED VIEW IF EXISTS water_z12;
CREATE OR REPLACE VIEW water_z0 AS CREATE OR REPLACE VIEW water_z0 AS
( (
-- etldoc: ne_110m_ocean_gen_z0 -> water_z0 -- etldoc: ne_110m_ocean_gen_z0 -> water_z0
SELECT geometry, SELECT id,
geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -200,7 +277,8 @@ SELECT geometry,
FROM ne_110m_ocean_gen_z0 FROM ne_110m_ocean_gen_z0
UNION ALL UNION ALL
-- etldoc: ne_110m_lakes_gen_z0 -> water_z0 -- etldoc: ne_110m_lakes_gen_z0 -> water_z0
SELECT geometry, SELECT id,
geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -211,7 +289,8 @@ FROM ne_110m_lakes_gen_z0
CREATE OR REPLACE VIEW water_z1 AS CREATE OR REPLACE VIEW water_z1 AS
( (
-- etldoc: ne_110m_ocean_gen_z1 -> water_z1 -- etldoc: ne_110m_ocean_gen_z1 -> water_z1
SELECT geometry, SELECT id,
geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -219,7 +298,8 @@ SELECT geometry,
FROM ne_110m_ocean_gen_z1 FROM ne_110m_ocean_gen_z1
UNION ALL UNION ALL
-- etldoc: ne_110m_lakes_gen_z1 -> water_z1 -- etldoc: ne_110m_lakes_gen_z1 -> water_z1
SELECT geometry, SELECT id,
geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -230,7 +310,8 @@ FROM ne_110m_lakes_gen_z1
CREATE OR REPLACE VIEW water_z2 AS CREATE OR REPLACE VIEW water_z2 AS
( (
-- etldoc: ne_50m_ocean_gen_z2 -> water_z2 -- etldoc: ne_50m_ocean_gen_z2 -> water_z2
SELECT geometry, SELECT id,
geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -238,7 +319,8 @@ SELECT geometry,
FROM ne_50m_ocean_gen_z2 FROM ne_50m_ocean_gen_z2
UNION ALL UNION ALL
-- etldoc: ne_50m_lakes_gen_z2 -> water_z2 -- etldoc: ne_50m_lakes_gen_z2 -> water_z2
SELECT geometry, SELECT id,
geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -249,7 +331,8 @@ FROM ne_50m_lakes_gen_z2
CREATE OR REPLACE VIEW water_z3 AS CREATE OR REPLACE VIEW water_z3 AS
( (
-- etldoc: ne_50m_ocean_gen_z3 -> water_z3 -- etldoc: ne_50m_ocean_gen_z3 -> water_z3
SELECT geometry, SELECT id,
geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -257,7 +340,8 @@ SELECT geometry,
FROM ne_50m_ocean_gen_z3 FROM ne_50m_ocean_gen_z3
UNION ALL UNION ALL
-- etldoc: ne_50m_lakes_gen_z3 -> water_z3 -- etldoc: ne_50m_lakes_gen_z3 -> water_z3
SELECT geometry, SELECT id,
geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -268,7 +352,8 @@ FROM ne_50m_lakes_gen_z3
CREATE OR REPLACE VIEW water_z4 AS CREATE OR REPLACE VIEW water_z4 AS
( (
-- etldoc: ne_50m_ocean_gen_z4 -> water_z4 -- etldoc: ne_50m_ocean_gen_z4 -> water_z4
SELECT geometry, SELECT id,
geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -276,7 +361,8 @@ SELECT geometry,
FROM ne_50m_ocean_gen_z4 FROM ne_50m_ocean_gen_z4
UNION ALL UNION ALL
-- etldoc: ne_10m_lakes_gen_z4 -> water_z4 -- etldoc: ne_10m_lakes_gen_z4 -> water_z4
SELECT geometry, SELECT id,
geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -284,10 +370,12 @@ SELECT geometry,
FROM ne_10m_lakes_gen_z4 FROM ne_10m_lakes_gen_z4
); );
CREATE OR REPLACE VIEW water_z5 AS CREATE OR REPLACE VIEW water_z5 AS
( (
-- etldoc: ne_10m_ocean_gen_z5 -> water_z5 -- etldoc: ne_10m_ocean_gen_z5 -> water_z5
SELECT geometry, SELECT id,
geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -295,7 +383,8 @@ SELECT geometry,
FROM ne_10m_ocean_gen_z5 FROM ne_10m_ocean_gen_z5
UNION ALL UNION ALL
-- etldoc: ne_10m_lakes_gen_z5 -> water_z5 -- etldoc: ne_10m_lakes_gen_z5 -> water_z5
SELECT geometry, SELECT id,
geometry,
class, class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -303,10 +392,11 @@ SELECT geometry,
FROM ne_10m_lakes_gen_z5 FROM ne_10m_lakes_gen_z5
); );
CREATE OR REPLACE VIEW water_z6 AS CREATE MATERIALIZED VIEW water_z6 AS
( (
-- etldoc: osm_ocean_polygon_gen_z6 -> water_z6 -- etldoc: osm_ocean_polygon_gen_z6 -> water_z6
SELECT geometry, SELECT NULL::integer AS id,
(ST_Dump(geometry)).geom AS 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,
@ -314,7 +404,8 @@ SELECT geometry,
FROM osm_ocean_polygon_gen_z6 FROM osm_ocean_polygon_gen_z6
UNION ALL UNION ALL
-- etldoc: osm_water_polygon_gen_z6 -> water_z6 -- etldoc: osm_water_polygon_gen_z6 -> water_z6
SELECT geometry, SELECT osm_id AS id,
(ST_Dump(geometry)).geom AS geometry,
water_class(waterway, water) AS class, water_class(waterway, water) AS class,
is_intermittent, is_intermittent,
NULL::boolean AS is_bridge, NULL::boolean AS is_bridge,
@ -322,11 +413,13 @@ SELECT geometry,
FROM osm_water_polygon_gen_z6 FROM osm_water_polygon_gen_z6
WHERE "natural" != 'bay' WHERE "natural" != 'bay'
); );
CREATE INDEX ON water_z6 USING gist(geometry);
CREATE OR REPLACE VIEW water_z7 AS CREATE MATERIALIZED VIEW water_z7 AS
( (
-- etldoc: osm_ocean_polygon_gen_z7 -> water_z7 -- etldoc: osm_ocean_polygon_gen_z7 -> water_z7
SELECT geometry, SELECT NULL::integer AS id,
(ST_Dump(geometry)).geom AS 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,
@ -334,7 +427,8 @@ SELECT geometry,
FROM osm_ocean_polygon_gen_z7 FROM osm_ocean_polygon_gen_z7
UNION ALL UNION ALL
-- etldoc: osm_water_polygon_gen_z7 -> water_z7 -- etldoc: osm_water_polygon_gen_z7 -> water_z7
SELECT geometry, SELECT osm_id AS id,
(ST_Dump(geometry)).geom AS geometry,
water_class(waterway, water) AS class, water_class(waterway, water) AS class,
is_intermittent, is_intermittent,
NULL::boolean AS is_bridge, NULL::boolean AS is_bridge,
@ -342,11 +436,13 @@ SELECT geometry,
FROM osm_water_polygon_gen_z7 FROM osm_water_polygon_gen_z7
WHERE "natural" != 'bay' WHERE "natural" != 'bay'
); );
CREATE INDEX ON water_z7 USING gist(geometry);
CREATE OR REPLACE VIEW water_z8 AS CREATE MATERIALIZED VIEW water_z8 AS
( (
-- etldoc: osm_ocean_polygon_gen_z8 -> water_z8 -- etldoc: osm_ocean_polygon_gen_z8 -> water_z8
SELECT geometry, SELECT NULL::integer AS id,
(ST_Dump(geometry)).geom AS 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,
@ -354,7 +450,8 @@ SELECT geometry,
FROM osm_ocean_polygon_gen_z8 FROM osm_ocean_polygon_gen_z8
UNION ALL UNION ALL
-- etldoc: osm_water_polygon_gen_z8 -> water_z8 -- etldoc: osm_water_polygon_gen_z8 -> water_z8
SELECT geometry, SELECT osm_id AS id,
(ST_Dump(geometry)).geom AS geometry,
water_class(waterway, water) AS class, water_class(waterway, water) AS class,
is_intermittent, is_intermittent,
NULL::boolean AS is_bridge, NULL::boolean AS is_bridge,
@ -362,11 +459,13 @@ SELECT geometry,
FROM osm_water_polygon_gen_z8 FROM osm_water_polygon_gen_z8
WHERE "natural" != 'bay' WHERE "natural" != 'bay'
); );
CREATE INDEX ON water_z8 USING gist(geometry);
CREATE OR REPLACE VIEW water_z9 AS CREATE MATERIALIZED VIEW water_z9 AS
( (
-- etldoc: osm_ocean_polygon_gen_z9 -> water_z9 -- etldoc: osm_ocean_polygon_gen_z9 -> water_z9
SELECT geometry, SELECT NULL::integer AS id,
(ST_Dump(geometry)).geom AS 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,
@ -374,7 +473,8 @@ SELECT geometry,
FROM osm_ocean_polygon_gen_z9 FROM osm_ocean_polygon_gen_z9
UNION ALL UNION ALL
-- etldoc: osm_water_polygon_gen_z9 -> water_z9 -- etldoc: osm_water_polygon_gen_z9 -> water_z9
SELECT geometry, SELECT osm_id AS id,
(ST_Dump(geometry)).geom AS geometry,
water_class(waterway, water) AS class, water_class(waterway, water) AS class,
is_intermittent, is_intermittent,
NULL::boolean AS is_bridge, NULL::boolean AS is_bridge,
@ -382,11 +482,13 @@ SELECT geometry,
FROM osm_water_polygon_gen_z9 FROM osm_water_polygon_gen_z9
WHERE "natural" != 'bay' WHERE "natural" != 'bay'
); );
CREATE INDEX ON water_z9 USING gist(geometry);
CREATE OR REPLACE VIEW water_z10 AS CREATE MATERIALIZED VIEW water_z10 AS
( (
-- etldoc: osm_ocean_polygon_gen_z10 -> water_z10 -- etldoc: osm_ocean_polygon_gen_z10 -> water_z10
SELECT geometry, SELECT NULL::integer AS id,
(ST_Dump(geometry)).geom AS 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,
@ -394,7 +496,8 @@ SELECT geometry,
FROM osm_ocean_polygon_gen_z10 FROM osm_ocean_polygon_gen_z10
UNION ALL UNION ALL
-- etldoc: osm_water_polygon_gen_z10 -> water_z10 -- etldoc: osm_water_polygon_gen_z10 -> water_z10
SELECT geometry, SELECT osm_id AS id,
(ST_Dump(geometry)).geom AS geometry,
water_class(waterway, water) AS class, water_class(waterway, water) AS class,
is_intermittent, is_intermittent,
NULL::boolean AS is_bridge, NULL::boolean AS is_bridge,
@ -402,11 +505,13 @@ SELECT geometry,
FROM osm_water_polygon_gen_z10 FROM osm_water_polygon_gen_z10
WHERE "natural" != 'bay' WHERE "natural" != 'bay'
); );
CREATE INDEX ON water_z10 USING gist(geometry);
CREATE OR REPLACE VIEW water_z11 AS CREATE MATERIALIZED VIEW water_z11 AS
( (
-- etldoc: osm_ocean_polygon_gen_z11 -> water_z11 -- etldoc: osm_ocean_polygon_gen_z11 -> water_z11
SELECT geometry, SELECT NULL::integer AS id,
(ST_Dump(geometry)).geom AS 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,
@ -414,7 +519,8 @@ SELECT geometry,
FROM osm_ocean_polygon_gen_z11 FROM osm_ocean_polygon_gen_z11
UNION ALL UNION ALL
-- etldoc: osm_water_polygon_gen_z11 -> water_z11 -- etldoc: osm_water_polygon_gen_z11 -> water_z11
SELECT geometry, SELECT osm_id AS id,
(ST_Dump(geometry)).geom AS geometry,
water_class(waterway, water) AS class, water_class(waterway, water) AS class,
is_intermittent, is_intermittent,
NULL::boolean AS is_bridge, NULL::boolean AS is_bridge,
@ -422,11 +528,13 @@ SELECT geometry,
FROM osm_water_polygon_gen_z11 FROM osm_water_polygon_gen_z11
WHERE "natural" != 'bay' WHERE "natural" != 'bay'
); );
CREATE INDEX ON water_z11 USING gist(geometry);
CREATE OR REPLACE VIEW water_z12 AS CREATE MATERIALIZED VIEW water_z12 AS
( (
-- etldoc: osm_ocean_polygon_union -> water_z12 -- etldoc: osm_ocean_polygon_union -> water_z12
SELECT geometry, SELECT NULL::integer AS id,
(ST_Dump(geometry)).geom AS 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,
@ -434,7 +542,8 @@ SELECT geometry,
FROM osm_ocean_polygon_union FROM osm_ocean_polygon_union
UNION ALL UNION ALL
-- etldoc: osm_water_polygon -> water_z12 -- etldoc: osm_water_polygon -> water_z12
SELECT geometry, SELECT osm_id AS id,
(ST_Dump(geometry)).geom AS geometry,
water_class(waterway, water) AS class, water_class(waterway, water) AS class,
is_intermittent, is_intermittent,
is_bridge, is_bridge,
@ -442,6 +551,7 @@ SELECT geometry,
FROM osm_water_polygon FROM osm_water_polygon
WHERE "natural" != 'bay' WHERE "natural" != 'bay'
); );
CREATE INDEX ON water_z12 USING gist(geometry);
-- etldoc: layer_water [shape=record fillcolor=lightpink, style="rounded,filled", -- etldoc: layer_water [shape=record fillcolor=lightpink, style="rounded,filled",
-- etldoc: label="layer_water |<z0> z0|<z1>z1|<z2>z2|<z3>z3 |<z4> z4|<z5>z5|<z6>z6|<z7>z7| <z8> z8 |<z9> z9 |<z10> z10 |<z11> z11 |<z12> z12+" ] ; -- etldoc: label="layer_water |<z0> z0|<z1>z1|<z2>z2|<z3>z3 |<z4> z4|<z5>z5|<z6>z6|<z7>z7| <z8> z8 |<z9> z9 |<z10> z10 |<z11> z11 |<z12> z12+" ] ;
@ -449,6 +559,7 @@ WHERE "natural" != 'bay'
CREATE OR REPLACE FUNCTION layer_water(bbox geometry, zoom_level int) CREATE OR REPLACE FUNCTION layer_water(bbox geometry, zoom_level int)
RETURNS TABLE RETURNS TABLE
( (
id bigint,
geometry geometry, geometry geometry,
class text, class text,
brunnel text, brunnel text,
@ -456,7 +567,8 @@ CREATE OR REPLACE FUNCTION layer_water(bbox geometry, zoom_level int)
) )
AS AS
$$ $$
SELECT geometry, SELECT id,
geometry,
class::text, class::text,
waterway_brunnel(is_bridge, is_tunnel) AS brunnel, waterway_brunnel(is_bridge, is_tunnel) AS brunnel,
is_intermittent::int AS intermittent is_intermittent::int AS intermittent

View File

@ -12,6 +12,10 @@ layer:
This however can lead to less rendering options in clients since these boundaries show up. So you might not be This however can lead to less rendering options in clients since these boundaries show up. So you might not be
able to use border styling for ocean water features. able to use border styling for ocean water features.
fields: fields:
id:
description: |
From zoom 6 are taken OSM IDs. Up to zoom 5 there are used Natural Earth lakes, where are propagated the OSM IDs insted of Natural Earth IDs.
For smaller area then planet, NE lakes keep their Natural Earth IDs.
class: class:
description: | description: |
All water polygons from [OpenStreetMapData](http://osmdata.openstreetmap.de/) have the class `ocean`. All water polygons from [OpenStreetMapData](http://osmdata.openstreetmap.de/) have the class `ocean`.
@ -39,7 +43,7 @@ layer:
- tunnel - tunnel
buffer_size: 4 buffer_size: 4
datasource: datasource:
query: (SELECT geometry, class, intermittent, brunnel FROM layer_water(!bbox!, z(!scale_denominator!))) AS t query: (SELECT id, geometry, class, intermittent, brunnel FROM layer_water(!bbox!, z(!scale_denominator!))) AS t
schema: schema:
- ./update_water.sql - ./update_water.sql
- ./water.sql - ./water.sql