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 #725. It addresses #814 and a part of #809.
79 lines
2.4 KiB
PL/PgSQL
79 lines
2.4 KiB
PL/PgSQL
DROP TRIGGER IF EXISTS trigger_delete_point ON osm_water_polygon;
|
|
DROP TRIGGER IF EXISTS trigger_update_point ON osm_water_polygon;
|
|
DROP TRIGGER IF EXISTS trigger_insert_point ON osm_water_polygon;
|
|
|
|
CREATE OR REPLACE VIEW osm_water_point_view AS
|
|
SELECT
|
|
wp.osm_id, ST_PointOnSurface(wp.geometry) AS geometry,
|
|
wp.name, wp.name_en, wp.name_de,
|
|
update_tags(wp.tags, ST_PointOnSurface(wp.geometry)) AS tags,
|
|
ST_Area(wp.geometry) AS area,
|
|
wp.is_intermittent
|
|
FROM osm_water_polygon AS wp
|
|
LEFT JOIN lake_centerline ll ON wp.osm_id = ll.osm_id
|
|
WHERE ll.osm_id IS NULL AND wp.name <> ''
|
|
;
|
|
|
|
-- etldoc: osm_water_polygon -> osm_water_point
|
|
-- etldoc: lake_centerline -> osm_water_point
|
|
CREATE TABLE IF NOT EXISTS osm_water_point AS
|
|
SELECT * FROM osm_water_point_view;
|
|
DO $$
|
|
BEGIN
|
|
ALTER TABLE osm_water_point ADD CONSTRAINT osm_water_point_pk PRIMARY KEY (osm_id);
|
|
EXCEPTION WHEN others then
|
|
RAISE NOTICE 'primary key osm_water_point_pk already exists in osm_water_point.';
|
|
END;
|
|
$$;
|
|
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 OR REPLACE FUNCTION water_point.delete() RETURNS trigger AS $BODY$
|
|
BEGIN
|
|
DELETE FROM osm_water_point
|
|
WHERE osm_water_point.osm_id = OLD.osm_id ;
|
|
|
|
RETURN null;
|
|
END;
|
|
$BODY$ language plpgsql;
|
|
|
|
CREATE OR REPLACE FUNCTION water_point.update() RETURNS trigger AS $BODY$
|
|
BEGIN
|
|
UPDATE osm_water_point
|
|
SET (osm_id, geometry, name, name_en, name_de, tags, area, is_intermittent) =
|
|
(SELECT * FROM osm_water_point_view WHERE osm_water_point_view.osm_id = NEW.osm_id)
|
|
WHERE osm_water_point.osm_id = NEW.osm_id;
|
|
|
|
RETURN null;
|
|
END;
|
|
$BODY$ language plpgsql;
|
|
|
|
CREATE OR REPLACE FUNCTION water_point.insert() RETURNS trigger AS $BODY$
|
|
BEGIN
|
|
INSERT INTO osm_water_point
|
|
SELECT *
|
|
FROM osm_water_point_view
|
|
WHERE osm_water_point_view.osm_id = NEW.osm_id;
|
|
|
|
RETURN null;
|
|
END;
|
|
$BODY$ language plpgsql;
|
|
|
|
CREATE TRIGGER trigger_delete_point
|
|
AFTER DELETE ON osm_water_polygon
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE water_point.delete();
|
|
|
|
CREATE TRIGGER trigger_update_point
|
|
AFTER UPDATE ON osm_water_polygon
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE water_point.update();
|
|
|
|
CREATE TRIGGER trigger_insert_point
|
|
AFTER INSERT ON osm_water_polygon
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE water_point.insert();
|