Move to new modular layer structure

This commit is contained in:
lukasmartinelli
2016-10-09 21:27:09 +02:00
parent ad5d53ad19
commit 480d720585
21 changed files with 92 additions and 251 deletions

View File

@@ -1,135 +0,0 @@
CREATE OR REPLACE FUNCTION boundary_class(featureclass VARCHAR) RETURNS VARCHAR
AS $$
BEGIN
RETURN CASE
WHEN featureclass ILIKE 'line of control%' THEN 'control'
WHEN featureclass ILIKE 'disputed%' THEN 'dispute'
WHEN featureclass ILIKE 'lease%' THEN 'lease'
WHEN featureclass ILIKE 'overlay%' THEN 'overlay'
ELSE 'boundary'
END;
END;
$$ LANGUAGE plpgsql IMMUTABLE;
CREATE OR REPLACE VIEW boundary_z0 AS (
SELECT geom, 0 AS admin_level, scalerank,
boundary_class(featurecla) AS class
FROM ne_110m_admin_0_boundary_lines_land
);
CREATE OR REPLACE VIEW boundary_z1 AS (
SELECT geom, 0 AS admin_level, scalerank,
boundary_class(featurecla) AS class
FROM ne_50m_admin_0_boundary_lines_land
UNION ALL
SELECT geom, 1 AS admin_level, scalerank,
boundary_class(featurecla) AS class
FROM ne_50m_admin_1_states_provinces_lines
WHERE scalerank <= 2
);
CREATE OR REPLACE VIEW boundary_z3 AS (
SELECT geom, 0 AS admin_level, scalerank,
boundary_class(featurecla) AS class
FROM ne_50m_admin_0_boundary_lines_land
UNION ALL
SELECT geom, 1 AS admin_level, scalerank,
boundary_class(featurecla) AS class
FROM ne_50m_admin_1_states_provinces_lines
);
CREATE OR REPLACE VIEW boundary_z4 AS (
SELECT geom, 0 AS admin_level, scalerank,
boundary_class(featurecla) AS class
FROM ne_10m_admin_0_boundary_lines_land
UNION ALL
SELECT geom, 1 AS admin_level, scalerank,
boundary_class(featurecla) AS class
FROM ne_10m_admin_1_states_provinces_lines_shp
WHERE scalerank <= 3 AND featurecla = 'Adm-1 boundary'
);
CREATE OR REPLACE VIEW boundary_z5 AS (
SELECT geom, 0 AS admin_level, scalerank,
boundary_class(featurecla) AS class
FROM ne_10m_admin_0_boundary_lines_land
UNION ALL
SELECT geom, 1 AS admin_level, scalerank,
boundary_class(featurecla) AS class
FROM ne_10m_admin_1_states_provinces_lines_shp
WHERE scalerank <= 7 AND featurecla = 'Adm-1 boundary'
);
CREATE OR REPLACE VIEW boundary_z7 AS (
SELECT geom, 0 AS admin_level, scalerank,
boundary_class(featurecla) AS class
FROM ne_10m_admin_0_boundary_lines_land
UNION ALL
SELECT geom, 1 AS admin_level, scalerank,
boundary_class(featurecla) AS class
FROM ne_10m_admin_1_states_provinces_lines_shp
WHERE featurecla = 'Adm-1 boundary'
);
CREATE OR REPLACE VIEW boundary_z8 AS (
SELECT way AS geom, level AS admin_level,
NULL AS scalerank, NULL AS class
FROM admin_line
WHERE level <= 4 AND ST_Length(way) > 10000
);
CREATE OR REPLACE VIEW boundary_z10 AS (
SELECT way AS geom, level AS admin_level,
NULL AS scalerank, NULL AS class
FROM admin_line
WHERE level <= 6
);
CREATE OR REPLACE VIEW boundary_z11 AS (
SELECT way AS geom, level AS admin_level,
NULL AS scalerank, NULL AS class
FROM admin_line
WHERE level <= 8
);
CREATE OR REPLACE VIEW boundary_z12 AS (
SELECT way AS geom, level AS admin_level,
NULL AS scalerank, NULL AS class
FROM admin_line
);
CREATE OR REPLACE FUNCTION layer_boundary (bbox geometry, zoom_level int)
RETURNS TABLE(geom geometry, admin_level int, scalerank int, class text) AS $$
SELECT geom, admin_level, scalerank::int, class FROM (
SELECT * FROM boundary_z0 WHERE geom && bbox AND zoom_level = 0
UNION ALL
SELECT * FROM boundary_z1 WHERE geom && bbox AND zoom_level BETWEEN 1 AND 2
UNION ALL
SELECT * FROM boundary_z3 WHERE geom && bbox AND zoom_level = 3
UNION ALL
SELECT * FROM boundary_z4 WHERE geom && bbox AND zoom_level = 4
UNION ALL
SELECT * FROM boundary_z5 WHERE geom && bbox AND zoom_level BETWEEN 5 AND 6
UNION ALL
SELECT * FROM boundary_z7 WHERE geom && bbox AND zoom_level = 7
UNION ALL
SELECT ST_Simplify(geom, 400) AS geom, admin_level, scalerank, class
FROM boundary_z8 WHERE geom && bbox AND zoom_level = 8
UNION ALL
SELECT ST_Simplify(geom, 320) AS geom, admin_level, scalerank, class
FROM boundary_z8 WHERE geom && bbox AND zoom_level = 9
UNION ALL
SELECT ST_Simplify(geom, 150) AS geom, admin_level, scalerank, class
FROM boundary_z10 WHERE geom && bbox AND zoom_level = 10
UNION ALL
SELECT ST_Simplify(geom, 100) AS geom, admin_level, scalerank, class
FROM boundary_z11 WHERE geom && bbox AND zoom_level = 11
UNION ALL
SELECT ST_Simplify(geom, 50) AS geom, admin_level, scalerank, class
FROM boundary_z12 WHERE geom && bbox AND zoom_level = 12
UNION ALL
SELECT geom, admin_level, scalerank, class
FROM boundary_z12 WHERE geom && bbox AND zoom_level >= 13
) AS zoom_levels;
$$ LANGUAGE SQL IMMUTABLE;

