Update Performance poi Layer (#1510)
Improved update performance of poi layer - Refactored update_poi_point.sql to partial diff update - Refactored IDs to be unique in poi_polygon.osm_ids - Restricted updates to INSERT and UPDATE operations during poi_polygon.refresh - Added analyze statements before update queries during poi_polygon.refresh
This commit is contained in:
parent
3caa11aee9
commit
0e8e2512e8
@ -1,18 +1,28 @@
|
|||||||
DROP TRIGGER IF EXISTS trigger_flag ON osm_poi_point;
|
DROP TRIGGER IF EXISTS trigger_flag ON osm_poi_point;
|
||||||
DROP TRIGGER IF EXISTS trigger_refresh ON poi_point.updates;
|
DROP TRIGGER IF EXISTS trigger_refresh ON poi_point.updates;
|
||||||
|
DROP TRIGGER IF EXISTS trigger_store ON osm_poi_point;
|
||||||
|
|
||||||
|
CREATE SCHEMA IF NOT EXISTS poi_point;
|
||||||
|
|
||||||
|
CREATE TABLE IF NOT EXISTS poi_point.osm_ids
|
||||||
|
(
|
||||||
|
osm_id bigint PRIMARY KEY
|
||||||
|
);
|
||||||
|
|
||||||
-- etldoc: osm_poi_point -> osm_poi_point
|
-- etldoc: osm_poi_point -> osm_poi_point
|
||||||
CREATE OR REPLACE FUNCTION update_osm_poi_point() RETURNS void AS
|
CREATE OR REPLACE FUNCTION update_osm_poi_point(full_update bool) RETURNS void AS
|
||||||
$$
|
$$
|
||||||
BEGIN
|
BEGIN
|
||||||
UPDATE osm_poi_point
|
UPDATE osm_poi_point
|
||||||
SET subclass = 'subway'
|
SET subclass = 'subway'
|
||||||
WHERE station = 'subway'
|
WHERE (full_update OR osm_id IN (SELECT osm_id FROM poi_point.osm_ids))
|
||||||
|
AND station = 'subway'
|
||||||
AND subclass = 'station';
|
AND subclass = 'station';
|
||||||
|
|
||||||
UPDATE osm_poi_point
|
UPDATE osm_poi_point
|
||||||
SET subclass = 'halt'
|
SET subclass = 'halt'
|
||||||
WHERE funicular = 'yes'
|
WHERE (full_update OR osm_id IN (SELECT osm_id FROM poi_point.osm_ids))
|
||||||
|
AND funicular = 'yes'
|
||||||
AND subclass = 'station';
|
AND subclass = 'station';
|
||||||
|
|
||||||
-- ATM without name
|
-- ATM without name
|
||||||
@ -23,7 +33,8 @@ BEGIN
|
|||||||
COALESCE(tags -> 'operator', tags -> 'network'),
|
COALESCE(tags -> 'operator', tags -> 'network'),
|
||||||
tags || hstore('name', COALESCE(tags -> 'operator', tags -> 'network'))
|
tags || hstore('name', COALESCE(tags -> 'operator', tags -> 'network'))
|
||||||
)
|
)
|
||||||
WHERE subclass = 'atm'
|
WHERE (full_update OR osm_id IN (SELECT osm_id FROM poi_point.osm_ids))
|
||||||
|
AND subclass = 'atm'
|
||||||
AND name = ''
|
AND name = ''
|
||||||
AND COALESCE(tags -> 'operator', tags -> 'network') IS NOT NULL;
|
AND COALESCE(tags -> 'operator', tags -> 'network') IS NOT NULL;
|
||||||
|
|
||||||
@ -35,19 +46,21 @@ BEGIN
|
|||||||
CONCAT(COALESCE(tags -> 'brand', tags -> 'operator'), concat(' ', tags -> 'ref')),
|
CONCAT(COALESCE(tags -> 'brand', tags -> 'operator'), concat(' ', tags -> 'ref')),
|
||||||
tags || hstore('name', CONCAT(COALESCE(tags -> 'brand', tags -> 'operator'), concat(' ', tags -> 'ref')))
|
tags || hstore('name', CONCAT(COALESCE(tags -> 'brand', tags -> 'operator'), concat(' ', tags -> 'ref')))
|
||||||
)
|
)
|
||||||
WHERE subclass = 'parcel_locker'
|
WHERE (full_update OR osm_id IN (SELECT osm_id FROM poi_point.osm_ids))
|
||||||
|
AND subclass = 'parcel_locker'
|
||||||
AND name = ''
|
AND name = ''
|
||||||
AND COALESCE(tags -> 'brand', tags -> 'operator') IS NOT NULL;
|
AND COALESCE(tags -> 'brand', tags -> 'operator') IS NOT NULL;
|
||||||
|
|
||||||
UPDATE osm_poi_point
|
UPDATE osm_poi_point
|
||||||
SET tags = update_tags(tags, geometry)
|
SET tags = update_tags(tags, geometry)
|
||||||
WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL
|
WHERE (full_update OR osm_id IN (SELECT osm_id FROM poi_point.osm_ids))
|
||||||
|
AND COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL
|
||||||
AND tags != update_tags(tags, geometry);
|
AND tags != update_tags(tags, geometry);
|
||||||
|
|
||||||
END;
|
END;
|
||||||
$$ LANGUAGE plpgsql;
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
SELECT update_osm_poi_point();
|
SELECT update_osm_poi_point(TRUE);
|
||||||
|
|
||||||
-- etldoc: osm_poi_stop_rank -> osm_poi_point
|
-- etldoc: osm_poi_stop_rank -> osm_poi_point
|
||||||
CREATE OR REPLACE FUNCTION update_osm_poi_point_agg() RETURNS void AS
|
CREATE OR REPLACE FUNCTION update_osm_poi_point_agg() RETURNS void AS
|
||||||
@ -91,7 +104,13 @@ SELECT update_osm_poi_point_agg();
|
|||||||
|
|
||||||
-- Handle updates
|
-- Handle updates
|
||||||
|
|
||||||
CREATE SCHEMA IF NOT EXISTS poi_point;
|
CREATE OR REPLACE FUNCTION poi_point.store() RETURNS trigger AS
|
||||||
|
$$
|
||||||
|
BEGIN
|
||||||
|
INSERT INTO poi_point.osm_ids VALUES (NEW.osm_id) ON CONFLICT (osm_id) DO NOTHING;
|
||||||
|
RETURN NULL;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
CREATE TABLE IF NOT EXISTS poi_point.updates
|
CREATE TABLE IF NOT EXISTS poi_point.updates
|
||||||
(
|
(
|
||||||
@ -113,11 +132,18 @@ DECLARE
|
|||||||
t TIMESTAMP WITH TIME ZONE := clock_timestamp();
|
t TIMESTAMP WITH TIME ZONE := clock_timestamp();
|
||||||
BEGIN
|
BEGIN
|
||||||
RAISE LOG 'Refresh poi_point';
|
RAISE LOG 'Refresh poi_point';
|
||||||
PERFORM update_osm_poi_point();
|
|
||||||
|
-- Analyze tracking and source tables before performing update
|
||||||
|
ANALYZE poi_point.osm_ids;
|
||||||
|
ANALYZE osm_poi_point;
|
||||||
|
|
||||||
|
PERFORM update_osm_poi_point(FALSE);
|
||||||
REFRESH MATERIALIZED VIEW osm_poi_stop_centroid;
|
REFRESH MATERIALIZED VIEW osm_poi_stop_centroid;
|
||||||
REFRESH MATERIALIZED VIEW osm_poi_stop_rank;
|
REFRESH MATERIALIZED VIEW osm_poi_stop_rank;
|
||||||
PERFORM update_osm_poi_point_agg();
|
PERFORM update_osm_poi_point_agg();
|
||||||
-- noinspection SqlWithoutWhere
|
-- noinspection SqlWithoutWhere
|
||||||
|
DELETE FROM poi_point.osm_ids;
|
||||||
|
-- noinspection SqlWithoutWhere
|
||||||
DELETE FROM poi_point.updates;
|
DELETE FROM poi_point.updates;
|
||||||
|
|
||||||
RAISE LOG 'Refresh poi_point done in %', age(clock_timestamp(), t);
|
RAISE LOG 'Refresh poi_point done in %', age(clock_timestamp(), t);
|
||||||
@ -125,8 +151,14 @@ BEGIN
|
|||||||
END;
|
END;
|
||||||
$$ LANGUAGE plpgsql;
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
CREATE TRIGGER trigger_store
|
||||||
|
AFTER INSERT OR UPDATE
|
||||||
|
ON osm_poi_point
|
||||||
|
FOR EACH ROW
|
||||||
|
EXECUTE PROCEDURE poi_point.store();
|
||||||
|
|
||||||
CREATE TRIGGER trigger_flag
|
CREATE TRIGGER trigger_flag
|
||||||
AFTER INSERT OR UPDATE OR DELETE
|
AFTER INSERT OR UPDATE
|
||||||
ON osm_poi_point
|
ON osm_poi_point
|
||||||
FOR EACH STATEMENT
|
FOR EACH STATEMENT
|
||||||
EXECUTE PROCEDURE poi_point.flag();
|
EXECUTE PROCEDURE poi_point.flag();
|
||||||
|
|||||||
@ -6,7 +6,7 @@ CREATE SCHEMA IF NOT EXISTS poi_polygon;
|
|||||||
|
|
||||||
CREATE TABLE IF NOT EXISTS poi_polygon.osm_ids
|
CREATE TABLE IF NOT EXISTS poi_polygon.osm_ids
|
||||||
(
|
(
|
||||||
osm_id bigint
|
osm_id bigint PRIMARY KEY
|
||||||
);
|
);
|
||||||
|
|
||||||
-- etldoc: osm_poi_polygon -> osm_poi_polygon
|
-- etldoc: osm_poi_polygon -> osm_poi_polygon
|
||||||
@ -51,11 +51,7 @@ SELECT update_poi_polygon(true);
|
|||||||
CREATE OR REPLACE FUNCTION poi_polygon.store() RETURNS trigger AS
|
CREATE OR REPLACE FUNCTION poi_polygon.store() RETURNS trigger AS
|
||||||
$$
|
$$
|
||||||
BEGIN
|
BEGIN
|
||||||
IF (tg_op = 'DELETE') THEN
|
INSERT INTO poi_polygon.osm_ids VALUES (NEW.osm_id) ON CONFLICT (osm_id) DO NOTHING;
|
||||||
INSERT INTO poi_polygon.osm_ids VALUES (OLD.osm_id);
|
|
||||||
ELSE
|
|
||||||
INSERT INTO poi_polygon.osm_ids VALUES (NEW.osm_id);
|
|
||||||
END IF;
|
|
||||||
RETURN NULL;
|
RETURN NULL;
|
||||||
END;
|
END;
|
||||||
$$ LANGUAGE plpgsql;
|
$$ LANGUAGE plpgsql;
|
||||||
@ -80,6 +76,11 @@ DECLARE
|
|||||||
t TIMESTAMP WITH TIME ZONE := clock_timestamp();
|
t TIMESTAMP WITH TIME ZONE := clock_timestamp();
|
||||||
BEGIN
|
BEGIN
|
||||||
RAISE LOG 'Refresh poi_polygon';
|
RAISE LOG 'Refresh poi_polygon';
|
||||||
|
|
||||||
|
-- Analyze tracking and source tables before performing update
|
||||||
|
ANALYZE poi_polygon.osm_ids;
|
||||||
|
ANALYZE osm_poi_polygon;
|
||||||
|
|
||||||
PERFORM update_poi_polygon(false);
|
PERFORM update_poi_polygon(false);
|
||||||
-- noinspection SqlWithoutWhere
|
-- noinspection SqlWithoutWhere
|
||||||
DELETE FROM poi_polygon.osm_ids;
|
DELETE FROM poi_polygon.osm_ids;
|
||||||
@ -92,13 +93,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_poi_polygon
|
ON osm_poi_polygon
|
||||||
FOR EACH ROW
|
FOR EACH ROW
|
||||||
EXECUTE PROCEDURE poi_polygon.store();
|
EXECUTE PROCEDURE poi_polygon.store();
|
||||||
|
|
||||||
CREATE TRIGGER trigger_flag
|
CREATE TRIGGER trigger_flag
|
||||||
AFTER INSERT OR UPDATE OR DELETE
|
AFTER INSERT OR UPDATE
|
||||||
ON osm_poi_polygon
|
ON osm_poi_polygon
|
||||||
FOR EACH STATEMENT
|
FOR EACH STATEMENT
|
||||||
EXECUTE PROCEDURE poi_polygon.flag();
|
EXECUTE PROCEDURE poi_polygon.flag();
|
||||||
|
|||||||
Loading…
x
Reference in New Issue
Block a user