Skip to content

Commit 82616ea

Browse files
authored
Make update_city_point use incremental update #814 (#951)
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) to 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. It is a based on the already merged #944 It is a separated PR as less obvious than previous. It replaces the reset of the `rank` field to NULL by missing value resulting of `LEFT JOIN`. It avoid triggering a new update on the table by reset the value then re-seting it to initial or new value. It addresses #814. Thanks @frodrigo
1 parent bb2a432 commit 82616ea

File tree

1 file changed

+41
-17
lines changed

1 file changed

+41
-17
lines changed

layers/place/update_city_point.sql

+41-17
Original file line numberDiff line numberDiff line change
@@ -1,24 +1,27 @@
11
DROP TRIGGER IF EXISTS trigger_flag ON osm_city_point;
2+
DROP TRIGGER IF EXISTS trigger_store ON osm_city_point;
23
DROP TRIGGER IF EXISTS trigger_refresh ON place_city.updates;
34

45
CREATE EXTENSION IF NOT EXISTS unaccent;
56

6-
CREATE OR REPLACE FUNCTION update_osm_city_point() RETURNS void AS
7-
$$
8-
BEGIN
7+
CREATE SCHEMA IF NOT EXISTS place_city;
98

10-
-- Clear OSM key:rank ( https://github.com/openmaptiles/openmaptiles/issues/108 )
11-
-- etldoc: osm_city_point -> osm_city_point
12-
UPDATE osm_city_point AS osm SET "rank" = NULL WHERE "rank" IS NOT NULL;
9+
CREATE TABLE IF NOT EXISTS place_city.osm_ids
10+
(
11+
osm_id bigint
12+
);
1313

14+
CREATE OR REPLACE FUNCTION update_osm_city_point(full_update boolean) RETURNS void AS
15+
$$
1416
-- etldoc: ne_10m_populated_places -> osm_city_point
1517
-- etldoc: osm_city_point -> osm_city_point
1618

1719
WITH important_city_point AS (
18-
SELECT osm.geometry, osm.osm_id, osm.name, osm.name_en, ne.scalerank, ne.labelrank
19-
FROM ne_10m_populated_places AS ne,
20-
osm_city_point AS osm
21-
WHERE (
20+
SELECT osm.osm_id, ne.scalerank
21+
FROM osm_city_point AS osm
22+
-- Clear OSM key:rank ( https://github.com/openmaptiles/openmaptiles/issues/108 )
23+
LEFT JOIN ne_10m_populated_places AS ne ON
24+
(
2225
(osm.tags ? 'wikidata' AND osm.tags->'wikidata' = ne.wikidataid) OR
2326
lower(osm.name) IN (lower(ne.name), lower(ne.namealt), lower(ne.meganame), lower(ne.gn_ascii), lower(ne.nameascii)) OR
2427
lower(osm.name_en) IN (lower(ne.name), lower(ne.namealt), lower(ne.meganame), lower(ne.gn_ascii), lower(ne.nameascii)) OR
@@ -32,22 +35,35 @@ BEGIN
3235
-- are in the scalerank 5 bucket
3336
SET "rank" = CASE WHEN scalerank <= 5 THEN scalerank + 1 ELSE scalerank END
3437
FROM important_city_point AS ne
35-
WHERE osm.osm_id = ne.osm_id;
38+
WHERE (full_update OR osm.osm_id IN (SELECT osm_id FROM place_city.osm_ids))
39+
AND rank IS DISTINCT FROM CASE WHEN scalerank <= 5 THEN scalerank + 1 ELSE scalerank END
40+
AND osm.osm_id = ne.osm_id;
3641

3742
UPDATE osm_city_point
3843
SET tags = update_tags(tags, geometry)
39-
WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL;
44+
WHERE (full_update OR osm_id IN (SELECT osm_id FROM place_city.osm_ids))
45+
AND COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL
46+
AND tags != update_tags(tags, geometry);
4047

41-
END;
42-
$$ LANGUAGE plpgsql;
48+
$$ LANGUAGE SQL;
4349

44-
SELECT update_osm_city_point();
50+
SELECT update_osm_city_point(true);
4551

4652
CREATE INDEX IF NOT EXISTS osm_city_point_rank_idx ON osm_city_point ("rank");
4753

4854
-- Handle updates
4955

50-
CREATE SCHEMA IF NOT EXISTS place_city;
56+
CREATE OR REPLACE FUNCTION place_city.store() RETURNS trigger AS
57+
$$
58+
BEGIN
59+
IF (tg_op = 'DELETE') THEN
60+
INSERT INTO place_city.osm_ids VALUES (OLD.osm_id);
61+
ELSE
62+
INSERT INTO place_city.osm_ids VALUES (NEW.osm_id);
63+
END IF;
64+
RETURN NULL;
65+
END;
66+
$$ LANGUAGE plpgsql;
5167

5268
CREATE TABLE IF NOT EXISTS place_city.updates
5369
(
@@ -67,13 +83,21 @@ CREATE OR REPLACE FUNCTION place_city.refresh() RETURNS trigger AS
6783
$$
6884
BEGIN
6985
RAISE LOG 'Refresh place_city rank';
70-
PERFORM update_osm_city_point();
86+
PERFORM update_osm_city_point(false);
87+
-- noinspection SqlWithoutWhere
88+
DELETE FROM place_city.osm_ids;
7189
-- noinspection SqlWithoutWhere
7290
DELETE FROM place_city.updates;
7391
RETURN NULL;
7492
END;
7593
$$ LANGUAGE plpgsql;
7694

95+
CREATE TRIGGER trigger_store
96+
AFTER INSERT OR UPDATE OR DELETE
97+
ON osm_city_point
98+
FOR EACH ROW
99+
EXECUTE PROCEDURE place_city.store();
100+
77101
CREATE TRIGGER trigger_flag
78102
AFTER INSERT OR UPDATE OR DELETE
79103
ON osm_city_point

0 commit comments

Comments
 (0)