View File

@@ -1,22 +0,0 @@
CREATE OR REPLACE VIEW building_z13 AS (
SELECT osm_id, way, height, levels FROM buildings WHERE way_area > 1400
);
CREATE OR REPLACE VIEW building_z14 AS (
SELECT osm_id, way, height, levels FROM buildings
);
CREATE OR REPLACE FUNCTION layer_building(bbox geometry, zoom_level int)
RETURNS TABLE(geom geometry, osm_id bigint, render_height float) AS $$
SELECT way, osm_id,
least(greatest(3, COALESCE(height, levels*3.66,5)),400)^.7 AS render_height
FROM (
SELECT osm_id, ST_Simplify(way, 10) AS way, height, levels FROM building_z13
WHERE zoom_level = 13 AND way && bbox
UNION ALL
SELECT * FROM building_z14
WHERE zoom_level >= 14 AND way && bbox
) AS zoom_levels
ORDER BY render_height, ST_YMin(way) DESC;
$$ LANGUAGE SQL IMMUTABLE;

View File

@@ -1,52 +0,0 @@
CREATE TABLE IF NOT EXISTS country_label AS (
SELECT topoint(geom) AS geom,
name,
adm0_a3, abbrev, postal,
scalerank, labelrank,
CASE WHEN tiny < 0 THEN 0 ELSE 1 END AS is_tiny
FROM ne_10m_admin_0_countries
WHERE scalerank <= 1
);
CREATE INDEX IF NOT EXISTS country_label_geom_idx ON country_label USING gist(geom);
CREATE OR REPLACE VIEW country_z0 AS (
SELECT * FROM country_label WHERE scalerank = 0 AND is_tiny = 0 AND labelrank <= 2
);
CREATE OR REPLACE VIEW country_z1 AS (
SELECT * FROM country_label WHERE scalerank = 0 AND is_tiny = 0 AND labelrank <= 3
);
CREATE OR REPLACE VIEW country_z2 AS (
SELECT * FROM country_label WHERE scalerank = 0 AND is_tiny = 0 AND labelrank <= 4
);
CREATE OR REPLACE VIEW country_z3 AS (
SELECT * FROM country_label WHERE scalerank = 0 AND is_tiny = 0
);
CREATE OR REPLACE VIEW country_z5 AS (
SELECT * FROM country_label WHERE scalerank <= 1
);
CREATE OR REPLACE FUNCTION layer_country(bbox geometry, zoom_level int)
RETURNS TABLE(geom geometry, name text, abbrev text, postal text, scalerank int, labelrank int) AS $$
SELECT geom, name, abbrev, postal, scalerank::int, labelrank::int FROM (
SELECT * FROM country_z0
WHERE zoom_level = 0
UNION ALL
SELECT * FROM country_z1
WHERE zoom_level = 1
UNION ALL
SELECT * FROM country_z2
WHERE zoom_level BETWEEN 2 AND 4
UNION ALL
SELECT * FROM country_z3
WHERE zoom_level BETWEEN 3 AND 4
UNION ALL
SELECT * FROM country_z5
WHERE zoom_level >= 5
) AS t
WHERE geom && bbox
ORDER BY scalerank ASC, labelrank ASC, length(name) ASC;
$$ LANGUAGE SQL IMMUTABLE;

