Refactor schema, one _gen_z view per zoom. (#1045)

* Refactor layer aeroway.

* Refactor layer boundary.

* Refactor layer landcover.

* Refactor layer landuse.

* Refactor layer park.

* Refactor layer transportation.

* Refactor layer water.

* Refactor layer waterway.

* Re-generate water* layers etl_diagrams.

* Regenerate etl_diagrams for waterway.

* Cast NULL to text.
This commit is contained in:
Adam Laža
2020-11-26 13:54:00 +01:00
committed by GitHub
parent 0c6fe2d9ba
commit 77f5d76e37
29 changed files with 1819 additions and 1063 deletions

View File

@@ -36,41 +36,50 @@ FROM (
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_names ON osm_important_waterway_linestring (name);
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 OR REPLACE VIEW osm_important_waterway_linestring_gen1_view AS
SELECT ST_Simplify(geometry, 60) AS geometry, name, name_en, name_de, tags
-- etldoc: osm_important_waterway_linestring -> osm_important_waterway_linestring_gen_z11
DROP MATERIALIZED VIEW IF EXISTS osm_important_waterway_linestring_gen_z11 CASCADE;
CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen_z11 AS
(
SELECT ST_Simplify(geometry, ZRes(12)) AS geometry,
name,
name_en,
name_de,
tags
FROM osm_important_waterway_linestring
WHERE ST_Length(geometry) > 1000;
WHERE ST_Length(geometry) > 1000
);
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen_z11_name_idx ON osm_important_waterway_linestring_gen_z11 (name);
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen_z11_geometry_idx ON osm_important_waterway_linestring_gen_z11 USING gist (geometry);
CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen1 AS
SELECT *
FROM osm_important_waterway_linestring_gen1_view;
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen1_name_idx ON osm_important_waterway_linestring_gen1 (name);
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_gen_z11 -> osm_important_waterway_linestring_gen_z10
DROP MATERIALIZED VIEW IF EXISTS osm_important_waterway_linestring_gen_z10 CASCADE;
CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen_z10 AS
(
SELECT ST_Simplify(geometry, ZRes(11)) AS geometry,
name,
name_en,
name_de,
tags
FROM osm_important_waterway_linestring_gen_z11
WHERE ST_Length(geometry) > 4000
);
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen_z10_name_idx ON osm_important_waterway_linestring_gen_z10 (name);
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen_z10_geometry_idx ON osm_important_waterway_linestring_gen_z10 USING gist (geometry);
-- etldoc: osm_important_waterway_linestring_gen1 -> osm_important_waterway_linestring_gen2
CREATE OR REPLACE VIEW osm_important_waterway_linestring_gen2_view AS
SELECT ST_Simplify(geometry, 100) AS geometry, name, name_en, name_de, tags
FROM osm_important_waterway_linestring_gen1
WHERE ST_Length(geometry) > 4000;
CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen2 AS
SELECT *
FROM osm_important_waterway_linestring_gen2_view;
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen2_name_idx ON osm_important_waterway_linestring_gen2 (name);
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 OR REPLACE VIEW osm_important_waterway_linestring_gen3_view AS
SELECT ST_Simplify(geometry, 200) AS geometry, name, name_en, name_de, tags
FROM osm_important_waterway_linestring_gen2
WHERE ST_Length(geometry) > 8000;
CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen3 AS
SELECT *
FROM osm_important_waterway_linestring_gen3_view;
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen3_name_idx ON osm_important_waterway_linestring_gen3 (name);
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen3_geometry_idx ON osm_important_waterway_linestring_gen3 USING gist (geometry);
-- etldoc: osm_important_waterway_linestring_gen_z10 -> osm_important_waterway_linestring_gen_z9
DROP MATERIALIZED VIEW IF EXISTS osm_important_waterway_linestring_gen_z9 CASCADE;
CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen_z9 AS
(
SELECT ST_Simplify(geometry, ZRes(10)) AS geometry,
name,
name_en,
name_de,
tags
FROM osm_important_waterway_linestring_gen_z10
WHERE ST_Length(geometry) > 8000
);
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen_z9_name_idx ON osm_important_waterway_linestring_gen_z9 (name);
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen_z9_geometry_idx ON osm_important_waterway_linestring_gen_z9 USING gist (geometry);
-- Handle updates
@@ -178,47 +187,14 @@ BEGIN
GROUP BY w.name, w.name_en, w.name_de, slice_language_tags(w.tags)
) AS waterway_union;
-- REFRESH sm_important_waterway_linestring_gen1
DELETE
FROM osm_important_waterway_linestring_gen1 AS w
USING changes_compact AS c
WHERE w.name = c.name
AND w.name_en IS NOT DISTINCT FROM c.name_en
AND w.name_de IS NOT DISTINCT FROM c.name_de
AND w.tags IS NOT DISTINCT FROM c.tags;
-- REFRESH osm_important_waterway_linestring_gen_z11
REFRESH MATERIALIZED VIEW osm_important_waterway_linestring_gen_z11;
INSERT INTO osm_important_waterway_linestring_gen1
SELECT w.*
FROM osm_important_waterway_linestring_gen1_view AS w
NATURAL JOIN changes_compact AS c;
-- REFRESH osm_important_waterway_linestring_gen_z10
REFRESH MATERIALIZED VIEW osm_important_waterway_linestring_gen_z10;
-- REFRESH osm_important_waterway_linestring_gen2
DELETE
FROM osm_important_waterway_linestring_gen2 AS w
USING changes_compact AS c
WHERE w.name = c.name
AND w.name_en IS NOT DISTINCT FROM c.name_en
AND w.name_de IS NOT DISTINCT FROM c.name_de
AND w.tags IS NOT DISTINCT FROM c.tags;
INSERT INTO osm_important_waterway_linestring_gen2
SELECT w.*
FROM osm_important_waterway_linestring_gen2_view AS w
NATURAL JOIN changes_compact AS c;
-- REFRESH osm_important_waterway_linestring_gen3
DELETE
FROM osm_important_waterway_linestring_gen3 AS w
USING changes_compact AS c
WHERE w.name = c.name
AND w.name_en IS NOT DISTINCT FROM c.name_en
AND w.name_de IS NOT DISTINCT FROM c.name_de
AND w.tags IS NOT DISTINCT FROM c.tags;
INSERT INTO osm_important_waterway_linestring_gen3
SELECT w.*
FROM osm_important_waterway_linestring_gen3_view AS w
NATURAL JOIN changes_compact AS c;
-- REFRESH osm_important_waterway_linestring_gen_z9
REFRESH MATERIALIZED VIEW osm_important_waterway_linestring_gen_z9;
DROP TABLE changes_compact;
-- noinspection SqlWithoutWhere