Major breakthrough, just some artifacting to resolve

This commit is contained in:
stirringhalo
2017-01-28 10:54:52 -05:00
parent e10e2b9b94
commit 199095a2ba
39 changed files with 1179 additions and 264 deletions

View File

@@ -1,50 +1,91 @@
DROP TABLE IF EXISTS osm_important_waterway_linestring CASCADE;
DROP TABLE IF EXISTS osm_important_waterway_linestring_gen1 CASCADE;
DROP TABLE IF EXISTS osm_important_waterway_linestring_gen2 CASCADE;
DROP TABLE IF EXISTS osm_important_waterway_linestring_gen3 CASCADE;
DROP TRIGGER IF EXISTS trigger_flag ON osm_waterway_linestring;
DROP TRIGGER IF EXISTS trigger_refresh ON waterway.updates;
-- We merge the waterways by name like the highways
-- This helps to drop not important rivers (since they do not have a name)
-- and also makes it possible to filter out too short rivers
-- etldoc: osm_waterway_linestring -> osm_important_waterway_linestring
CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring AS (
DROP MATERIALIZED VIEW IF EXISTS osm_important_waterway_linestring CASCADE;
DROP MATERIALIZED VIEW IF EXISTS osm_important_waterway_linestring_gen1 CASCADE;
DROP MATERIALIZED VIEW IF EXISTS osm_important_waterway_linestring_gen2 CASCADE;
DROP MATERIALIZED VIEW IF EXISTS osm_important_waterway_linestring_gen3 CASCADE;
CREATE MATERIALIZED VIEW osm_important_waterway_linestring AS (
SELECT
(ST_Dump(geometry)).geom AS geometry,
name
name, name_en
FROM (
SELECT
ST_LineMerge(ST_Union(geometry)) AS geometry,
name
name, COALESCE(NULLIF(name_en, ''), name) AS name_en
FROM osm_waterway_linestring
WHERE name <> '' AND waterway = 'river'
GROUP BY name
GROUP BY name, name_en
) AS waterway_union
);
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_geometry_idx ON osm_important_waterway_linestring USING gist(geometry);
-- etldoc: osm_important_waterway_linestring -> osm_important_waterway_linestring_gen1
CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen1 AS (
SELECT ST_Simplify(geometry, 60) AS geometry, name
CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen1 AS (
SELECT ST_Simplify(geometry, 60) AS geometry, name, name_en
FROM osm_important_waterway_linestring
WHERE ST_Length(geometry) > 1000
);
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen1_geometry_idx ON osm_important_waterway_linestring_gen1 USING gist(geometry);
-- etldoc: osm_important_waterway_linestring_gen1 -> osm_important_waterway_linestring_gen2
CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen2 AS (
SELECT ST_Simplify(geometry, 100) AS geometry, name
CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen2 AS (
SELECT ST_Simplify(geometry, 100) AS geometry, name, name_en
FROM osm_important_waterway_linestring_gen1
WHERE ST_Length(geometry) > 4000
);
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen2_geometry_idx ON osm_important_waterway_linestring_gen2 USING gist(geometry);
-- etldoc: osm_important_waterway_linestring_gen2 -> osm_important_waterway_linestring_gen3
CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen3 AS (
SELECT ST_Simplify(geometry, 200) AS geometry, name
CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen3 AS (
SELECT ST_Simplify(geometry, 200) AS geometry, name, name_en
FROM osm_important_waterway_linestring_gen2
WHERE ST_Length(geometry) > 8000
);
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen3_geometry_idx ON osm_important_waterway_linestring_gen3 USING gist(geometry);
-- Handle updates
CREATE SCHEMA IF NOT EXISTS waterway;
CREATE TABLE IF NOT EXISTS waterway.updates(id serial primary key, t text, unique (t));
CREATE OR REPLACE FUNCTION waterway.flag() RETURNS trigger AS $$
BEGIN
INSERT INTO waterway.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
RETURN null;
END;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION waterway.refresh() RETURNS trigger AS
$BODY$
BEGIN
RAISE LOG 'Refresh waterway';
REFRESH MATERIALIZED VIEW osm_important_waterway_linestring;
REFRESH MATERIALIZED VIEW osm_important_waterway_linestring_gen1;
REFRESH MATERIALIZED VIEW osm_important_waterway_linestring_gen2;
REFRESH MATERIALIZED VIEW osm_important_waterway_linestring_gen3;
DELETE FROM waterway.updates;
RETURN null;
END;
$BODY$
language plpgsql;
CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE ON osm_waterway_linestring
FOR EACH STATEMENT
EXECUTE PROCEDURE waterway.flag();
CREATE CONSTRAINT TRIGGER trigger_refresh
AFTER INSERT ON waterway.updates
INITIALLY DEFERRED
FOR EACH ROW
EXECUTE PROCEDURE waterway.refresh();

View File

@@ -1,60 +1,66 @@
-- etldoc: ne_110m_rivers_lake_centerlines -> waterway_z3
CREATE OR REPLACE VIEW waterway_z3 AS (
SELECT geometry, 'river'::text AS class, NULL::text AS name FROM ne_110m_rivers_lake_centerlines
SELECT geometry, 'river'::text AS class, NULL::text AS name, NULL::text AS name_en
FROM ne_110m_rivers_lake_centerlines
WHERE featurecla = 'River'
);
-- etldoc: ne_50m_rivers_lake_centerlines -> waterway_z4
CREATE OR REPLACE VIEW waterway_z4 AS (
SELECT geometry, 'river'::text AS class, NULL::text AS name FROM ne_50m_rivers_lake_centerlines
SELECT geometry, 'river'::text AS class, NULL::text AS name, NULL::text AS name_en
FROM ne_50m_rivers_lake_centerlines
WHERE featurecla = 'River'
);
-- etldoc: ne_10m_rivers_lake_centerlines -> waterway_z6
CREATE OR REPLACE VIEW waterway_z6 AS (
SELECT geometry, 'river'::text AS class, NULL::text AS name FROM ne_10m_rivers_lake_centerlines
SELECT geometry, 'river'::text AS class, NULL::text AS name, NULL::text AS name_en
FROM ne_10m_rivers_lake_centerlines
WHERE featurecla = 'River'
);
-- etldoc: osm_important_waterway_linestring_gen3 -> waterway_z9
CREATE OR REPLACE VIEW waterway_z9 AS (
SELECT geometry, 'river'::text AS class, name FROM osm_important_waterway_linestring_gen3
SELECT geometry, 'river'::text AS class, name, name_en FROM osm_important_waterway_linestring_gen3
);
-- etldoc: osm_important_waterway_linestring_gen2 -> waterway_z10
CREATE OR REPLACE VIEW waterway_z10 AS (
SELECT geometry, 'river'::text AS class, name FROM osm_important_waterway_linestring_gen2
SELECT geometry, 'river'::text AS class, name, name_en FROM osm_important_waterway_linestring_gen2
);
-- etldoc:osm_important_waterway_linestring_gen1 -> waterway_z11
CREATE OR REPLACE VIEW waterway_z11 AS (
SELECT geometry, 'river'::text AS class, name FROM osm_important_waterway_linestring_gen1
SELECT geometry, 'river'::text AS class, name, name_en FROM osm_important_waterway_linestring_gen1
);
-- etldoc: osm_waterway_linestring -> waterway_z12
CREATE OR REPLACE VIEW waterway_z12 AS (
SELECT geometry, waterway AS class, name FROM osm_waterway_linestring
SELECT geometry, waterway AS class, name, name_en FROM osm_waterway_linestring
WHERE waterway IN ('river', 'canal')
);
-- etldoc: osm_waterway_linestring -> waterway_z13
CREATE OR REPLACE VIEW waterway_z13 AS (
SELECT geometry, waterway::text AS class, name FROM osm_waterway_linestring
SELECT geometry, waterway::text AS class, name, name_en FROM osm_waterway_linestring
WHERE waterway IN ('river', 'canal', 'stream', 'drain', 'ditch')
);
-- etldoc: osm_waterway_linestring -> waterway_z14
CREATE OR REPLACE VIEW waterway_z14 AS (
SELECT geometry, waterway::text AS class, name FROM osm_waterway_linestring
SELECT geometry, waterway::text AS class, name, name_en FROM osm_waterway_linestring
);
-- etldoc: layer_waterway[shape=record fillcolor=lightpink, style="rounded,filled",
-- etldoc: label="layer_waterway | <z3> z3 |<z4_5> z4-z5 |<z6_8> z6-8 | <z9> z9 |<z10> z10 |<z11> z11 |<z12> z12|<z13> z13|<z14> z14+" ];
CREATE OR REPLACE FUNCTION layer_waterway(bbox geometry, zoom_level int)
RETURNS TABLE(geometry geometry, class text, name text) AS $$
SELECT geometry, class, NULLIF(name, '') AS name FROM (
RETURNS TABLE(geometry geometry, class text, name text, name_en text) AS $$
SELECT geometry, class,
NULLIF(name, '') AS name,
COALESCE(NULLIF(name_en, ''), name) AS name_en
FROM (
-- etldoc: waterway_z3 -> layer_waterway:z3
SELECT * FROM waterway_z3 WHERE zoom_level = 3
UNION ALL

View File

@@ -10,6 +10,7 @@ layer:
name: |
The OSM [`name`](http://wiki.openstreetmap.org/wiki/Key:name) value of the waterway.
The `name` field may be empty for NaturalEarth data or at lower zoom levels.
name_en: The english `name:en` value if available.
class:
description: |
The original value of the [`waterway`](http://wiki.openstreetmap.org/wiki/Key:waterway) tag.
@@ -21,7 +22,7 @@ layer:
- ditch
datasource:
geometry_field: geometry
query: (SELECT geometry, name, class FROM layer_waterway(!bbox!, z(!scale_denominator!))) AS t
query: (SELECT geometry, name, name_en, class FROM layer_waterway(!bbox!, z(!scale_denominator!))) AS t
schema:
- ./merge_waterway.sql
- ./waterway.sql