Improved update performance of aerodrome_label layer (#1506)

Improved update performance of aerodrome_label layer
- Refactored IDs to be unique in aerodrome_label.osm_ids
- Restricted updates to INSERT and UPDATE operations during aerodrome_label.refresh
- Added analyze statements before update queries during aerodrome_label.refresh

See #1433 for more detailed discussion.
This commit is contained in:
benedikt-brandtner-bikemap 2023-03-21 18:09:32 +01:00 committed by GitHub
parent f918f4d607
commit d8a8c81f79
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23

View File

@ -12,7 +12,7 @@ CREATE SCHEMA IF NOT EXISTS aerodrome_label;
CREATE TABLE IF NOT EXISTS aerodrome_label.osm_ids CREATE TABLE IF NOT EXISTS aerodrome_label.osm_ids
( (
osm_id bigint osm_id bigint PRIMARY KEY
); );
-- etldoc: osm_aerodrome_label_point -> osm_aerodrome_label_point -- etldoc: osm_aerodrome_label_point -> osm_aerodrome_label_point
@ -48,11 +48,7 @@ SELECT update_aerodrome_label_point(true);
CREATE OR REPLACE FUNCTION aerodrome_label.store() RETURNS trigger AS CREATE OR REPLACE FUNCTION aerodrome_label.store() RETURNS trigger AS
$$ $$
BEGIN BEGIN
IF (tg_op = 'DELETE') THEN INSERT INTO aerodrome_label.osm_ids VALUES (NEW.osm_id) ON CONFLICT (osm_id) DO NOTHING;
INSERT INTO aerodrome_label.osm_ids VALUES (OLD.osm_id);
ELSE
INSERT INTO aerodrome_label.osm_ids VALUES (NEW.osm_id);
END IF;
RETURN NULL; RETURN NULL;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
@ -77,6 +73,11 @@ DECLARE
t TIMESTAMP WITH TIME ZONE := clock_timestamp(); t TIMESTAMP WITH TIME ZONE := clock_timestamp();
BEGIN BEGIN
RAISE LOG 'Refresh aerodrome_label'; RAISE LOG 'Refresh aerodrome_label';
-- Analyze tracking and source tables before performing update
ANALYZE aerodrome_label.osm_ids;
ANALYZE osm_aerodrome_label_point;
PERFORM update_aerodrome_label_point(false); PERFORM update_aerodrome_label_point(false);
-- noinspection SqlWithoutWhere -- noinspection SqlWithoutWhere
DELETE FROM aerodrome_label.osm_ids; DELETE FROM aerodrome_label.osm_ids;
@ -89,13 +90,13 @@ END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE TRIGGER trigger_store CREATE TRIGGER trigger_store
AFTER INSERT OR UPDATE OR DELETE AFTER INSERT OR UPDATE
ON osm_aerodrome_label_point ON osm_aerodrome_label_point
FOR EACH ROW FOR EACH ROW
EXECUTE PROCEDURE aerodrome_label.store(); EXECUTE PROCEDURE aerodrome_label.store();
CREATE TRIGGER trigger_flag CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE AFTER INSERT OR UPDATE
ON osm_aerodrome_label_point ON osm_aerodrome_label_point
FOR EACH STATEMENT FOR EACH STATEMENT
EXECUTE PROCEDURE aerodrome_label.flag(); EXECUTE PROCEDURE aerodrome_label.flag();