View File

@@ -1,30 +0,0 @@
CREATE OR REPLACE VIEW ice_z0 AS (
SELECT geom, 'glacier' AS type FROM ne_110m_glaciated_areas
);
CREATE OR REPLACE VIEW ice_z2 AS (
SELECT geom, 'glacier' AS type FROM ne_50m_glaciated_areas
UNION ALL
SELECT geom, 'ice_shelf' AS type FROM ne_50m_antarctic_ice_shelves_polys
);
CREATE OR REPLACE VIEW ice_z5 AS (
SELECT geom, 'glacier' AS type FROM ne_10m_glaciated_areas
UNION ALL
SELECT geom, 'ice_shelf' AS type FROM ne_10m_antarctic_ice_shelves_polys
);
CREATE OR REPLACE FUNCTION layer_ice(bbox geometry, zoom_level int)
RETURNS TABLE(geom geometry, class text) AS $$
SELECT geom, type::text AS class FROM (
SELECT geom, type FROM ice_z0
WHERE zoom_level BETWEEN 0 AND 1
UNION ALL
SELECT * FROM ice_z2
WHERE zoom_level BETWEEN 2 AND 4
UNION ALL
SELECT * FROM ice_z5
WHERE zoom_level BETWEEN 5 AND 8
) AS zoom_levels
WHERE geom && bbox;
$$ LANGUAGE SQL IMMUTABLE;

View File

