Skip to content

Commit

Permalink
Improved update performance of place layer
Browse files Browse the repository at this point in the history
  * Refactored IDs to be unique in the following tables
    * place_city.osm_ids
    * place_continent_point.osm_ids
    * place_country.osm_ids
    * place_island_point.osm_ids
    * place_island_polygon.osm_ids
    * place_state.osm_ids
  * Added analyze statements before update queries and restricted updates to INSERT and UPDATE operations during execution of the following functions
    * place_city.refresh
    * place_continent_point.refresh
    * place_country.refresh
    * place_island_point.refresh
    * place_island_polygon.refresh
    * place_state.refresh
  • Loading branch information
benedikt-brandtner-bikemap committed Mar 19, 2023
1 parent 81d29ff commit bd26527
Show file tree
Hide file tree
Showing 6 changed files with 54 additions and 48 deletions.
17 changes: 9 additions & 8 deletions layers/place/update_city_point.sql
Original file line number Diff line number Diff line change
Expand Up @@ -8,7 +8,7 @@ CREATE SCHEMA IF NOT EXISTS place_city;

CREATE TABLE IF NOT EXISTS place_city.osm_ids
(
osm_id bigint
osm_id bigint PRIMARY KEY
);

CREATE OR REPLACE FUNCTION update_osm_city_point(full_update boolean) RETURNS void AS
Expand Down Expand Up @@ -56,11 +56,7 @@ CREATE INDEX IF NOT EXISTS osm_city_point_rank_idx ON osm_city_point ("rank");
CREATE OR REPLACE FUNCTION place_city.store() RETURNS trigger AS
$$
BEGIN
IF (tg_op = 'DELETE') THEN
INSERT INTO place_city.osm_ids VALUES (OLD.osm_id);
ELSE
INSERT INTO place_city.osm_ids VALUES (NEW.osm_id);
END IF;
INSERT INTO place_city.osm_ids VALUES (NEW.osm_id) ON CONFLICT (osm_id) DO NOTHING;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
Expand All @@ -85,6 +81,11 @@ DECLARE
t TIMESTAMP WITH TIME ZONE := clock_timestamp();
BEGIN
RAISE LOG 'Refresh place_city rank';

-- Analyze tracking and source tables before performing update
ANALYZE place_city.osm_ids;
ANALYZE osm_city_point;

PERFORM update_osm_city_point(false);
-- noinspection SqlWithoutWhere
DELETE FROM place_city.osm_ids;
Expand All @@ -97,13 +98,13 @@ END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER trigger_store
AFTER INSERT OR UPDATE OR DELETE
AFTER INSERT OR UPDATE
ON osm_city_point
FOR EACH ROW
EXECUTE PROCEDURE place_city.store();

CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE
AFTER INSERT OR UPDATE
ON osm_city_point
FOR EACH STATEMENT
EXECUTE PROCEDURE place_city.flag();
Expand Down
17 changes: 9 additions & 8 deletions layers/place/update_continent_point.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,7 @@ CREATE SCHEMA IF NOT EXISTS place_continent_point;

CREATE TABLE IF NOT EXISTS place_continent_point.osm_ids
(
osm_id bigint
osm_id bigint PRIMARY KEY
);

-- etldoc: osm_continent_point -> osm_continent_point
Expand All @@ -26,11 +26,7 @@ SELECT update_osm_continent_point(true);
CREATE OR REPLACE FUNCTION place_continent_point.store() RETURNS trigger AS
$$
BEGIN
IF (tg_op = 'DELETE') THEN
INSERT INTO place_continent_point.osm_ids VALUES (OLD.osm_id);
ELSE
INSERT INTO place_continent_point.osm_ids VALUES (NEW.osm_id);
END IF;
INSERT INTO place_continent_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 place_continent_point';

-- Analyze tracking and source tables before performing update
ANALYZE place_continent_point.osm_ids;
ANALYZE osm_continent_point;

PERFORM update_osm_continent_point(false);
-- noinspection SqlWithoutWhere
DELETE FROM place_continent_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_continent_point
FOR EACH ROW
EXECUTE PROCEDURE place_continent_point.store();

CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE
AFTER INSERT OR UPDATE
ON osm_continent_point
FOR EACH STATEMENT
EXECUTE PROCEDURE place_continent_point.flag();
Expand Down
17 changes: 9 additions & 8 deletions layers/place/update_country_point.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,7 @@ CREATE SCHEMA IF NOT EXISTS place_country;

CREATE TABLE IF NOT EXISTS place_country.osm_ids
(
osm_id bigint
osm_id bigint PRIMARY KEY
);

