Replacing update on the whole table with an update only on changed rows. The goal is to update more quickly by just updating the changing content. The update now focus on osm_id of changed rows, it use index. Add a where clause tags != update_tags(tags, geometry) en ensure only update when changed. It requires one more trigger and a table to store changed osm_id. The UPDATE is keep in a function to be reusable for initial setup and trigger update. I try many code layout before done it in this way with the goal to keep the code for initial pass and for update. It should have low impact on initial data load. Better performance for row update can be achieve with BEFORE UPDATE, but require to duplicate the logic. It is not based on the already merged https://github.com/openmaptiles/openmaptiles/pull/896 because calling and update within a function for each updated row was not efficient for larger table (like housenumber). It addresses #814. * Remake update_peak_point use incremental update #814 * Make update_aerodrome_label_point use incremental update #814 * Make housenumber_centroid use incremental update #814 * Make update_continent_point use incremental update #814 * Make update_island_point use incremental update #814 * Make update_island_polygon use incremental update #814 * Remove dead code in update_state_point.sql * Make update_state_point use incremental update #814 * Remove dead code in update_country_point.sql * Make update_country_point use incremental update #814 * Make osm_poi_polygon use incremental update #814 Thanks @frodrigo
87 lines
2.3 KiB
PL/PgSQL
87 lines
2.3 KiB
PL/PgSQL
DROP TRIGGER IF EXISTS trigger_flag ON osm_housenumber_point;
|
|
DROP TRIGGER IF EXISTS trigger_store ON osm_housenumber_point;
|
|
DROP TRIGGER IF EXISTS trigger_refresh ON housenumber.updates;
|
|
|
|
CREATE SCHEMA IF NOT EXISTS housenumber;
|
|
|
|
CREATE TABLE IF NOT EXISTS housenumber.osm_ids
|
|
(
|
|
osm_id bigint
|
|
);
|
|
|
|
-- etldoc: osm_housenumber_point -> osm_housenumber_point
|
|
CREATE OR REPLACE FUNCTION convert_housenumber_point(full_update boolean) RETURNS void AS
|
|
$$
|
|
UPDATE osm_housenumber_point
|
|
SET geometry =
|
|
CASE
|
|
WHEN ST_NPoints(ST_ConvexHull(geometry)) = ST_NPoints(geometry)
|
|
THEN ST_Centroid(geometry)
|
|
ELSE ST_PointOnSurface(geometry)
|
|
END
|
|
WHERE (full_update OR osm_id IN (SELECT osm_id FROM housenumber.osm_ids))
|
|
AND ST_GeometryType(geometry) <> 'ST_Point';
|
|
$$ LANGUAGE SQL;
|
|
|
|
SELECT convert_housenumber_point(true);
|
|
|
|
-- Handle updates
|
|
|
|
CREATE OR REPLACE FUNCTION housenumber.store() RETURNS trigger AS
|
|
$$
|
|
BEGIN
|
|
IF (tg_op = 'DELETE') THEN
|
|
INSERT INTO housenumber.osm_ids VALUES (OLD.osm_id);
|
|
ELSE
|
|
INSERT INTO housenumber.osm_ids VALUES (NEW.osm_id);
|
|
END IF;
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TABLE IF NOT EXISTS housenumber.updates
|
|
(
|
|
id serial PRIMARY KEY,
|
|
t text,
|
|
UNIQUE (t)
|
|
);
|
|
CREATE OR REPLACE FUNCTION housenumber.flag() RETURNS trigger AS
|
|
$$
|
|
BEGIN
|
|
INSERT INTO housenumber.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE FUNCTION housenumber.refresh() RETURNS trigger AS
|
|
$$
|
|
BEGIN
|
|
RAISE LOG 'Refresh housenumber';
|
|
PERFORM convert_housenumber_point(false);
|
|
-- noinspection SqlWithoutWhere
|
|
DELETE FROM housenumber.osm_ids;
|
|
-- noinspection SqlWithoutWhere
|
|
DELETE FROM housenumber.updates;
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER trigger_store
|
|
AFTER INSERT OR UPDATE OR DELETE
|
|
ON osm_housenumber_point
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE housenumber.store();
|
|
|
|
CREATE TRIGGER trigger_flag
|
|
AFTER INSERT OR UPDATE OR DELETE
|
|
ON osm_housenumber_point
|
|
FOR EACH STATEMENT
|
|
EXECUTE PROCEDURE housenumber.flag();
|
|
|
|
CREATE CONSTRAINT TRIGGER trigger_refresh
|
|
AFTER INSERT
|
|
ON housenumber.updates
|
|
INITIALLY DEFERRED
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE housenumber.refresh();
|