Merge pull request #131 from openmaptiles/trigger_tables_sql

Daily updates
pull/134/head
Lukas Martinelli 2017-01-16 09:38:47 +01:00 zatwierdzone przez GitHub
commit 2d586bb47a
10 zmienionych plików z 522 dodań i 115 usunięć

Wyświetl plik

@ -1,4 +1,45 @@
DROP TRIGGER IF EXISTS trigger_flag ON osm_housenumber_point;
DROP TRIGGER IF EXISTS trigger_refresh ON housenumber.updates;
-- etldoc: osm_housenumber_point -> osm_housenumber_point -- etldoc: osm_housenumber_point -> osm_housenumber_point
UPDATE osm_housenumber_point SET geometry=topoint(geometry) CREATE OR REPLACE FUNCTION convert_housenumber_point() RETURNS VOID AS $$
WHERE ST_GeometryType(geometry) <> 'ST_Point'; BEGIN
UPDATE osm_housenumber_point SET geometry=topoint(geometry) WHERE ST_GeometryType(geometry) <> 'ST_Point';
END;
$$ LANGUAGE plpgsql;
SELECT convert_housenumber_point();
-- Handle updates
CREATE SCHEMA IF NOT EXISTS housenumber;
CREATE TABLE IF NOT EXISTS housenumber.updates(id serial primary key, t text, unique (t));
CREATE OR REPLACE FUNCTION housenumber.flag() RETURNS trigger AS $$
BEGIN
INSERT INTO housenumber.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
RETURN null;
END;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION housenumber.refresh() RETURNS trigger AS
$BODY$
BEGIN
RAISE LOG 'Refresh housenumber';
PERFORM convert_housenumber_point();
DELETE FROM housenumber.updates;
RETURN null;
END;
$BODY$
language plpgsql;
CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE ON osm_housenumber_point
FOR EACH STATEMENT
EXECUTE PROCEDURE housenumber.flag();
CREATE CONSTRAINT TRIGGER trigger_refresh
AFTER INSERT ON housenumber.updates
INITIALLY DEFERRED
FOR EACH ROW
EXECUTE PROCEDURE housenumber.refresh();

Wyświetl plik

@ -1,5 +1,46 @@
-- etldoc: osm_island_polygon -> osm_island_polygon DROP TRIGGER IF EXISTS trigger_flag ON osm_island_polygon;
UPDATE osm_island_polygon SET geometry=topoint(geometry) DROP TRIGGER IF EXISTS trigger_refresh ON place_island.updates;
WHERE ST_GeometryType(geometry) <> 'ST_Point';
-- etldoc: osm_island_polygon -> osm_island_polygon
CREATE OR REPLACE FUNCTION convert_island_polygon_point() RETURNS VOID AS $$
BEGIN
UPDATE osm_island_polygon SET geometry=topoint(geometry) WHERE ST_GeometryType(geometry) <> 'ST_Point';
ANALYZE osm_island_polygon; ANALYZE osm_island_polygon;
END;
$$ LANGUAGE plpgsql;
SELECT convert_island_polygon_point();
-- Handle updates
CREATE SCHEMA IF NOT EXISTS place_island;
CREATE TABLE IF NOT EXISTS place_island.updates(id serial primary key, t text, unique (t));
CREATE OR REPLACE FUNCTION place_island.flag() RETURNS trigger AS $$
BEGIN
INSERT INTO place_island.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
RETURN null;
END;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION place_island.refresh() RETURNS trigger AS
$BODY$
BEGIN
RAISE LOG 'Refresh place_island';
PERFORM convert_island_polygon_point();
DELETE FROM place_island.updates;
RETURN null;
END;
$BODY$
language plpgsql;
CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE ON osm_island_polygon
FOR EACH STATEMENT
EXECUTE PROCEDURE place_island.flag();
CREATE CONSTRAINT TRIGGER trigger_refresh
AFTER INSERT ON place_island.updates
INITIALLY DEFERRED
FOR EACH ROW
EXECUTE PROCEDURE place_island.refresh();

Wyświetl plik