-- etldoc: ne_10m_admin_0_countries -> osm_country_point
Expand Down Expand Up @@ -105,11 +105,7 @@ CREATE INDEX IF NOT EXISTS osm_country_point_rank_idx ON osm_country_point ("ran
CREATE OR REPLACE FUNCTION place_country.store() RETURNS trigger AS
$$
BEGIN
IF (tg_op = 'DELETE') THEN
INSERT INTO place_country.osm_ids VALUES (OLD.osm_id);
ELSE
INSERT INTO place_country.osm_ids VALUES (NEW.osm_id);
END IF;
INSERT INTO place_country.osm_ids VALUES (NEW.osm_id) ON CONFLICT (osm_id) DO NOTHING;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
Expand All @@ -134,6 +130,11 @@ DECLARE
t TIMESTAMP WITH TIME ZONE := clock_timestamp();
BEGIN
RAISE LOG 'Refresh place_country rank';

-- Analyze tracking and source tables before performing update
ANALYZE place_country.osm_ids;
ANALYZE osm_country_point;

PERFORM update_osm_country_point(false);
-- noinspection SqlWithoutWhere
DELETE FROM place_country.osm_ids;
Expand All @@ -146,13 +147,13 @@ END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER trigger_store
AFTER INSERT OR UPDATE OR DELETE
AFTER INSERT OR UPDATE
ON osm_country_point
FOR EACH ROW
EXECUTE PROCEDURE place_country.store();

CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE
AFTER INSERT OR UPDATE
ON osm_country_point
FOR EACH STATEMENT
EXECUTE PROCEDURE place_country.flag();
Expand Down
17 changes: 9 additions & 8 deletions layers/place/update_island_point.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,7 @@ CREATE SCHEMA IF NOT EXISTS place_island_point;

CREATE TABLE IF NOT EXISTS place_island_point.osm_ids
(
osm_id bigint
osm_id bigint PRIMARY KEY
);

-- etldoc: osm_island_point -> osm_island_point
Expand All @@ -26,11 +26,7 @@ SELECT update_osm_island_point(true);
CREATE OR REPLACE FUNCTION place_island_point.store() RETURNS trigger AS
$$
BEGIN
IF (tg_op = 'DELETE') THEN
INSERT INTO place_island_point.osm_ids VALUES (OLD.osm_id);
ELSE
INSERT INTO place_island_point.osm_ids VALUES (NEW.osm_id);
END IF;
INSERT INTO place_island_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 place_island_point';

-- Analyze tracking and source tables before performing update
ANALYZE place_island_point.osm_ids;
ANALYZE osm_island_point;

PERFORM update_osm_island_point(false);
-- noinspection SqlWithoutWhere
DELETE FROM place_island_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_island_point
FOR EACH ROW
EXECUTE PROCEDURE place_island_point.store();

CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE
AFTER INSERT OR UPDATE
ON osm_island_point
FOR EACH STATEMENT
EXECUTE PROCEDURE place_island_point.flag();
Expand Down
17 changes: 9 additions & 8 deletions layers/place/update_island_polygon.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,7 @@ CREATE SCHEMA IF NOT EXISTS place_island_polygon;

CREATE TABLE IF NOT EXISTS place_island_polygon.osm_ids
(
osm_id bigint
osm_id bigint PRIMARY KEY
);

-- etldoc: osm_island_polygon -> osm_island_polygon
Expand All @@ -33,11 +33,7 @@ SELECT update_osm_island_polygon(true);
CREATE OR REPLACE FUNCTION place_island_polygon.store() RETURNS trigger AS
$$
BEGIN
IF (tg_op = 'DELETE') THEN
INSERT INTO place_island_polygon.osm_ids VALUES (OLD.osm_id);
ELSE
INSERT INTO place_island_polygon.osm_ids VALUES (NEW.osm_id);
END IF;
INSERT INTO place_island_polygon.osm_ids VALUES (NEW.osm_id) ON CONFLICT (osm_id) DO NOTHING;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
Expand All @@ -62,6 +58,11 @@ DECLARE
t TIMESTAMP WITH TIME ZONE := clock_timestamp();
BEGIN
RAISE LOG 'Refresh place_island_polygon';

-- Analyze tracking and source tables before performing update
ANALYZE place_island_polygon.osm_ids;
ANALYZE osm_island_polygon;

PERFORM update_osm_island_polygon(false);
-- noinspection SqlWithoutWhere
DELETE FROM place_island_polygon.osm_ids;
Expand All @@ -74,13 +75,13 @@ END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER trigger_store
AFTER INSERT OR UPDATE OR DELETE
AFTER INSERT OR UPDATE
ON osm_island_polygon
FOR EACH ROW
EXECUTE PROCEDURE place_island_polygon.store();

CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE
AFTER INSERT OR UPDATE
ON osm_island_polygon
FOR EACH STATEMENT
EXECUTE PROCEDURE place_island_polygon.flag();
Expand Down
17 changes: 9 additions & 8 deletions layers/place/update_state_point.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,7 @@ CREATE SCHEMA IF NOT EXISTS place_state;

CREATE TABLE IF NOT EXISTS place_state.osm_ids
(
osm_id bigint
osm_id bigint PRIMARY KEY
);

-- etldoc: ne_10m_admin_1_states_provinces -> osm_state_point
Expand Down Expand Up @@ -67,11 +67,7 @@ CREATE INDEX IF NOT EXISTS osm_state_point_rank_idx ON osm_state_point ("rank");
CREATE OR REPLACE FUNCTION place_state.store() RETURNS trigger AS
$$
BEGIN
IF (tg_op = 'DELETE') THEN
INSERT INTO place_state.osm_ids VALUES (OLD.osm_id);
ELSE
INSERT INTO place_state.osm_ids VALUES (NEW.osm_id);
END IF;
INSERT INTO place_state.osm_ids VALUES (NEW.osm_id) ON CONFLICT (osm_id) DO NOTHING;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
Expand All @@ -96,6 +92,11 @@ DECLARE
t TIMESTAMP WITH TIME ZONE := clock_timestamp();
BEGIN
RAISE LOG 'Refresh place_state rank';

-- Analyze tracking and source tables before performing update
ANALYZE place_state.osm_ids;
ANALYZE osm_state_point;

PERFORM update_osm_state_point(false);
-- noinspection SqlWithoutWhere
DELETE FROM place_state.osm_ids;
Expand All @@ -108,13 +109,13 @@ END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER trigger_store
AFTER INSERT OR UPDATE OR DELETE
AFTER INSERT OR UPDATE
ON osm_state_point
FOR EACH ROW
EXECUTE PROCEDURE place_state.store();

CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE
AFTER INSERT OR UPDATE
ON osm_state_point
FOR EACH STATEMENT
EXECUTE PROCEDURE place_state.flag();
Expand Down

0 comments on commit bd26527

Please sign in to comment.