@@ -1,112 +0,0 @@
CREATE OR REPLACE VIEW place_z2 AS (
SELECT geom, name, 'settlement' AS class, 'city'::place AS rank, scalerank, pop_min AS population
FROM ne_10m_populated_places
WHERE scalerank <= 0
);
CREATE OR REPLACE VIEW place_z3 AS (
SELECT geom, name, 'settlement' AS class, 'city'::place AS rank, scalerank, pop_min AS population
FROM ne_10m_populated_places
WHERE scalerank <= 2
);
CREATE OR REPLACE VIEW place_z4 AS (
SELECT geom, name, 'settlement' AS class, 'city'::place AS rank, scalerank, pop_min AS population
FROM ne_10m_populated_places
WHERE scalerank <= 5
);
CREATE OR REPLACE VIEW place_z5 AS (
SELECT geom, name, 'settlement' AS class, 'city'::place AS rank, scalerank, pop_min AS population
FROM ne_10m_populated_places
WHERE scalerank <= 6
);
CREATE OR REPLACE VIEW place_z6 AS (
SELECT geom, name, 'settlement' AS class, 'city'::place AS rank, scalerank, pop_min AS population
FROM ne_10m_populated_places
WHERE scalerank <= 7
);
CREATE OR REPLACE VIEW place_z7 AS (
SELECT geom, name, 'settlement' AS class, 'city'::place AS rank, scalerank, pop_min AS population
FROM ne_10m_populated_places
);
CREATE OR REPLACE VIEW place_z8 AS (
SELECT way AS geom, name, class::text, rank, NULL::integer AS scalerank, population FROM place_point
WHERE rank IN ('city', 'town')
);
CREATE OR REPLACE VIEW place_z10 AS (
SELECT way AS geom, name, class::text, rank, NULL::integer AS scalerank, population FROM place_point
WHERE rank IN ('city', 'town', 'village') OR class='subregion'
);
CREATE OR REPLACE VIEW place_z11 AS (
SELECT way AS geom, name, class::text, rank, NULL::integer AS scalerank, population FROM place_point
WHERE class IN ('subregion', 'settlement')
);
CREATE OR REPLACE VIEW place_z13 AS (
SELECT way AS geom, name, class::text, rank, NULL::integer AS scalerank, population FROM place_point
);
CREATE OR REPLACE FUNCTION layer_place(bbox geometry, zoom_level int, pixel_width numeric)
RETURNS TABLE(geom geometry, name text, class text, rank text, scalerank int) AS $$
SELECT geom, name, class, rank::text, scalerank FROM (
SELECT geom, name, class, rank, scalerank,
row_number() OVER (
PARTITION BY LabelGrid(geom, 150 * pixel_width)
ORDER BY scalerank ASC NULLS LAST,
CASE class
WHEN 'settlement' THEN 10
WHEN 'subregion' THEN 5
WHEN 'locality' THEN 2 ELSE 1
END DESC,
rank DESC,
population DESC NULLS LAST,
length(name) DESC
) AS gridrank
FROM (
SELECT * FROM place_z2
WHERE zoom_level = 2
UNION ALL
SELECT * FROM place_z3
WHERE zoom_level = 3
UNION ALL
SELECT * FROM place_z4
WHERE zoom_level = 4
UNION ALL
SELECT * FROM place_z5
WHERE zoom_level = 5
UNION ALL
SELECT * FROM place_z6
WHERE zoom_level = 6
UNION ALL
SELECT * FROM place_z7
WHERE zoom_level = 7
UNION ALL
SELECT * FROM place_z8
WHERE zoom_level BETWEEN 8 AND 9
UNION ALL
SELECT * FROM place_z10
WHERE zoom_level = 10
UNION ALL
SELECT * FROM place_z11
WHERE zoom_level BETWEEN 11 AND 12
UNION ALL
SELECT * FROM place_z13
WHERE zoom_level >= 13
) AS zoom_levels
WHERE geom && bbox
) AS ranked_places
WHERE
zoom_level <= 7 OR
(zoom_level = 8 AND gridrank <= 4) OR
(zoom_level = 9 AND gridrank <= 9) OR
(zoom_level = 10 AND gridrank <= 9) OR
(zoom_level = 11 AND gridrank <= 9) OR
(zoom_level = 12 AND gridrank <= 9) OR
zoom_level >= 13;
$$ LANGUAGE SQL IMMUTABLE;

View File

@@ -1,18 +0,0 @@
CREATE OR REPLACE VIEW rail_z13 AS (
SELECT * FROM rail
WHERE class='rail'
);
CREATE OR REPLACE VIEW rail_z14 AS (
SELECT * FROM rail
);
CREATE OR REPLACE FUNCTION layer_rail(bbox geometry, zoom_level int)
RETURNS TABLE(geom geometry, class text, brunnel text) AS $$
SELECT way AS geom, class::text, brunnel::text FROM (
SELECT * FROM rail_z13 WHERE zoom_level = 13
UNION ALL
SELECT * FROM rail_z14 WHERE zoom_level >= 14
) AS zoom_levels
WHERE way && bbox;
$$ LANGUAGE SQL IMMUTABLE;

View File