@ -1,6 +1,11 @@
DROP TRIGGER IF EXISTS trigger_flag ON osm_city_point;
DROP TRIGGER IF EXISTS trigger_refresh ON place_city.updates;
CREATE EXTENSION IF NOT EXISTS unaccent; CREATE EXTENSION IF NOT EXISTS unaccent;
CREATE OR REPLACE FUNCTION update_osm_city_point() RETURNS VOID AS $$
BEGIN
-- Clear OSM key:rank ( https://github.com/openmaptiles/openmaptiles/issues/108 ) -- Clear OSM key:rank ( https://github.com/openmaptiles/openmaptiles/issues/108 )
-- etldoc: osm_city_point -> osm_city_point -- etldoc: osm_city_point -> osm_city_point
UPDATE osm_city_point AS osm SET "rank" = NULL WHERE "rank" IS NOT NULL; UPDATE osm_city_point AS osm SET "rank" = NULL WHERE "rank" IS NOT NULL;
@ -35,4 +40,43 @@ SET "rank" = CASE WHEN scalerank <= 5 THEN scalerank + 1 ELSE scalerank END
FROM important_city_point AS ne FROM important_city_point AS ne
WHERE osm.osm_id = ne.osm_id; WHERE osm.osm_id = ne.osm_id;
END;
$$ LANGUAGE plpgsql;
SELECT update_osm_city_point();
CREATE INDEX IF NOT EXISTS osm_city_point_rank_idx ON osm_city_point("rank"); CREATE INDEX IF NOT EXISTS osm_city_point_rank_idx ON osm_city_point("rank");
-- Handle updates
CREATE SCHEMA IF NOT EXISTS place_city;
CREATE TABLE IF NOT EXISTS place_city.updates(id serial primary key, t text, unique (t));
CREATE OR REPLACE FUNCTION place_city.flag() RETURNS trigger AS $$
BEGIN
INSERT INTO place_city.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
RETURN null;
END;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION place_city.refresh() RETURNS trigger AS
$BODY$
BEGIN
RAISE LOG 'Refresh place_city rank';
PERFORM update_osm_city_point();
DELETE FROM place_city.updates;
RETURN null;
END;
$BODY$
language plpgsql;
CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE ON osm_city_point
FOR EACH STATEMENT
EXECUTE PROCEDURE place_city.flag();
CREATE CONSTRAINT TRIGGER trigger_refresh
AFTER INSERT ON place_city.updates
INITIALLY DEFERRED
FOR EACH ROW
EXECUTE PROCEDURE place_city.refresh();

Wyświetl plik

@ -1,8 +1,14 @@
DROP TRIGGER IF EXISTS trigger_flag ON osm_country_point;
DROP TRIGGER IF EXISTS trigger_refresh ON place_country.updates;
ALTER TABLE osm_country_point DROP CONSTRAINT IF EXISTS osm_country_point_rank_constraint; ALTER TABLE osm_country_point DROP CONSTRAINT IF EXISTS osm_country_point_rank_constraint;
-- etldoc: ne_10m_admin_0_countries -> osm_country_point -- etldoc: ne_10m_admin_0_countries -> osm_country_point
-- etldoc: osm_country_point -> osm_country_point -- etldoc: osm_country_point -> osm_country_point
CREATE OR REPLACE FUNCTION update_osm_country_point() RETURNS VOID AS $$
BEGIN
WITH important_country_point AS ( WITH important_country_point AS (
SELECT osm.geometry, osm.osm_id, osm.name, COALESCE(NULLIF(osm.name_en, ''), ne.name) AS name_en, ne.scalerank, ne.labelrank SELECT osm.geometry, osm.osm_id, osm.name, COALESCE(NULLIF(osm.name_en, ''), ne.name) AS name_en, ne.scalerank, ne.labelrank
FROM ne_10m_admin_0_countries AS ne, osm_country_point AS osm FROM ne_10m_admin_0_countries AS ne, osm_country_point AS osm
@ -30,5 +36,44 @@ UPDATE osm_country_point AS osm
SET "rank" = 1 SET "rank" = 1
WHERE "rank" = 0; WHERE "rank" = 0;
ALTER TABLE osm_country_point ADD CONSTRAINT osm_country_point_rank_constraint CHECK("rank" BETWEEN 1 AND 6); END;
$$ LANGUAGE plpgsql;
SELECT update_osm_country_point();
-- ALTER TABLE osm_country_point ADD CONSTRAINT osm_country_point_rank_constraint CHECK("rank" BETWEEN 1 AND 6);
CREATE INDEX IF NOT EXISTS osm_country_point_rank_idx ON osm_country_point("rank"); CREATE INDEX IF NOT EXISTS osm_country_point_rank_idx ON osm_country_point("rank");
-- Handle updates
CREATE SCHEMA IF NOT EXISTS place_country;
CREATE TABLE IF NOT EXISTS place_country.updates(id serial primary key, t text, unique (t));
CREATE OR REPLACE FUNCTION place_country.flag() RETURNS trigger AS $$
BEGIN
INSERT INTO place_country.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
RETURN null;
END;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION place_country.refresh() RETURNS trigger AS
$BODY$
BEGIN
RAISE LOG 'Refresh place_country rank';
PERFORM update_osm_country_point();
DELETE FROM place_country.updates;
RETURN null;
END;
$BODY$
language plpgsql;
CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE ON osm_country_point
FOR EACH STATEMENT
EXECUTE PROCEDURE place_country.flag();
CREATE CONSTRAINT TRIGGER trigger_refresh
AFTER INSERT ON place_country.updates
INITIALLY DEFERRED
FOR EACH ROW
EXECUTE PROCEDURE place_country.refresh();

Wyświetl plik

@ -1,8 +1,14 @@
DROP TRIGGER IF EXISTS trigger_flag ON osm_state_point;
DROP TRIGGER IF EXISTS trigger_refresh ON place_state.updates;
ALTER TABLE osm_state_point DROP CONSTRAINT IF EXISTS osm_state_point_rank_constraint; ALTER TABLE osm_state_point DROP CONSTRAINT IF EXISTS osm_state_point_rank_constraint;
-- etldoc: ne_10m_admin_1_states_provinces_shp -> osm_state_point -- etldoc: ne_10m_admin_1_states_provinces_shp -> osm_state_point
-- etldoc: osm_state_point -> osm_state_point -- etldoc: osm_state_point -> osm_state_point
CREATE OR REPLACE FUNCTION update_osm_state_point() RETURNS VOID AS $$
BEGIN
WITH important_state_point AS ( WITH important_state_point AS (
SELECT osm.geometry, osm.osm_id, osm.name, COALESCE(NULLIF(osm.name_en, ''), ne.name) AS name_en, ne.scalerank, ne.labelrank, ne.datarank SELECT osm.geometry, osm.osm_id, osm.name, COALESCE(NULLIF(osm.name_en, ''), ne.name) AS name_en, ne.scalerank, ne.labelrank, ne.datarank
FROM ne_10m_admin_1_states_provinces_shp AS ne, osm_state_point AS osm FROM ne_10m_admin_1_states_provinces_shp AS ne, osm_state_point AS osm
@ -26,5 +32,44 @@ WHERE "rank" = 0;
DELETE FROM osm_state_point WHERE "rank" IS NULL; DELETE FROM osm_state_point WHERE "rank" IS NULL;
ALTER TABLE osm_state_point ADD CONSTRAINT osm_state_point_rank_constraint CHECK("rank" BETWEEN 1 AND 6); END;
$$ LANGUAGE plpgsql;
SELECT update_osm_state_point();
-- ALTER TABLE osm_state_point ADD CONSTRAINT osm_state_point_rank_constraint CHECK("rank" BETWEEN 1 AND 6);
CREATE INDEX IF NOT EXISTS osm_state_point_rank_idx ON osm_state_point("rank"); CREATE INDEX IF NOT EXISTS osm_state_point_rank_idx ON osm_state_point("rank");
-- Handle updates
CREATE SCHEMA IF NOT EXISTS place_state;
CREATE TABLE IF NOT EXISTS place_state.updates(id serial primary key, t text, unique (t));
CREATE OR REPLACE FUNCTION place_state.flag() RETURNS trigger AS $$
BEGIN
INSERT INTO place_state.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
RETURN null;
END;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION place_state.refresh() RETURNS trigger AS
$BODY$
BEGIN
RAISE LOG 'Refresh place_state rank';
PERFORM update_osm_state_point();
DELETE FROM place_state.updates;
RETURN null;
END;
$BODY$
language plpgsql;
CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE ON osm_state_point
FOR EACH STATEMENT
EXECUTE PROCEDURE place_state.flag();
CREATE CONSTRAINT TRIGGER trigger_refresh
AFTER INSERT ON place_state.updates
INITIALLY DEFERRED
FOR EACH ROW
EXECUTE PROCEDURE place_state.refresh();

Wyświetl plik

@ -1,5 +1,47 @@
-- etldoc: osm_poi_polygon -> osm_poi_polygon DROP TRIGGER IF EXISTS trigger_flag ON osm_poi_polygon;
UPDATE osm_poi_polygon SET geometry=topoint(geometry) DROP TRIGGER IF EXISTS trigger_refresh ON poi.updates;
WHERE ST_GeometryType(geometry) <> 'ST_Point';
-- etldoc: osm_poi_polygon -> osm_poi_polygon
CREATE OR REPLACE FUNCTION convert_poi_point() RETURNS VOID AS $$
BEGIN
UPDATE osm_poi_polygon SET geometry=topoint(geometry) WHERE ST_GeometryType(geometry) <> 'ST_Point';
ANALYZE osm_poi_polygon; ANALYZE osm_poi_polygon;
END;
$$ LANGUAGE plpgsql;
SELECT convert_poi_point();
-- Handle updates
CREATE SCHEMA IF NOT EXISTS poi;
CREATE TABLE IF NOT EXISTS poi.updates(id serial primary key, t text, unique (t));
CREATE OR REPLACE FUNCTION poi.flag() RETURNS trigger AS $$
BEGIN
INSERT INTO poi.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
RETURN null;
END;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION poi.refresh() RETURNS trigger AS
$BODY$
BEGIN
RAISE LOG 'Refresh poi';
PERFORM convert_poi_point();
DELETE FROM poi.updates;
RETURN null;
END;
$BODY$
language plpgsql;
CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE ON osm_poi_polygon
FOR EACH STATEMENT
EXECUTE PROCEDURE poi.flag();
CREATE CONSTRAINT TRIGGER trigger_refresh
AFTER INSERT ON poi.updates
INITIALLY DEFERRED
FOR EACH ROW
EXECUTE PROCEDURE poi.refresh();

Wyświetl plik

@ -1,16 +1,18 @@
DROP TRIGGER IF EXISTS trigger_flag ON osm_highway_linestring;
DROP TABLE IF EXISTS osm_transportation_name_linestring CASCADE; DROP TRIGGER IF EXISTS trigger_refresh ON transportation_name.updates;
DROP TABLE IF EXISTS osm_transportation_name_linestring_gen1 CASCADE;
DROP TABLE IF EXISTS osm_transportation_name_linestring_gen2 CASCADE;
DROP TABLE IF EXISTS osm_transportation_name_linestring_gen3 CASCADE;
-- Instead of using relations to find out the road names we -- Instead of using relations to find out the road names we
-- stitch together the touching ways with the same name -- stitch together the touching ways with the same name
-- to allow for nice label rendering -- to allow for nice label rendering
-- Because this works well for roads that do not have relations as well -- Because this works well for roads that do not have relations as well
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_linestring CASCADE;
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_linestring_gen1 CASCADE;
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_linestring_gen2 CASCADE;
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_linestring_gen3 CASCADE;
-- etldoc: osm_highway_linestring -> osm_transportation_name_linestring -- etldoc: osm_highway_linestring -> osm_transportation_name_linestring
CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring AS ( CREATE MATERIALIZED VIEW osm_transportation_name_linestring AS (
SELECT SELECT
(ST_Dump(geometry)).geom AS geometry, (ST_Dump(geometry)).geom AS geometry,
-- NOTE: The osm_id is no longer the original one which can make it difficult -- NOTE: The osm_id is no longer the original one which can make it difficult
@ -35,11 +37,10 @@ CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring AS (
GROUP BY name, highway, ref GROUP BY name, highway, ref
) AS highway_union ) AS highway_union
); );
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_geometry_idx ON osm_transportation_name_linestring USING gist(geometry); CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_geometry_idx ON osm_transportation_name_linestring USING gist(geometry);
-- etldoc: osm_transportation_name_linestring -> osm_transportation_name_linestring_gen1 -- etldoc: osm_transportation_name_linestring -> osm_transportation_name_linestring_gen1
CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen1 AS ( CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen1 AS (
SELECT ST_Simplify(geometry, 50) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order SELECT ST_Simplify(geometry, 50) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order
FROM osm_transportation_name_linestring FROM osm_transportation_name_linestring
WHERE highway IN ('motorway','trunk') AND ST_Length(geometry) > 8000 WHERE highway IN ('motorway','trunk') AND ST_Length(geometry) > 8000
@ -47,7 +48,7 @@ CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen1 AS (
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen1_geometry_idx ON osm_transportation_name_linestring_gen1 USING gist(geometry); CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen1_geometry_idx ON osm_transportation_name_linestring_gen1 USING gist(geometry);
-- etldoc: osm_transportation_name_linestring_gen1 -> osm_transportation_name_linestring_gen2 -- etldoc: osm_transportation_name_linestring_gen1 -> osm_transportation_name_linestring_gen2
CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen2 AS ( CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen2 AS (
SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order
FROM osm_transportation_name_linestring_gen1 FROM osm_transportation_name_linestring_gen1
WHERE highway IN ('motorway','trunk') AND ST_Length(geometry) > 14000 WHERE highway IN ('motorway','trunk') AND ST_Length(geometry) > 14000
@ -55,9 +56,46 @@ CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen2 AS (
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen2_geometry_idx ON osm_transportation_name_linestring_gen2 USING gist(geometry); CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen2_geometry_idx ON osm_transportation_name_linestring_gen2 USING gist(geometry);
-- etldoc: osm_transportation_name_linestring_gen2 -> osm_transportation_name_linestring_gen3 -- etldoc: osm_transportation_name_linestring_gen2 -> osm_transportation_name_linestring_gen3
CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen3 AS ( CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen3 AS (
SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order
FROM osm_transportation_name_linestring_gen2 FROM osm_transportation_name_linestring_gen2
WHERE highway = 'motorway' AND ST_Length(geometry) > 20000 WHERE highway = 'motorway' AND ST_Length(geometry) > 20000
); );
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen3_geometry_idx ON osm_transportation_name_linestring_gen3 USING gist(geometry); CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen3_geometry_idx ON osm_transportation_name_linestring_gen3 USING gist(geometry);
-- Handle updates
CREATE SCHEMA IF NOT EXISTS transportation_name;
CREATE TABLE IF NOT EXISTS transportation_name.updates(id serial primary key, t text, unique (t));
CREATE OR REPLACE FUNCTION transportation_name.flag() RETURNS trigger AS $$
BEGIN
INSERT INTO transportation_name.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
RETURN null;
END;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION transportation_name.refresh() RETURNS trigger AS
$BODY$
BEGIN
RAISE LOG 'Refresh transportation_name';
REFRESH MATERIALIZED VIEW osm_transportation_name_linestring;
REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen1;
REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen2;
REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen3;
DELETE FROM transportation_name.updates;
RETURN null;
END;
$BODY$
language plpgsql;
CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE ON osm_highway_linestring
FOR EACH STATEMENT
EXECUTE PROCEDURE transportation_name.flag();
CREATE CONSTRAINT TRIGGER trigger_refresh
AFTER INSERT ON transportation_name.updates
INITIALLY DEFERRED
FOR EACH ROW
EXECUTE PROCEDURE transportation_name.refresh();

Wyświetl plik

@ -1,9 +1,11 @@
DROP TRIGGER IF EXISTS trigger_flag_line ON osm_water_polygon;
DROP TABLE IF EXISTS osm_water_lakeline CASCADE; DROP TRIGGER IF EXISTS trigger_refresh ON water_lakeline.updates;
-- etldoc: osm_water_polygon -> osm_water_lakeline -- etldoc: osm_water_polygon -> osm_water_lakeline
-- etldoc: lake_centerline -> osm_water_lakeline -- etldoc: lake_centerline -> osm_water_lakeline
CREATE TABLE IF NOT EXISTS osm_water_lakeline AS ( DROP MATERIALIZED VIEW IF EXISTS osm_water_lakeline CASCADE;
CREATE MATERIALIZED VIEW osm_water_lakeline AS (
SELECT wp.osm_id, SELECT wp.osm_id,
ll.wkb_geometry AS geometry, ll.wkb_geometry AS geometry,
name, name_en, ST_Area(wp.geometry) AS area name, name_en, ST_Area(wp.geometry) AS area
@ -11,5 +13,38 @@ CREATE TABLE IF NOT EXISTS osm_water_lakeline AS (
INNER JOIN lake_centerline ll ON wp.osm_id = ll.osm_id INNER JOIN lake_centerline ll ON wp.osm_id = ll.osm_id
WHERE wp.name <> '' WHERE wp.name <> ''
); );
CREATE INDEX IF NOT EXISTS osm_water_lakeline_geometry_idx ON osm_water_lakeline USING gist(geometry); CREATE INDEX IF NOT EXISTS osm_water_lakeline_geometry_idx ON osm_water_lakeline USING gist(geometry);
-- Handle updates
CREATE SCHEMA IF NOT EXISTS water_lakeline;
CREATE TABLE IF NOT EXISTS water_lakeline.updates(id serial primary key, t text, unique (t));
CREATE OR REPLACE FUNCTION water_lakeline.flag() RETURNS trigger AS $$
BEGIN
INSERT INTO water_lakeline.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
RETURN null;
END;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION water_lakeline.refresh() RETURNS trigger AS
$BODY$
BEGIN
RAISE LOG 'Refresh water_lakeline';
REFRESH MATERIALIZED VIEW osm_water_lakeline;
DELETE FROM water_lakeline.updates;
RETURN null;
END;
$BODY$
language plpgsql;
CREATE TRIGGER trigger_flag_line
AFTER INSERT OR UPDATE OR DELETE ON osm_water_polygon
FOR EACH STATEMENT
EXECUTE PROCEDURE water_lakeline.flag();
CREATE CONSTRAINT TRIGGER trigger_refresh
AFTER INSERT ON water_lakeline.updates
INITIALLY DEFERRED
FOR EACH ROW
EXECUTE PROCEDURE water_lakeline.refresh();

Wyświetl plik

@ -1,9 +1,11 @@
DROP TRIGGER IF EXISTS trigger_flag_point ON osm_water_polygon;
DROP TABLE IF EXISTS osm_water_point CASCADE; DROP TRIGGER IF EXISTS trigger_refresh ON water_point.updates;
-- etldoc: osm_water_polygon -> osm_water_point -- etldoc: osm_water_polygon -> osm_water_point
-- etldoc: lake_centerline -> osm_water_point -- etldoc: lake_centerline -> osm_water_point
CREATE TABLE IF NOT EXISTS osm_water_point AS ( DROP MATERIALIZED VIEW IF EXISTS osm_water_point CASCADE;
CREATE MATERIALIZED VIEW osm_water_point AS (
SELECT SELECT
wp.osm_id, topoint(wp.geometry) AS geometry, wp.osm_id, topoint(wp.geometry) AS geometry,
wp.name, wp.name_en, ST_Area(wp.geometry) AS area wp.name, wp.name_en, ST_Area(wp.geometry) AS area
@ -11,5 +13,38 @@ CREATE TABLE IF NOT EXISTS osm_water_point AS (
LEFT JOIN lake_centerline ll ON wp.osm_id = ll.osm_id LEFT JOIN lake_centerline ll ON wp.osm_id = ll.osm_id
WHERE ll.osm_id IS NULL AND wp.name <> '' WHERE ll.osm_id IS NULL AND wp.name <> ''
); );
CREATE INDEX IF NOT EXISTS osm_water_point_geometry_idx ON osm_water_point USING gist (geometry); CREATE INDEX IF NOT EXISTS osm_water_point_geometry_idx ON osm_water_point USING gist (geometry);
-- Handle updates
CREATE SCHEMA IF NOT EXISTS water_point;
CREATE TABLE IF NOT EXISTS water_point.updates(id serial primary key, t text, unique (t));
CREATE OR REPLACE FUNCTION water_point.flag() RETURNS trigger AS $$
BEGIN
INSERT INTO water_point.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
RETURN null;
END;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION water_point.refresh() RETURNS trigger AS
$BODY$
BEGIN
RAISE LOG 'Refresh water_point';
REFRESH MATERIALIZED VIEW osm_water_point;
DELETE FROM water_point.updates;
RETURN null;
END;
$BODY$
language plpgsql;
CREATE TRIGGER trigger_flag_point
AFTER INSERT OR UPDATE OR DELETE ON osm_water_polygon
FOR EACH STATEMENT
EXECUTE PROCEDURE water_point.flag();
CREATE CONSTRAINT TRIGGER trigger_refresh
AFTER INSERT ON water_point.updates
INITIALLY DEFERRED
FOR EACH ROW
EXECUTE PROCEDURE water_point.refresh();

Wyświetl plik

@ -1,15 +1,17 @@
DROP TRIGGER IF EXISTS trigger_flag ON osm_waterway_linestring;
DROP TABLE IF EXISTS osm_important_waterway_linestring CASCADE; DROP TRIGGER IF EXISTS trigger_refresh ON waterway.updates;
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;
-- We merge the waterways by name like the highways -- We merge the waterways by name like the highways
-- This helps to drop not important rivers (since they do not have a name) -- 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 -- and also makes it possible to filter out too short rivers
-- etldoc: osm_waterway_linestring -> osm_important_waterway_linestring -- 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 SELECT
(ST_Dump(geometry)).geom AS geometry, (ST_Dump(geometry)).geom AS geometry,
name name
@ -22,11 +24,10 @@ CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring AS (
GROUP BY name GROUP BY name
) AS waterway_union ) AS waterway_union
); );
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_geometry_idx ON osm_important_waterway_linestring USING gist(geometry); 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 -- etldoc: osm_important_waterway_linestring -> osm_important_waterway_linestring_gen1
CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen1 AS ( CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen1 AS (
SELECT ST_Simplify(geometry, 60) AS geometry, name SELECT ST_Simplify(geometry, 60) AS geometry, name
FROM osm_important_waterway_linestring FROM osm_important_waterway_linestring
WHERE ST_Length(geometry) > 1000 WHERE ST_Length(geometry) > 1000
@ -34,7 +35,7 @@ CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen1 AS (
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen1_geometry_idx ON osm_important_waterway_linestring_gen1 USING gist(geometry); 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 -- etldoc: osm_important_waterway_linestring_gen1 -> osm_important_waterway_linestring_gen2
CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen2 AS ( CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen2 AS (
SELECT ST_Simplify(geometry, 100) AS geometry, name SELECT ST_Simplify(geometry, 100) AS geometry, name
FROM osm_important_waterway_linestring_gen1 FROM osm_important_waterway_linestring_gen1
WHERE ST_Length(geometry) > 4000 WHERE ST_Length(geometry) > 4000
@ -42,9 +43,49 @@ CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen2 AS (
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen2_geometry_idx ON osm_important_waterway_linestring_gen2 USING gist(geometry); 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 -- etldoc: osm_important_waterway_linestring_gen2 -> osm_important_waterway_linestring_gen3
CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen3 AS ( CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen3 AS (
SELECT ST_Simplify(geometry, 200) AS geometry, name SELECT ST_Simplify(geometry, 200) AS geometry, name
FROM osm_important_waterway_linestring_gen2 FROM osm_important_waterway_linestring_gen2
WHERE ST_Length(geometry) > 8000 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); 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();