Skip to content

Commit

Permalink
Improved update performance of mountain_peak layer
Browse files Browse the repository at this point in the history
  * 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
  • Loading branch information
benedikt-brandtner-bikemap committed Mar 19, 2023
1 parent 22ec9c1 commit 6193e2d
Show file tree
Hide file tree
Showing 2 changed files with 18 additions and 16 deletions.
17 changes: 9 additions & 8 deletions layers/mountain_peak/update_mountain_linestring.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand All @@ -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;
Expand All @@ -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;
Expand All @@ -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();
Expand Down
17 changes: 9 additions & 8 deletions layers/mountain_peak/update_peak_point.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand All @@ -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;
Expand All @@ -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;
Expand All @@ -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();
Expand Down

0 comments on commit 6193e2d

Please sign in to comment.