@@ -1,129 +0,0 @@
CREATE OR REPLACE FUNCTION ne_road_class(type VARCHAR) RETURNS VARCHAR AS $$
SELECT CASE type
WHEN 'Major Highway' THEN 'motorway'
WHEN 'Secondary Highway' THEN 'trunk'
WHEN 'Road' THEN 'primary'
ELSE type
END;
$$ LANGUAGE SQL IMMUTABLE;
CREATE TABLE IF NOT EXISTS ne_10m_global_roads AS (
SELECT geom, scalerank, ne_road_class(type) AS class
FROM ne_10m_roads
WHERE continent <> 'North America'
AND featurecla = 'Road'
AND type IN ('Major Highway', 'Secondary Highway', 'Road')
UNION ALL
SELECT geom, scalerank, ne_road_class(type) AS class
FROM ne_10m_roads_north_america
WHERE type IN ('Major Highway', 'Secondary Highway', 'Road')
);
CREATE INDEX IF NOT EXISTS ne_10m_global_roads_geom_idx ON ne_10m_global_roads USING gist(geom);
CREATE INDEX IF NOT EXISTS ne_10m_global_roads_scalerank_idx ON ne_10m_global_roads(scalerank);
CREATE OR REPLACE VIEW road_z4 AS (
SELECT geom, class
FROM ne_10m_global_roads
WHERE scalerank <= 5
);
CREATE OR REPLACE VIEW road_z5 AS (
SELECT geom, class
FROM ne_10m_global_roads
WHERE scalerank <= 6
);
CREATE OR REPLACE VIEW road_z6 AS (
SELECT geom, class
FROM ne_10m_global_roads
WHERE scalerank <= 7
);
CREATE OR REPLACE VIEW road_z7 AS (
SELECT geom, class
FROM ne_10m_global_roads
WHERE scalerank <= 7
);
CREATE TABLE IF NOT EXISTS road_z8 AS (
SELECT ST_Simplify(way, 200) AS geom, class::text
FROM roads
WHERE class IN ('motorway','trunk')
);
CREATE INDEX IF NOT EXISTS road_z8_geom_idx ON road_z8 USING gist(geom);
CREATE TABLE IF NOT EXISTS road_z9 AS (
SELECT ST_Simplify(way, 120) AS geom, class::text
FROM roads
WHERE class IN ('motorway','trunk', 'primary')
);
CREATE INDEX IF NOT EXISTS road_z9_geom_idx ON road_z9 USING gist(geom);
CREATE TABLE IF NOT EXISTS road_z10 AS (
SELECT ST_Simplify(way, 50) AS geom, class::text
FROM roads
WHERE class IN ('motorway','trunk', 'primary', 'secondary')
);
CREATE INDEX IF NOT EXISTS road_z10_geom_idx ON road_z10 USING gist(geom);
CREATE TABLE IF NOT EXISTS road_z11 AS (
SELECT ST_Simplify(way, 20) AS geom, class::text
FROM roads
WHERE class IN ('motorway','trunk', 'primary', 'secondary', 'tertiary')
);
CREATE INDEX IF NOT EXISTS road_z11_geom_idx ON road_z11 USING gist(geom);
CREATE OR REPLACE VIEW road_z12 AS (
SELECT way AS geom, class::text
FROM roads
WHERE class IN ('motorway','trunk','primary', 'secondary', 'tertiary', 'minor')
UNION ALL
SELECT way AS geom, class::text
FROM road_areas
);
CREATE OR REPLACE VIEW road_z13 AS (
SELECT way AS geom, class::text
FROM roads
WHERE class NOT IN ('path')
UNION ALL
SELECT way AS geom, class::text
FROM road_areas
);
CREATE OR REPLACE VIEW road_z14 AS (
SELECT way AS geom, class::text
FROM roads
UNION ALL
SELECT way AS geom, class::text
FROM road_areas
);
CREATE OR REPLACE FUNCTION layer_road(bbox geometry, zoom_level int)
RETURNS TABLE(geom geometry, class text) AS $$
SELECT geom, class::text FROM (
SELECT * FROM road_z4 WHERE zoom_level BETWEEN 4 AND 5
UNION ALL
SELECT * FROM road_z5 WHERE zoom_level = 5
UNION ALL
SELECT * FROM road_z6 WHERE zoom_level = 6
UNION ALL
SELECT * FROM road_z7 WHERE zoom_level = 7
UNION ALL
SELECT * FROM road_z8 WHERE zoom_level = 8
UNION ALL
SELECT geom, class FROM road_z9 WHERE zoom_level = 9
UNION ALL
SELECT geom, class FROM road_z10 WHERE zoom_level = 10
UNION ALL
SELECT geom, class FROM road_z11 WHERE zoom_level = 11
UNION ALL
SELECT geom, class FROM road_z12 WHERE zoom_level = 12
UNION ALL
SELECT * FROM road_z13 WHERE zoom_level = 13
UNION ALL
SELECT * FROM road_z14 WHERE zoom_level >= 14
) AS zoom_levels
WHERE geom && bbox;
$$ LANGUAGE SQL IMMUTABLE;

View File

