Make more simple incremental update (#944)

Replacing update on the whole table with an update only on changed rows.

The goal is to update more quickly by just updating the changing content.
The update now focus on osm_id of changed rows, it use index. Add a where clause tags != update_tags(tags, geometry) en ensure only update when changed.

It requires one more trigger and a table to store changed osm_id.

The UPDATE is keep in a function to be reusable for initial setup and trigger update.

I try many code layout before done it in this way with the goal to keep the code for initial pass and for update. It should have low impact on initial data load. Better performance for row update can be achieve with BEFORE UPDATE, but require to duplicate the logic.

It is not based on the already merged https://github.com/openmaptiles/openmaptiles/pull/896 because calling and update within a function for each updated row was not efficient for larger table (like housenumber).

It addresses #814.


* Remake update_peak_point use incremental update #814

* Make update_aerodrome_label_point use incremental update #814

* Make housenumber_centroid use incremental update #814

* Make update_continent_point use incremental update #814

* Make update_island_point use incremental update #814

* Make update_island_polygon use incremental update #814

* Remove dead code in update_state_point.sql

* Make update_state_point use incremental update #814

* Remove dead code in update_country_point.sql

* Make update_country_point use incremental update #814

* Make osm_poi_polygon use incremental update #814

Thanks @frodrigo
This commit is contained in:
Frédéric Rodrigo 2020-08-28 11:03:27 +02:00 committed by GitHub
parent 10efc29280
commit bb2a4328f3
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
9 changed files with 372 additions and 109 deletions

View File

@ -1,25 +1,44 @@
DROP TRIGGER IF EXISTS trigger_flag ON osm_aerodrome_label_point; DROP TRIGGER IF EXISTS trigger_flag ON osm_aerodrome_label_point;
DROP TRIGGER IF EXISTS trigger_store ON osm_aerodrome_label_point;
DROP TRIGGER IF EXISTS trigger_refresh ON aerodrome_label.updates; DROP TRIGGER IF EXISTS trigger_refresh ON aerodrome_label.updates;
CREATE SCHEMA IF NOT EXISTS aerodrome_label;
CREATE TABLE IF NOT EXISTS aerodrome_label.osm_ids
(
osm_id bigint
);
-- etldoc: osm_aerodrome_label_point -> osm_aerodrome_label_point -- etldoc: osm_aerodrome_label_point -> osm_aerodrome_label_point
CREATE OR REPLACE FUNCTION update_aerodrome_label_point() RETURNS void AS CREATE OR REPLACE FUNCTION update_aerodrome_label_point(full_update boolean) RETURNS void AS
$$ $$
BEGIN
UPDATE osm_aerodrome_label_point UPDATE osm_aerodrome_label_point
SET geometry = ST_Centroid(geometry) SET geometry = ST_Centroid(geometry)
WHERE ST_GeometryType(geometry) <> 'ST_Point'; WHERE (full_update OR osm_id IN (SELECT osm_id FROM aerodrome_label.osm_ids))
AND ST_GeometryType(geometry) <> 'ST_Point';
UPDATE osm_aerodrome_label_point UPDATE osm_aerodrome_label_point
SET tags = update_tags(tags, geometry) SET tags = update_tags(tags, geometry)
WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; WHERE (full_update OR osm_id IN (SELECT osm_id FROM aerodrome_label.osm_ids))
END; AND COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL
$$ LANGUAGE plpgsql; AND tags = update_tags(tags, geometry);
$$ LANGUAGE SQL;
SELECT update_aerodrome_label_point(); SELECT update_aerodrome_label_point(true);
-- Handle updates -- Handle updates
CREATE SCHEMA IF NOT EXISTS aerodrome_label; CREATE OR REPLACE FUNCTION aerodrome_label.store() RETURNS trigger AS
$$
BEGIN
IF (tg_op = 'DELETE') THEN
INSERT INTO aerodrome_label.osm_ids VALUES (OLD.osm_id);
ELSE
INSERT INTO aerodrome_label.osm_ids VALUES (NEW.osm_id);
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TABLE IF NOT EXISTS aerodrome_label.updates CREATE TABLE IF NOT EXISTS aerodrome_label.updates
( (
@ -39,13 +58,21 @@ CREATE OR REPLACE FUNCTION aerodrome_label.refresh() RETURNS trigger AS
$$ $$
BEGIN BEGIN
RAISE LOG 'Refresh aerodrome_label'; RAISE LOG 'Refresh aerodrome_label';
PERFORM update_aerodrome_label_point(); PERFORM update_aerodrome_label_point(false);
-- noinspection SqlWithoutWhere
DELETE FROM aerodrome_label.osm_ids;
-- noinspection SqlWithoutWhere -- noinspection SqlWithoutWhere
DELETE FROM aerodrome_label.updates; DELETE FROM aerodrome_label.updates;
RETURN NULL; RETURN NULL;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE TRIGGER trigger_store
AFTER INSERT OR UPDATE OR DELETE
ON osm_aerodrome_label_point
FOR EACH ROW
EXECUTE PROCEDURE aerodrome_label.store();
CREATE TRIGGER trigger_flag CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE AFTER INSERT OR UPDATE OR DELETE
ON osm_aerodrome_label_point ON osm_aerodrome_label_point

View File

@ -1,10 +1,17 @@
DROP TRIGGER IF EXISTS trigger_flag ON osm_housenumber_point; DROP TRIGGER IF EXISTS trigger_flag ON osm_housenumber_point;
DROP TRIGGER IF EXISTS trigger_store ON osm_housenumber_point;
DROP TRIGGER IF EXISTS trigger_refresh ON housenumber.updates; DROP TRIGGER IF EXISTS trigger_refresh ON housenumber.updates;
CREATE SCHEMA IF NOT EXISTS housenumber;
CREATE TABLE IF NOT EXISTS housenumber.osm_ids
(
osm_id bigint
);
-- etldoc: osm_housenumber_point -> osm_housenumber_point -- etldoc: osm_housenumber_point -> osm_housenumber_point
CREATE OR REPLACE FUNCTION convert_housenumber_point() RETURNS void AS CREATE OR REPLACE FUNCTION convert_housenumber_point(full_update boolean) RETURNS void AS
$$ $$
BEGIN
UPDATE osm_housenumber_point UPDATE osm_housenumber_point
SET geometry = SET geometry =
CASE CASE
@ -12,15 +19,25 @@ BEGIN
THEN ST_Centroid(geometry) THEN ST_Centroid(geometry)
ELSE ST_PointOnSurface(geometry) ELSE ST_PointOnSurface(geometry)
END END
WHERE ST_GeometryType(geometry) <> 'ST_Point'; WHERE (full_update OR osm_id IN (SELECT osm_id FROM housenumber.osm_ids))
END; AND ST_GeometryType(geometry) <> 'ST_Point';
$$ LANGUAGE plpgsql; $$ LANGUAGE SQL;
SELECT convert_housenumber_point(); SELECT convert_housenumber_point(true);
-- Handle updates -- Handle updates
CREATE SCHEMA IF NOT EXISTS housenumber; CREATE OR REPLACE FUNCTION housenumber.store() RETURNS trigger AS
$$
BEGIN
IF (tg_op = 'DELETE') THEN
INSERT INTO housenumber.osm_ids VALUES (OLD.osm_id);
ELSE
INSERT INTO housenumber.osm_ids VALUES (NEW.osm_id);
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TABLE IF NOT EXISTS housenumber.updates CREATE TABLE IF NOT EXISTS housenumber.updates
( (
@ -40,13 +57,21 @@ CREATE OR REPLACE FUNCTION housenumber.refresh() RETURNS trigger AS
$$ $$
BEGIN BEGIN
RAISE LOG 'Refresh housenumber'; RAISE LOG 'Refresh housenumber';
PERFORM convert_housenumber_point(); PERFORM convert_housenumber_point(false);
-- noinspection SqlWithoutWhere
DELETE FROM housenumber.osm_ids;
-- noinspection SqlWithoutWhere -- noinspection SqlWithoutWhere
DELETE FROM housenumber.updates; DELETE FROM housenumber.updates;
RETURN NULL; RETURN NULL;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE TRIGGER trigger_store
AFTER INSERT OR UPDATE OR DELETE
ON osm_housenumber_point
FOR EACH ROW
EXECUTE PROCEDURE housenumber.store();
CREATE TRIGGER trigger_flag CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE AFTER INSERT OR UPDATE OR DELETE
ON osm_housenumber_point ON osm_housenumber_point

View File

@ -1,32 +1,82 @@
DROP TRIGGER IF EXISTS trigger_update_point ON osm_peak_point; DROP TRIGGER IF EXISTS trigger_flag ON osm_peak_point;
DROP TRIGGER IF EXISTS trigger_store ON osm_peak_point;
DROP TRIGGER IF EXISTS trigger_refresh ON mountain_peak_point.updates;
CREATE SCHEMA IF NOT EXISTS mountain_peak_point;
CREATE TABLE IF NOT EXISTS mountain_peak_point.osm_ids
(
osm_id bigint
);
-- etldoc: osm_peak_point -> osm_peak_point -- etldoc: osm_peak_point -> osm_peak_point
CREATE OR REPLACE FUNCTION update_osm_peak_point(new_osm_id bigint) RETURNS void AS CREATE OR REPLACE FUNCTION update_osm_peak_point(full_update boolean) RETURNS void AS
$$ $$
UPDATE osm_peak_point UPDATE osm_peak_point
SET tags = update_tags(tags, geometry) SET tags = update_tags(tags, geometry)
WHERE (new_osm_id IS NULL OR osm_id = new_osm_id) WHERE (full_update OR osm_id IN (SELECT osm_id FROM mountain_peak_point.osm_ids))
AND COALESCE(tags -> 'name:latin', tags -> 'name:nonlatin', tags -> 'name_int') IS NULL AND COALESCE(tags -> 'name:latin', tags -> 'name:nonlatin', tags -> 'name_int') IS NULL
AND tags != update_tags(tags, geometry) AND tags != update_tags(tags, geometry)
$$ LANGUAGE SQL; $$ LANGUAGE SQL;
SELECT update_osm_peak_point(NULL); SELECT update_osm_peak_point(true);
-- Handle updates -- Handle updates
CREATE SCHEMA IF NOT EXISTS mountain_peak_point; CREATE OR REPLACE FUNCTION mountain_peak_point.store() RETURNS trigger AS
CREATE OR REPLACE FUNCTION mountain_peak_point.update() RETURNS trigger AS
$$ $$
BEGIN BEGIN
PERFORM update_osm_peak_point(new.osm_id); IF (tg_op = 'DELETE') THEN
INSERT INTO mountain_peak_point.osm_ids VALUES (OLD.osm_id);
ELSE
INSERT INTO mountain_peak_point.osm_ids VALUES (NEW.osm_id);
END IF;
RETURN NULL; RETURN NULL;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE CONSTRAINT TRIGGER trigger_update_point CREATE TABLE IF NOT EXISTS mountain_peak_point.updates
AFTER INSERT OR UPDATE (
id serial PRIMARY KEY,
t text,
UNIQUE (t)
);
CREATE OR REPLACE FUNCTION mountain_peak_point.flag() RETURNS trigger AS
$$
BEGIN
INSERT INTO mountain_peak_point.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION mountain_peak_point.refresh() RETURNS trigger AS
$$
BEGIN
RAISE LOG 'Refresh mountain_peak_point';
PERFORM update_osm_peak_point(false);
-- noinspection SqlWithoutWhere
DELETE FROM mountain_peak_point.osm_ids;
-- noinspection SqlWithoutWhere
DELETE FROM mountain_peak_point.updates;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER trigger_store
AFTER INSERT OR UPDATE OR DELETE
ON osm_peak_point ON osm_peak_point
FOR EACH ROW
EXECUTE PROCEDURE mountain_peak_point.store();
CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE
ON osm_peak_point
FOR EACH STATEMENT
EXECUTE PROCEDURE mountain_peak_point.flag();
CREATE CONSTRAINT TRIGGER trigger_refresh
AFTER INSERT
ON mountain_peak_point.updates
INITIALLY DEFERRED INITIALLY DEFERRED
FOR EACH ROW FOR EACH ROW
EXECUTE PROCEDURE mountain_peak_point.update(); EXECUTE PROCEDURE mountain_peak_point.refresh();

View File

@ -1,22 +1,39 @@
DROP TRIGGER IF EXISTS trigger_flag ON osm_continent_point; DROP TRIGGER IF EXISTS trigger_flag ON osm_continent_point;
DROP TRIGGER IF EXISTS trigger_store ON osm_continent_point;
DROP TRIGGER IF EXISTS trigger_refresh ON place_continent_point.updates; DROP TRIGGER IF EXISTS trigger_refresh ON place_continent_point.updates;
CREATE SCHEMA IF NOT EXISTS place_continent_point;
CREATE TABLE IF NOT EXISTS place_continent_point.osm_ids
(
osm_id bigint
);
-- etldoc: osm_continent_point -> osm_continent_point -- etldoc: osm_continent_point -> osm_continent_point
CREATE OR REPLACE FUNCTION update_osm_continent_point() RETURNS void AS CREATE OR REPLACE FUNCTION update_osm_continent_point(full_update boolean) RETURNS void AS
$$ $$
BEGIN
UPDATE osm_continent_point UPDATE osm_continent_point
SET tags = update_tags(tags, geometry) SET tags = update_tags(tags, geometry)
WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; WHERE (full_update OR osm_id IN (SELECT osm_id FROM place_continent_point.osm_ids))
AND COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL
AND tags != update_tags(tags, geometry);
$$ LANGUAGE SQL;
END; SELECT update_osm_continent_point(true);
$$ LANGUAGE plpgsql;
SELECT update_osm_continent_point();
-- Handle updates -- Handle updates
CREATE SCHEMA IF NOT EXISTS place_continent_point; CREATE OR REPLACE FUNCTION place_continent_point.store() RETURNS trigger AS
$$
BEGIN
IF (tg_op = 'DELETE') THEN
INSERT INTO place_continent_point.osm_ids VALUES (OLD.osm_id);
ELSE
INSERT INTO place_continent_point.osm_ids VALUES (NEW.osm_id);
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TABLE IF NOT EXISTS place_continent_point.updates CREATE TABLE IF NOT EXISTS place_continent_point.updates
( (
@ -36,13 +53,21 @@ CREATE OR REPLACE FUNCTION place_continent_point.refresh() RETURNS trigger AS
$$ $$
BEGIN BEGIN
RAISE LOG 'Refresh place_continent_point'; RAISE LOG 'Refresh place_continent_point';
PERFORM update_osm_continent_point(); PERFORM update_osm_continent_point(false);
-- noinspection SqlWithoutWhere
DELETE FROM place_continent_point.osm_ids;
-- noinspection SqlWithoutWhere -- noinspection SqlWithoutWhere
DELETE FROM place_continent_point.updates; DELETE FROM place_continent_point.updates;
RETURN NULL; RETURN NULL;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE TRIGGER trigger_store
AFTER INSERT OR UPDATE OR DELETE
ON osm_continent_point
FOR EACH ROW
EXECUTE PROCEDURE place_continent_point.store();
CREATE TRIGGER trigger_flag CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE AFTER INSERT OR UPDATE OR DELETE
ON osm_continent_point ON osm_continent_point

View File

@ -1,23 +1,28 @@
DROP TRIGGER IF EXISTS trigger_flag ON osm_country_point; DROP TRIGGER IF EXISTS trigger_flag ON osm_country_point;
DROP TRIGGER IF EXISTS trigger_store ON osm_country_point;
DROP TRIGGER IF EXISTS trigger_refresh ON place_country.updates; DROP TRIGGER IF EXISTS trigger_refresh ON place_country.updates;
ALTER TABLE osm_country_point CREATE SCHEMA IF NOT EXISTS place_country;
DROP CONSTRAINT IF EXISTS osm_country_point_rank_constraint;
CREATE TABLE IF NOT EXISTS place_country.osm_ids
(
osm_id bigint
);
-- 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 CREATE OR REPLACE FUNCTION update_osm_country_point(full_update boolean) RETURNS void AS
$$ $$
BEGIN
UPDATE osm_country_point AS osm UPDATE osm_country_point AS osm
SET "rank" = 7, SET "rank" = 7,
iso3166_1_alpha_2 = COALESCE( iso3166_1_alpha_2 = COALESCE(
NULLIF(osm.country_code_iso3166_1_alpha_2, ''), NULLIF(osm.country_code_iso3166_1_alpha_2, ''),
NULLIF(osm.iso3166_1_alpha_2, ''), NULLIF(osm.iso3166_1_alpha_2, ''),
NULLIF(osm.iso3166_1, '') NULLIF(osm.iso3166_1, '')
); )
WHERE (full_update OR osm_id IN (SELECT osm_id FROM place_country.osm_ids))
AND rank IS NULL;
WITH important_country_point AS ( WITH important_country_point AS (
SELECT osm.geometry, SELECT osm.geometry,
@ -39,7 +44,9 @@ BEGIN
-- where the ranks are still distributed uniform enough across all countries -- where the ranks are still distributed uniform enough across all countries
SET "rank" = LEAST(6, CEILING((scalerank + labelrank) / 2.0)) SET "rank" = LEAST(6, CEILING((scalerank + labelrank) / 2.0))
FROM important_country_point AS ne FROM important_country_point AS ne
WHERE osm.osm_id = ne.osm_id; WHERE (full_update OR osm.osm_id IN (SELECT osm_id FROM place_country.osm_ids))
AND rank = 7
AND osm.osm_id = ne.osm_id;
-- Repeat the step for archipelago countries like Philippines or Indonesia -- Repeat the step for archipelago countries like Philippines or Indonesia
-- whose label point is not within country's polygon -- whose label point is not within country's polygon
@ -65,33 +72,47 @@ BEGIN
-- where the ranks are still distributed uniform enough across all countries -- where the ranks are still distributed uniform enough across all countries
SET "rank" = LEAST(6, CEILING((ne.scalerank + ne.labelrank) / 2.0)) SET "rank" = LEAST(6, CEILING((ne.scalerank + ne.labelrank) / 2.0))
FROM important_country_point AS ne FROM important_country_point AS ne
WHERE osm.osm_id = ne.osm_id WHERE (full_update OR osm.osm_id IN (SELECT osm_id FROM place_country.osm_ids))
AND rank = 7
AND osm.osm_id = ne.osm_id
AND ne.rk = 1; AND ne.rk = 1;
UPDATE osm_country_point AS osm UPDATE osm_country_point AS osm
SET "rank" = 6 SET "rank" = 6
WHERE "rank" = 7; WHERE (full_update OR osm_id IN (SELECT osm_id FROM place_country.osm_ids))
AND "rank" = 7;
-- TODO: This shouldn't be necessary? The rank function makes something wrong... -- TODO: This shouldn't be necessary? The rank function makes something wrong...
UPDATE osm_country_point AS osm UPDATE osm_country_point AS osm
SET "rank" = 1 SET "rank" = 1
WHERE "rank" = 0; WHERE (full_update OR osm_id IN (SELECT osm_id FROM place_country.osm_ids))
AND "rank" = 0;
UPDATE osm_country_point UPDATE osm_country_point
SET tags = update_tags(tags, geometry) SET tags = update_tags(tags, geometry)
WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; WHERE (full_update OR osm_id IN (SELECT osm_id FROM place_country.osm_ids))
AND COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL
AND tags != update_tags(tags, geometry);
END; $$ LANGUAGE SQL;
$$ LANGUAGE plpgsql;
SELECT update_osm_country_point(); SELECT update_osm_country_point(true);
-- 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 -- Handle updates
CREATE SCHEMA IF NOT EXISTS place_country; CREATE OR REPLACE FUNCTION place_country.store() RETURNS trigger AS
$$
BEGIN
IF (tg_op = 'DELETE') THEN
INSERT INTO place_country.osm_ids VALUES (OLD.osm_id);
ELSE
INSERT INTO place_country.osm_ids VALUES (NEW.osm_id);
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TABLE IF NOT EXISTS place_country.updates CREATE TABLE IF NOT EXISTS place_country.updates
( (
@ -111,13 +132,21 @@ CREATE OR REPLACE FUNCTION place_country.refresh() RETURNS trigger AS
$$ $$
BEGIN BEGIN
RAISE LOG 'Refresh place_country rank'; RAISE LOG 'Refresh place_country rank';
PERFORM update_osm_country_point(); PERFORM update_osm_country_point(false);
-- noinspection SqlWithoutWhere
DELETE FROM place_country.osm_ids;
-- noinspection SqlWithoutWhere -- noinspection SqlWithoutWhere
DELETE FROM place_country.updates; DELETE FROM place_country.updates;
RETURN NULL; RETURN NULL;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE TRIGGER trigger_store
AFTER INSERT OR UPDATE OR DELETE
ON osm_country_point
FOR EACH ROW
EXECUTE PROCEDURE place_country.store();
CREATE TRIGGER trigger_flag CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE AFTER INSERT OR UPDATE OR DELETE
ON osm_country_point ON osm_country_point

View File

@ -1,22 +1,39 @@
DROP TRIGGER IF EXISTS trigger_flag ON osm_island_point; DROP TRIGGER IF EXISTS trigger_flag ON osm_island_point;
DROP TRIGGER IF EXISTS trigger_store ON osm_island_point;
DROP TRIGGER IF EXISTS trigger_refresh ON place_island_point.updates; DROP TRIGGER IF EXISTS trigger_refresh ON place_island_point.updates;
CREATE SCHEMA IF NOT EXISTS place_island_point;
CREATE TABLE IF NOT EXISTS place_island_point.osm_ids
(
osm_id bigint
);
-- etldoc: osm_island_point -> osm_island_point -- etldoc: osm_island_point -> osm_island_point
CREATE OR REPLACE FUNCTION update_osm_island_point() RETURNS void AS CREATE OR REPLACE FUNCTION update_osm_island_point(full_update boolean) RETURNS void AS
$$ $$
BEGIN
UPDATE osm_island_point UPDATE osm_island_point
SET tags = update_tags(tags, geometry) SET tags = update_tags(tags, geometry)
WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; WHERE (full_update OR osm_id IN (SELECT osm_id FROM place_island_point.osm_ids))
AND COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL
AND tags != update_tags(tags, geometry);
$$ LANGUAGE SQL;
END; SELECT update_osm_island_point(true);
$$ LANGUAGE plpgsql;
SELECT update_osm_island_point();
-- Handle updates -- Handle updates
CREATE SCHEMA IF NOT EXISTS place_island_point; CREATE OR REPLACE FUNCTION place_island_point.store() RETURNS trigger AS
$$
BEGIN
IF (tg_op = 'DELETE') THEN
INSERT INTO place_island_point.osm_ids VALUES (OLD.osm_id);
ELSE
INSERT INTO place_island_point.osm_ids VALUES (NEW.osm_id);
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TABLE IF NOT EXISTS place_island_point.updates CREATE TABLE IF NOT EXISTS place_island_point.updates
( (
@ -36,13 +53,21 @@ CREATE OR REPLACE FUNCTION place_island_point.refresh() RETURNS trigger AS
$$ $$
BEGIN BEGIN
RAISE LOG 'Refresh place_island_point'; RAISE LOG 'Refresh place_island_point';
PERFORM update_osm_island_point(); PERFORM update_osm_island_point(false);
-- noinspection SqlWithoutWhere
DELETE FROM place_island_point.osm_ids;
-- noinspection SqlWithoutWhere -- noinspection SqlWithoutWhere
DELETE FROM place_island_point.updates; DELETE FROM place_island_point.updates;
RETURN NULL; RETURN NULL;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE TRIGGER trigger_store
AFTER INSERT OR UPDATE OR DELETE
ON osm_island_point
FOR EACH ROW
EXECUTE PROCEDURE place_island_point.store();
CREATE TRIGGER trigger_flag CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE AFTER INSERT OR UPDATE OR DELETE
ON osm_island_point ON osm_island_point

View File

@ -1,25 +1,45 @@
DROP TRIGGER IF EXISTS trigger_flag ON osm_island_polygon; DROP TRIGGER IF EXISTS trigger_flag ON osm_island_polygon;
DROP TRIGGER IF EXISTS trigger_store ON osm_island_polygon;
DROP TRIGGER IF EXISTS trigger_refresh ON place_island_polygon.updates; DROP TRIGGER IF EXISTS trigger_refresh ON place_island_polygon.updates;
CREATE SCHEMA IF NOT EXISTS place_island_polygon;
CREATE TABLE IF NOT EXISTS place_island_polygon.osm_ids
(
osm_id bigint
);
-- etldoc: osm_island_polygon -> osm_island_polygon -- etldoc: osm_island_polygon -> osm_island_polygon
CREATE OR REPLACE FUNCTION update_osm_island_polygon() RETURNS void AS CREATE OR REPLACE FUNCTION update_osm_island_polygon(full_update boolean) RETURNS void AS
$$ $$
BEGIN UPDATE osm_island_polygon
UPDATE osm_island_polygon SET geometry=ST_PointOnSurface(geometry) WHERE ST_GeometryType(geometry) <> 'ST_Point'; SET geometry = ST_PointOnSurface(geometry)
WHERE (full_update OR osm_id IN (SELECT osm_id FROM place_island_polygon.osm_ids))
AND ST_GeometryType(geometry) <> 'ST_Point';
UPDATE osm_island_polygon UPDATE osm_island_polygon
SET tags = update_tags(tags, geometry) SET tags = update_tags(tags, geometry)
WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; WHERE (full_update OR osm_id IN (SELECT osm_id FROM place_island_polygon.osm_ids))
AND COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL
AND tags != update_tags(tags, geometry);
ANALYZE osm_island_polygon; $$ LANGUAGE SQL;
END;
$$ LANGUAGE plpgsql;
SELECT update_osm_island_polygon(); SELECT update_osm_island_polygon(true);
-- Handle updates -- Handle updates
CREATE SCHEMA IF NOT EXISTS place_island_polygon; CREATE OR REPLACE FUNCTION place_island_polygon.store() RETURNS trigger AS
$$
BEGIN
IF (tg_op = 'DELETE') THEN
INSERT INTO place_island_polygon.osm_ids VALUES (OLD.osm_id);
ELSE
INSERT INTO place_island_polygon.osm_ids VALUES (NEW.osm_id);
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TABLE IF NOT EXISTS place_island_polygon.updates CREATE TABLE IF NOT EXISTS place_island_polygon.updates
( (
@ -39,13 +59,21 @@ CREATE OR REPLACE FUNCTION place_island_polygon.refresh() RETURNS trigger AS
$$ $$
BEGIN BEGIN
RAISE LOG 'Refresh place_island_polygon'; RAISE LOG 'Refresh place_island_polygon';
PERFORM update_osm_island_polygon(); PERFORM update_osm_island_polygon(false);
-- noinspection SqlWithoutWhere
DELETE FROM place_island_polygon.osm_ids;
-- noinspection SqlWithoutWhere -- noinspection SqlWithoutWhere
DELETE FROM place_island_polygon.updates; DELETE FROM place_island_polygon.updates;
RETURN NULL; RETURN NULL;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE TRIGGER trigger_store
AFTER INSERT OR UPDATE OR DELETE
ON osm_island_polygon
FOR EACH ROW
EXECUTE PROCEDURE place_island_polygon.store();
CREATE TRIGGER trigger_flag CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE AFTER INSERT OR UPDATE OR DELETE
ON osm_island_polygon ON osm_island_polygon

View File

@ -1,16 +1,19 @@
DROP TRIGGER IF EXISTS trigger_flag ON osm_state_point; DROP TRIGGER IF EXISTS trigger_flag ON osm_state_point;
DROP TRIGGER IF EXISTS trigger_store ON osm_state_point;
DROP TRIGGER IF EXISTS trigger_refresh ON place_state.updates; DROP TRIGGER IF EXISTS trigger_refresh ON place_state.updates;
ALTER TABLE osm_state_point CREATE SCHEMA IF NOT EXISTS place_state;
DROP CONSTRAINT IF EXISTS osm_state_point_rank_constraint;
CREATE TABLE IF NOT EXISTS place_state.osm_ids
(
osm_id bigint
);
-- etldoc: ne_10m_admin_1_states_provinces -> osm_state_point -- etldoc: ne_10m_admin_1_states_provinces -> 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 CREATE OR REPLACE FUNCTION update_osm_state_point(full_update boolean) RETURNS void AS
$$ $$
BEGIN
WITH important_state_point AS ( WITH important_state_point AS (
SELECT osm.geometry, SELECT osm.geometry,
osm.osm_id, osm.osm_id,
@ -33,30 +36,45 @@ BEGIN
-- Normalize both scalerank and labelrank into a ranking system from 1 to 6. -- Normalize both scalerank and labelrank into a ranking system from 1 to 6.
SET "rank" = LEAST(6, CEILING((scalerank + labelrank + datarank) / 3.0)) SET "rank" = LEAST(6, CEILING((scalerank + labelrank + datarank) / 3.0))
FROM important_state_point AS ne FROM important_state_point AS ne
WHERE osm.osm_id = ne.osm_id; WHERE (full_update OR osm.osm_id IN (SELECT osm_id FROM place_state.osm_ids))
AND rank IS NULL
AND osm.osm_id = ne.osm_id;
-- TODO: This shouldn't be necessary? The rank function makes something wrong... -- TODO: This shouldn't be necessary? The rank function makes something wrong...
UPDATE osm_state_point AS osm UPDATE osm_state_point AS osm
SET "rank" = 1 SET "rank" = 1
WHERE "rank" = 0; WHERE (full_update OR osm_id IN (SELECT osm_id FROM place_state.osm_ids))
AND "rank" = 0;
DELETE FROM osm_state_point WHERE "rank" IS NULL; DELETE FROM osm_state_point
WHERE (full_update OR osm_id IN (SELECT osm_id FROM place_state.osm_ids))
AND "rank" IS NULL;
UPDATE osm_state_point UPDATE osm_state_point
SET tags = update_tags(tags, geometry) SET tags = update_tags(tags, geometry)
WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; WHERE (full_update OR osm_id IN (SELECT osm_id FROM place_state.osm_ids))
AND COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL
AND tags != update_tags(tags, geometry);
END; $$ LANGUAGE SQL;
$$ LANGUAGE plpgsql;
SELECT update_osm_state_point(); SELECT update_osm_state_point(true);
-- 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 -- Handle updates
CREATE SCHEMA IF NOT EXISTS place_state; CREATE OR REPLACE FUNCTION place_state.store() RETURNS trigger AS
$$
BEGIN
IF (tg_op = 'DELETE') THEN
INSERT INTO place_state.osm_ids VALUES (OLD.osm_id);
ELSE
INSERT INTO place_state.osm_ids VALUES (NEW.osm_id);
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TABLE IF NOT EXISTS place_state.updates CREATE TABLE IF NOT EXISTS place_state.updates
( (
@ -76,13 +94,21 @@ CREATE OR REPLACE FUNCTION place_state.refresh() RETURNS trigger AS
$$ $$
BEGIN BEGIN
RAISE LOG 'Refresh place_state rank'; RAISE LOG 'Refresh place_state rank';
PERFORM update_osm_state_point(); PERFORM update_osm_state_point(false);
-- noinspection SqlWithoutWhere
DELETE FROM place_state.osm_ids;
-- noinspection SqlWithoutWhere -- noinspection SqlWithoutWhere
DELETE FROM place_state.updates; DELETE FROM place_state.updates;
RETURN NULL; RETURN NULL;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE TRIGGER trigger_store
AFTER INSERT OR UPDATE OR DELETE
ON osm_state_point
FOR EACH ROW
EXECUTE PROCEDURE place_state.store();
CREATE TRIGGER trigger_flag CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE AFTER INSERT OR UPDATE OR DELETE
ON osm_state_point ON osm_state_point

View File

@ -1,11 +1,18 @@
DROP TRIGGER IF EXISTS trigger_flag ON osm_poi_polygon; DROP TRIGGER IF EXISTS trigger_flag ON osm_poi_polygon;
DROP TRIGGER IF EXISTS trigger_store ON osm_poi_polygon;
DROP TRIGGER IF EXISTS trigger_refresh ON poi_polygon.updates; DROP TRIGGER IF EXISTS trigger_refresh ON poi_polygon.updates;
CREATE SCHEMA IF NOT EXISTS poi_polygon;
CREATE TABLE IF NOT EXISTS poi_polygon.osm_ids
(
osm_id bigint
);
-- etldoc: osm_poi_polygon -> osm_poi_polygon -- etldoc: osm_poi_polygon -> osm_poi_polygon
CREATE OR REPLACE FUNCTION update_poi_polygon() RETURNS void AS CREATE OR REPLACE FUNCTION update_poi_polygon(full_update boolean) RETURNS void AS
$$ $$
BEGIN
UPDATE osm_poi_polygon UPDATE osm_poi_polygon
SET geometry = SET geometry =
CASE CASE
@ -13,31 +20,44 @@ BEGIN
THEN ST_Centroid(geometry) THEN ST_Centroid(geometry)
ELSE ST_PointOnSurface(geometry) ELSE ST_PointOnSurface(geometry)
END END
WHERE ST_GeometryType(geometry) <> 'ST_Point'; WHERE (full_update OR osm_id IN (SELECT osm_id FROM poi_polygon.osm_ids))
AND ST_GeometryType(geometry) <> 'ST_Point';
UPDATE osm_poi_polygon UPDATE osm_poi_polygon
SET subclass = 'subway' SET subclass = 'subway'
WHERE station = 'subway' WHERE (full_update OR osm_id IN (SELECT osm_id FROM poi_polygon.osm_ids))
AND station = 'subway'
AND subclass = 'station'; AND subclass = 'station';
UPDATE osm_poi_polygon UPDATE osm_poi_polygon
SET subclass = 'halt' SET subclass = 'halt'
WHERE funicular = 'yes' WHERE (full_update OR osm_id IN (SELECT osm_id FROM poi_polygon.osm_ids))
AND funicular = 'yes'
AND subclass = 'station'; AND subclass = 'station';
UPDATE osm_poi_polygon UPDATE osm_poi_polygon
SET tags = update_tags(tags, geometry) SET tags = update_tags(tags, geometry)
WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; WHERE (full_update OR osm_id IN (SELECT osm_id FROM poi_polygon.osm_ids))
AND COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL
AND tags != update_tags(tags, geometry);
ANALYZE osm_poi_polygon; $$ LANGUAGE SQL;
END;
$$ LANGUAGE plpgsql;
SELECT update_poi_polygon(); SELECT update_poi_polygon(true);
-- Handle updates -- Handle updates
CREATE SCHEMA IF NOT EXISTS poi_polygon; CREATE OR REPLACE FUNCTION poi_polygon.store() RETURNS trigger AS
$$
BEGIN
IF (tg_op = 'DELETE') THEN
INSERT INTO poi_polygon.osm_ids VALUES (OLD.osm_id);
ELSE
INSERT INTO poi_polygon.osm_ids VALUES (NEW.osm_id);
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TABLE IF NOT EXISTS poi_polygon.updates CREATE TABLE IF NOT EXISTS poi_polygon.updates
( (
@ -57,13 +77,21 @@ CREATE OR REPLACE FUNCTION poi_polygon.refresh() RETURNS trigger AS
$$ $$
BEGIN BEGIN
RAISE LOG 'Refresh poi_polygon'; RAISE LOG 'Refresh poi_polygon';
PERFORM update_poi_polygon(); PERFORM update_poi_polygon(false);
-- noinspection SqlWithoutWhere
DELETE FROM poi_polygon.osm_ids;
-- noinspection SqlWithoutWhere -- noinspection SqlWithoutWhere
DELETE FROM poi_polygon.updates; DELETE FROM poi_polygon.updates;
RETURN NULL; RETURN NULL;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE TRIGGER trigger_store
AFTER INSERT OR UPDATE OR DELETE
ON osm_poi_polygon
FOR EACH ROW
EXECUTE PROCEDURE poi_polygon.store();
CREATE TRIGGER trigger_flag CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE AFTER INSERT OR UPDATE OR DELETE
ON osm_poi_polygon ON osm_poi_polygon