From 1126e30d0d274e27d9b6b0cf47c5ffca1595a885 Mon Sep 17 00:00:00 2001 From: benedikt-brandtner-bikemap Date: Wed, 22 Mar 2023 12:13:05 +0100 Subject: [PATCH] Improved update performance of mountain_peak layer (#1508) Improved update performance of mountain_peak layer - Refactored IDs to be unique in mountain_linestring.osm_ids and mountain_peak_point.osm_ids - Restricted updates to INSERT and UPDATE operations during mountain_linestring.refresh and mountain_peak_point.refresh - Added analyze statements before update queries during mountain_linestring.refresh and mountain_peak_point.refresh --- .../update_mountain_linestring.sql | 17 +++++++++-------- layers/mountain_peak/update_peak_point.sql | 17 +++++++++-------- 2 files changed, 18 insertions(+), 16 deletions(-) diff --git a/layers/mountain_peak/update_mountain_linestring.sql b/layers/mountain_peak/update_mountain_linestring.sql index 760c2742..4862ff8b 100644 --- a/layers/mountain_peak/update_mountain_linestring.sql +++ b/layers/mountain_peak/update_mountain_linestring.sql @@ -6,7 +6,7 @@ CREATE SCHEMA IF NOT EXISTS mountain_linestring; CREATE TABLE IF NOT EXISTS mountain_linestring.osm_ids ( - osm_id bigint + osm_id bigint PRIMARY KEY ); -- etldoc: osm_mountain_linestring -> osm_mountain_linestring @@ -26,11 +26,7 @@ SELECT update_osm_mountain_linestring(true); CREATE OR REPLACE FUNCTION mountain_linestring.store() RETURNS trigger AS $$ BEGIN - IF (tg_op = 'DELETE') THEN - INSERT INTO mountain_linestring.osm_ids VALUES (OLD.osm_id); - ELSE - INSERT INTO mountain_linestring.osm_ids VALUES (NEW.osm_id); - END IF; + INSERT INTO mountain_linestring.osm_ids VALUES (NEW.osm_id) ON CONFLICT (osm_id) DO NOTHING; RETURN NULL; END; $$ LANGUAGE plpgsql; @@ -55,6 +51,11 @@ DECLARE t TIMESTAMP WITH TIME ZONE := clock_timestamp(); BEGIN RAISE LOG 'Refresh mountain_linestring'; + + -- Analyze tracking and source tables before performing update + ANALYZE mountain_linestring.osm_ids; + ANALYZE osm_mountain_linestring; + PERFORM update_osm_mountain_linestring(false); -- noinspection SqlWithoutWhere DELETE FROM mountain_linestring.osm_ids; @@ -67,13 +68,13 @@ END; $$ LANGUAGE plpgsql; CREATE TRIGGER trigger_store - AFTER INSERT OR UPDATE OR DELETE + AFTER INSERT OR UPDATE ON osm_mountain_linestring FOR EACH ROW EXECUTE PROCEDURE mountain_linestring.store(); CREATE TRIGGER trigger_flag - AFTER INSERT OR UPDATE OR DELETE + AFTER INSERT OR UPDATE ON osm_mountain_linestring FOR EACH STATEMENT EXECUTE PROCEDURE mountain_linestring.flag(); diff --git a/layers/mountain_peak/update_peak_point.sql b/layers/mountain_peak/update_peak_point.sql index cda77f3d..73465387 100644 --- a/layers/mountain_peak/update_peak_point.sql +++ b/layers/mountain_peak/update_peak_point.sql @@ -6,7 +6,7 @@ CREATE SCHEMA IF NOT EXISTS mountain_peak_point; CREATE TABLE IF NOT EXISTS mountain_peak_point.osm_ids ( - osm_id bigint + osm_id bigint PRIMARY KEY ); -- etldoc: osm_peak_point -> osm_peak_point @@ -26,11 +26,7 @@ SELECT update_osm_peak_point(true); CREATE OR REPLACE FUNCTION mountain_peak_point.store() RETURNS trigger AS $$ BEGIN - 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; + INSERT INTO mountain_peak_point.osm_ids VALUES (NEW.osm_id) ON CONFLICT (osm_id) DO NOTHING; RETURN NULL; END; $$ LANGUAGE plpgsql; @@ -55,6 +51,11 @@ DECLARE t TIMESTAMP WITH TIME ZONE := clock_timestamp(); BEGIN RAISE LOG 'Refresh mountain_peak_point'; + + -- Analyze tracking and source tables before performing update + ANALYZE mountain_peak_point.osm_ids; + ANALYZE osm_peak_point; + PERFORM update_osm_peak_point(false); -- noinspection SqlWithoutWhere DELETE FROM mountain_peak_point.osm_ids; @@ -67,13 +68,13 @@ END; $$ LANGUAGE plpgsql; CREATE TRIGGER trigger_store - AFTER INSERT OR UPDATE OR DELETE + AFTER INSERT OR UPDATE ON osm_peak_point FOR EACH ROW EXECUTE PROCEDURE mountain_peak_point.store(); CREATE TRIGGER trigger_flag - AFTER INSERT OR UPDATE OR DELETE + AFTER INSERT OR UPDATE ON osm_peak_point FOR EACH STATEMENT EXECUTE PROCEDURE mountain_peak_point.flag();