@@ -1,43 +0,0 @@
CREATE OR REPLACE FUNCTION fix_win1252_shp_encoding(str TEXT) RETURNS TEXT
AS $$
BEGIN
RETURN convert_from(convert_to(str, 'WIN1252'), 'UTF-8');
EXCEPTION WHEN others THEN RETURN str;
END;
$$ LANGUAGE plpgsql IMMUTABLE;
CREATE TABLE IF NOT EXISTS state_label AS (
SELECT topoint(geom) AS geom,
name_local, fix_win1252_shp_encoding(name) AS name_en,
abbrev, postal,
scalerank, labelrank,
shape_area, datarank, type
FROM ne_10m_admin_1_states_provinces_shp
WHERE type IN ('State', 'Avtonomnyy Okrug', 'Sheng', 'Estado')
AND scalerank <= 3 AND labelrank <= 2
);
CREATE INDEX IF NOT EXISTS state_label_geom_idx ON state_label USING gist(geom);
CREATE OR REPLACE VIEW state_z3 AS (
SELECT * FROM state_label
WHERE (scalerank <= 2 AND labelrank <= 1) OR type = 'Avtonomnyy Okrug'
);
CREATE OR REPLACE VIEW state_z4 AS (
SELECT * FROM state_label
);
CREATE OR REPLACE FUNCTION layer_state(bbox geometry, zoom_level int)
RETURNS TABLE(geom geometry, name text, name_en text, abbrev text, postal text, scalerank int, labelrank int) AS $$
SELECT geom,
COALESCE(name_local, name_en) AS name_local, name_en,
abbrev, postal, scalerank::int, labelrank::int FROM (
SELECT * FROM state_z3
WHERE zoom_level = 3
UNION ALL
SELECT * FROM state_z4
WHERE zoom_level >= 4
) AS t
WHERE geom && bbox
ORDER BY scalerank ASC, labelrank ASC, shape_area DESC;
$$ LANGUAGE SQL IMMUTABLE;

View File

@@ -1,30 +0,0 @@
CREATE OR REPLACE VIEW urban_z4 AS (
SELECT geom, scalerank
FROM ne_50m_urban_areas
WHERE scalerank <= 2
);
CREATE OR REPLACE VIEW urban_z5 AS (
SELECT geom, scalerank
FROM ne_50m_urban_areas
);
CREATE OR REPLACE VIEW urban_z6 AS (
SELECT geom, scalerank
FROM ne_10m_urban_areas
);
CREATE OR REPLACE FUNCTION layer_urban(bbox geometry, zoom_level int)
RETURNS TABLE(geom geometry, scalerank int) AS $$
SELECT geom, scalerank FROM (
SELECT * FROM urban_z4
WHERE zoom_level = 4
UNION ALL
SELECT * FROM urban_z5
WHERE zoom_level = 5
UNION ALL
SELECT * FROM urban_z6
WHERE zoom_level BETWEEN 6 AND 10 AND scalerank-1 <= zoom_level
) AS zoom_levels
WHERE geom && bbox;
$$ LANGUAGE SQL IMMUTABLE;

View File

