Skip to content

Commit 97216c5

Browse files
authored
Replace materialized view of water by tables with diff update (openmaptiles#853)
Replacing materialized view by a tables with update from trigger on change only. Start with the most simple cases. Just replicate the change on: * `osm_water_polygon` to `osm_water_lakeline`, * `osm_water_polygon` to `osm_water_point`. Use a view to factorize the `osm_water_lakeline` and `osm_water_point_view` definition and reuse it in the trigger. The update of `osm_important_waterway_linestring` is more complex, as it is a merge of `osm_waterway_linestring`. It not done in the same way. At the end of the transaction we remove impacted and recompute them. The goal is to update more quickly the content of derivated table by just updating the changing content. It replaces the update of materialized view because their need a full recompute (with lock issue). Note, an advanced version of differential update over materialized view as already implemented in the building cluster PR openmaptiles#725. It addresses openmaptiles#814 and a part of openmaptiles#809.
1 parent be75e76 commit 97216c5

File tree

3 files changed

+229
-83
lines changed

3 files changed

+229
-83
lines changed
+57-32
Original file line numberDiff line numberDiff line change
@@ -1,11 +1,8 @@
1-
DROP TRIGGER IF EXISTS trigger_flag_line ON osm_water_polygon;
2-
DROP TRIGGER IF EXISTS trigger_refresh ON water_lakeline.updates;
1+
DROP TRIGGER IF EXISTS trigger_delete_line ON osm_water_polygon;
2+
DROP TRIGGER IF EXISTS trigger_update_line ON osm_water_polygon;
3+
DROP TRIGGER IF EXISTS trigger_insert_line ON osm_water_polygon;
34

4-
-- etldoc: osm_water_polygon -> osm_water_lakeline
5-
-- etldoc: lake_centerline -> osm_water_lakeline
6-
DROP MATERIALIZED VIEW IF EXISTS osm_water_lakeline CASCADE;
7-
8-
CREATE MATERIALIZED VIEW osm_water_lakeline AS (
5+
CREATE OR REPLACE VIEW osm_water_lakeline_view AS
96
SELECT wp.osm_id,
107
ll.wkb_geometry AS geometry,
118
name, name_en, name_de,
@@ -15,39 +12,67 @@ CREATE MATERIALIZED VIEW osm_water_lakeline AS (
1512
FROM osm_water_polygon AS wp
1613
INNER JOIN lake_centerline ll ON wp.osm_id = ll.osm_id
1714
WHERE wp.name <> '' AND ST_IsValid(wp.geometry)
18-
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
15+
;
16+
17+
-- etldoc: osm_water_polygon -> osm_water_lakeline
18+
-- etldoc: lake_centerline -> osm_water_lakeline
19+
CREATE TABLE IF NOT EXISTS osm_water_lakeline AS
20+
SELECT * FROM osm_water_lakeline_view;
21+
DO $$
22+
BEGIN
23+
ALTER TABLE osm_water_lakeline ADD CONSTRAINT osm_water_lakeline_pk PRIMARY KEY (osm_id);
24+
EXCEPTION WHEN others then
25+
RAISE NOTICE 'primary key osm_water_lakeline_pk already exists in osm_water_lakeline.';
26+
END;
27+
$$;
1928
CREATE INDEX IF NOT EXISTS osm_water_lakeline_geometry_idx ON osm_water_lakeline USING gist(geometry);
2029

2130
-- Handle updates
2231

2332
CREATE SCHEMA IF NOT EXISTS water_lakeline;
2433

25-
CREATE TABLE IF NOT EXISTS water_lakeline.updates(id serial primary key, t text, unique (t));
26-
CREATE OR REPLACE FUNCTION water_lakeline.flag() RETURNS trigger AS $$
34+
CREATE OR REPLACE FUNCTION water_lakeline.delete() RETURNS trigger AS $BODY$
2735
BEGIN
28-
INSERT INTO water_lakeline.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
36+
DELETE FROM osm_water_lakeline
37+
WHERE osm_water_lakeline.osm_id = OLD.osm_id ;
38+
2939
RETURN null;
3040
END;
31-
$$ language plpgsql;
32-
33-
CREATE OR REPLACE FUNCTION water_lakeline.refresh() RETURNS trigger AS
34-
$BODY$
35-
BEGIN
36-
RAISE LOG 'Refresh water_lakeline';
37-
REFRESH MATERIALIZED VIEW osm_water_lakeline;
38-
DELETE FROM water_lakeline.updates;
41+
$BODY$ language plpgsql;
42+
43+
CREATE OR REPLACE FUNCTION water_lakeline.update() RETURNS trigger AS $BODY$
44+
BEGIN
45+
UPDATE osm_water_lakeline
46+
SET (osm_id, geometry, name, name_en, name_de, tags, area, is_intermittent) =
47+
(SELECT * FROM osm_water_lakeline_view WHERE osm_water_lakeline_view.osm_id = NEW.osm_id)
48+
WHERE osm_water_lakeline.osm_id = NEW.osm_id;
49+
3950
RETURN null;
40-
END;
41-
$BODY$
42-
language plpgsql;
43-
44-
CREATE TRIGGER trigger_flag_line
45-
AFTER INSERT OR UPDATE OR DELETE ON osm_water_polygon
46-
FOR EACH STATEMENT
47-
EXECUTE PROCEDURE water_lakeline.flag();
48-
49-
CREATE CONSTRAINT TRIGGER trigger_refresh
50-
AFTER INSERT ON water_lakeline.updates
51-
INITIALLY DEFERRED
51+
END;
52+
$BODY$ language plpgsql;
53+
54+
CREATE OR REPLACE FUNCTION water_lakeline.insert() RETURNS trigger AS $BODY$
55+
BEGIN
56+
INSERT INTO osm_water_lakeline
57+
SELECT *
58+
FROM osm_water_lakeline_view
59+
WHERE osm_water_lakeline_view.osm_id = NEW.osm_id;
60+
61+
RETURN null;
62+
END;
63+
$BODY$ language plpgsql;
64+
65+
CREATE TRIGGER trigger_delete_line
66+
AFTER DELETE ON osm_water_polygon
67+
FOR EACH ROW
68+
EXECUTE PROCEDURE water_lakeline.delete();
69+
70+
CREATE TRIGGER trigger_update_line
71+
AFTER UPDATE ON osm_water_polygon
72+
FOR EACH ROW
73+
EXECUTE PROCEDURE water_lakeline.update();
74+
75+
CREATE TRIGGER trigger_insert_line
76+
AFTER INSERT ON osm_water_polygon
5277
FOR EACH ROW
53-
EXECUTE PROCEDURE water_lakeline.refresh();
78+
EXECUTE PROCEDURE water_lakeline.insert();
+57-32
Original file line numberDiff line numberDiff line change
@@ -1,11 +1,8 @@
1-
DROP TRIGGER IF EXISTS trigger_flag_point ON osm_water_polygon;
2-
DROP TRIGGER IF EXISTS trigger_refresh ON water_point.updates;
1+
DROP TRIGGER IF EXISTS trigger_delete_point ON osm_water_polygon;
2+
DROP TRIGGER IF EXISTS trigger_update_point ON osm_water_polygon;
3+
DROP TRIGGER IF EXISTS trigger_insert_point ON osm_water_polygon;
34

4-
-- etldoc: osm_water_polygon -> osm_water_point
5-
-- etldoc: lake_centerline -> osm_water_point
6-
DROP MATERIALIZED VIEW IF EXISTS osm_water_point CASCADE;
7-
8-
CREATE MATERIALIZED VIEW osm_water_point AS (
5+
CREATE OR REPLACE VIEW osm_water_point_view AS
96
SELECT
107
wp.osm_id, ST_PointOnSurface(wp.geometry) AS geometry,
118
wp.name, wp.name_en, wp.name_de,
@@ -15,39 +12,67 @@ CREATE MATERIALIZED VIEW osm_water_point AS (
1512
FROM osm_water_polygon AS wp
1613
LEFT JOIN lake_centerline ll ON wp.osm_id = ll.osm_id
1714
WHERE ll.osm_id IS NULL AND wp.name <> ''
18-
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
15+
;
16+
17+
-- etldoc: osm_water_polygon -> osm_water_point
18+
-- etldoc: lake_centerline -> osm_water_point
19+
CREATE TABLE IF NOT EXISTS osm_water_point AS
20+
SELECT * FROM osm_water_point_view;
21+
DO $$
22+
BEGIN
23+
ALTER TABLE osm_water_point ADD CONSTRAINT osm_water_point_pk PRIMARY KEY (osm_id);
24+
EXCEPTION WHEN others then
25+
RAISE NOTICE 'primary key osm_water_point_pk already exists in osm_water_point.';
26+
END;
27+
$$;
1928
CREATE INDEX IF NOT EXISTS osm_water_point_geometry_idx ON osm_water_point USING gist (geometry);
2029

2130
-- Handle updates
2231

2332
CREATE SCHEMA IF NOT EXISTS water_point;
2433

25-
CREATE TABLE IF NOT EXISTS water_point.updates(id serial primary key, t text, unique (t));
26-
CREATE OR REPLACE FUNCTION water_point.flag() RETURNS trigger AS $$
34+
CREATE OR REPLACE FUNCTION water_point.delete() RETURNS trigger AS $BODY$
2735
BEGIN
28-
INSERT INTO water_point.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
36+
DELETE FROM osm_water_point
37+
WHERE osm_water_point.osm_id = OLD.osm_id ;
38+
2939
RETURN null;
3040
END;
31-
$$ language plpgsql;
32-
33-
CREATE OR REPLACE FUNCTION water_point.refresh() RETURNS trigger AS
34-
$BODY$
35-
BEGIN
36-
RAISE LOG 'Refresh water_point';
37-
REFRESH MATERIALIZED VIEW osm_water_point;
38-
DELETE FROM water_point.updates;
41+
$BODY$ language plpgsql;
42+
43+
CREATE OR REPLACE FUNCTION water_point.update() RETURNS trigger AS $BODY$
44+
BEGIN
45+
UPDATE osm_water_point
46+
SET (osm_id, geometry, name, name_en, name_de, tags, area, is_intermittent) =
47+
(SELECT * FROM osm_water_point_view WHERE osm_water_point_view.osm_id = NEW.osm_id)
48+
WHERE osm_water_point.osm_id = NEW.osm_id;
49+
3950
RETURN null;
40-
END;
41-
$BODY$
42-
language plpgsql;
43-
44-
CREATE TRIGGER trigger_flag_point
45-
AFTER INSERT OR UPDATE OR DELETE ON osm_water_polygon
46-
FOR EACH STATEMENT
47-
EXECUTE PROCEDURE water_point.flag();
48-
49-
CREATE CONSTRAINT TRIGGER trigger_refresh
50-
AFTER INSERT ON water_point.updates
51-
INITIALLY DEFERRED
51+
END;
52+
$BODY$ language plpgsql;
53+
54+
CREATE OR REPLACE FUNCTION water_point.insert() RETURNS trigger AS $BODY$
55+
BEGIN
56+
INSERT INTO osm_water_point
57+
SELECT *
58+
FROM osm_water_point_view
59+
WHERE osm_water_point_view.osm_id = NEW.osm_id;
60+
61+
RETURN null;
62+
END;
63+
$BODY$ language plpgsql;
64+
65+
CREATE TRIGGER trigger_delete_point
66+
AFTER DELETE ON osm_water_polygon
67+
FOR EACH ROW
68+
EXECUTE PROCEDURE water_point.delete();
69+
70+
CREATE TRIGGER trigger_update_point
71+
AFTER UPDATE ON osm_water_polygon
72+
FOR EACH ROW
73+
EXECUTE PROCEDURE water_point.update();
74+
75+
CREATE TRIGGER trigger_insert_point
76+
AFTER INSERT ON osm_water_polygon
5277
FOR EACH ROW
53-
EXECUTE PROCEDURE water_point.refresh();
78+
EXECUTE PROCEDURE water_point.insert();

0 commit comments

Comments
 (0)