@@ -1,148 +0,0 @@
CREATE OR REPLACE VIEW water_z0 AS (
SELECT geom FROM ne_110m_ocean
UNION ALL
SELECT geom FROM ne_110m_lakes
);
CREATE OR REPLACE VIEW water_z1 AS (
SELECT geom FROM ne_110m_ocean
UNION ALL
SELECT geom FROM ne_110m_lakes
);
CREATE OR REPLACE VIEW water_z2 AS (
SELECT geom FROM ne_50m_ocean
UNION ALL
SELECT geom FROM ne_110m_lakes
);
CREATE OR REPLACE VIEW water_z3 AS (
SELECT geom FROM ne_50m_ocean
UNION ALL
SELECT geom FROM ne_110m_lakes
UNION ALL
SELECT geom FROM ne_110m_rivers_lake_centerlines
WHERE featurecla = 'River'
);
CREATE OR REPLACE VIEW water_z4 AS (
SELECT geom FROM ne_50m_ocean
UNION ALL
SELECT geom FROM ne_50m_lakes
UNION ALL
SELECT geom FROM ne_50m_rivers_lake_centerlines
WHERE featurecla = 'River'
);
CREATE OR REPLACE VIEW water_z5 AS (
SELECT geom FROM ne_10m_ocean
UNION ALL
SELECT geom FROM ne_10m_lakes
UNION ALL
SELECT geom FROM ne_50m_rivers_lake_centerlines
WHERE featurecla = 'River'
);
CREATE OR REPLACE VIEW water_z6 AS (
SELECT geom FROM ne_10m_ocean
UNION ALL
SELECT geom FROM ne_10m_lakes
UNION ALL
SELECT geom FROM ne_10m_rivers_lake_centerlines
WHERE featurecla = 'River'
);
CREATE TABLE IF NOT EXISTS water_z7 AS (
SELECT geom FROM ne_10m_ocean
UNION ALL
SELECT ST_SimplifyPreserveTopology(way, 350) AS geom FROM water_areas
WHERE way_area > 9000000
UNION ALL
SELECT geom FROM ne_10m_rivers_lake_centerlines
WHERE featurecla = 'River'
);
CREATE INDEX IF NOT EXISTS water_z7_geom_idx ON water_z7 USING gist(geom);
CREATE TABLE IF NOT EXISTS water_z8 AS (
SELECT geom FROM ne_10m_ocean
UNION ALL
SELECT ST_SimplifyPreserveTopology(way, 200) AS geom FROM water_areas
WHERE way_area > 1000000
UNION ALL
SELECT ST_Simplify(way, 200) AS geom FROM waterways
WHERE waterway IN ('river') AND ST_Length(way) > 10000
);
CREATE INDEX IF NOT EXISTS water_z8_geom_idx ON water_z8 USING gist(geom);
CREATE TABLE IF NOT EXISTS water_z9 AS (
SELECT ST_SimplifyPreserveTopology(way, 100) AS geom FROM water_areas
WHERE way_area > 500000
UNION ALL
SELECT ST_Simplify(way,100) AS geom FROM waterways
WHERE waterway IN ('river') AND ST_Length(way) > 5000
);
CREATE INDEX IF NOT EXISTS water_z9_geom_idx ON water_z9 USING gist(geom);
CREATE OR REPLACE VIEW water_z11 AS (
SELECT way AS geom FROM water_areas
WHERE way_area > 50000
UNION ALL
SELECT way AS geom FROM waterways
WHERE waterway IN ('river')
);
CREATE OR REPLACE VIEW water_z12 AS (
SELECT way AS geom FROM water_areas
WHERE way_area > 40000
UNION ALL
SELECT way AS geom FROM waterways
WHERE waterway IN ('river', 'canal', 'stream')
);
CREATE OR REPLACE VIEW water_z13 AS (
SELECT way AS geom FROM water_areas
WHERE way_area > 2000
UNION ALL
SELECT way AS geom FROM waterways
WHERE waterway IN ('river', 'canal', 'stream', 'drain', 'ditch')
);
CREATE OR REPLACE VIEW water_z14 AS (
SELECT way AS geom FROM water_areas
UNION ALL
SELECT way AS geom FROM waterways
);
CREATE OR REPLACE FUNCTION layer_water (bbox geometry, zoom_level int)
RETURNS TABLE(geom geometry) AS $$
SELECT geom FROM (
SELECT * FROM water_z0 WHERE zoom_level = 0
UNION ALL
SELECT * FROM water_z1 WHERE zoom_level = 1
UNION ALL
SELECT * FROM water_z2 WHERE zoom_level = 2
UNION ALL
SELECT * FROM water_z3 WHERE zoom_level = 3
UNION ALL
SELECT * FROM water_z4 WHERE zoom_level = 4
UNION ALL
SELECT * FROM water_z5 WHERE zoom_level = 5
UNION ALL
SELECT * FROM water_z6 WHERE zoom_level = 6
UNION ALL
SELECT * FROM water_z7 WHERE zoom_level = 7
UNION ALL
SELECT geom FROM water_z8 WHERE zoom_level = 8
UNION ALL
SELECT geom FROM water_z9 WHERE zoom_level BETWEEN 9 AND 10
UNION ALL
SELECT * FROM water_z11 WHERE zoom_level = 11
UNION ALL
SELECT * FROM water_z12 WHERE zoom_level = 12
UNION ALL
SELECT * FROM water_z13 WHERE zoom_level = 13
UNION ALL
SELECT * FROM water_z14 WHERE zoom_level >= 14
) AS zoom_levels
WHERE geom && bbox;
$$ LANGUAGE SQL IMMUTABLE;