Better update of osm_important_waterway_linestring, use frist and last version of osm object (#997)

Current implementation of osm_important_waterway_linestring have two bugs:
* The distinct on is_old keep the oldest version of the old object, and the oldest version of the new object, but need the last version of the new object.
* Delete the old version of the object and rebuild the using the new version of the object. But we need to remove matchings the old and the new version of the object, then rebuild the two.

Then only delete and update using first and last version of the object, intermediate versions are ignored.

Similar implementation of what is done in #996.
pull/998/head^2
Frédéric Rodrigo 2020-09-28 16:07:37 +02:00 zatwierdzone przez GitHub
rodzic 8bb77b67a1
commit c8f919e9d6
Nie znaleziono w bazie danych klucza dla tego podpisu
ID klucza GPG: 4AEE18F83AFDEB23
1 zmienionych plików z 41 dodań i 26 usunięć

Wyświetl plik

@ -79,25 +79,23 @@ CREATE SCHEMA IF NOT EXISTS waterway_important;
CREATE TABLE IF NOT EXISTS waterway_important.changes CREATE TABLE IF NOT EXISTS waterway_important.changes
( (
id serial PRIMARY KEY, id serial PRIMARY KEY,
osm_id bigint,
is_old boolean, is_old boolean,
name character varying, name character varying,
name_en character varying, name_en character varying,
name_de character varying, name_de character varying,
tags hstore, tags hstore
UNIQUE (is_old, name, name_en, name_de, tags)
); );
CREATE OR REPLACE FUNCTION waterway_important.store() RETURNS trigger AS CREATE OR REPLACE FUNCTION waterway_important.store() RETURNS trigger AS
$$ $$
BEGIN BEGIN
IF (tg_op IN ('DELETE', 'UPDATE')) AND OLD.name <> '' AND OLD.waterway = 'river' THEN IF (tg_op IN ('DELETE', 'UPDATE')) AND OLD.name <> '' AND OLD.waterway = 'river' THEN
INSERT INTO waterway_important.changes(is_old, name, name_en, name_de, tags) INSERT INTO waterway_important.changes(is_old, name, name_en, name_de, tags)
VALUES (TRUE, OLD.name, OLD.name_en, OLD.name_de, slice_language_tags(OLD.tags)) VALUES (TRUE, OLD.name, OLD.name_en, OLD.name_de, slice_language_tags(OLD.tags));
ON CONFLICT(is_old, name, name_en, name_de, tags) DO NOTHING;
END IF; END IF;
IF (tg_op IN ('UPDATE', 'INSERT')) AND NEW.name <> '' AND NEW.waterway = 'river' THEN IF (tg_op IN ('UPDATE', 'INSERT')) AND NEW.name <> '' AND NEW.waterway = 'river' THEN
INSERT INTO waterway_important.changes(is_old, name, name_en, name_de, tags) INSERT INTO waterway_important.changes(is_old, name, name_en, name_de, tags)
VALUES (FALSE, NEW.name, NEW.name_en, NEW.name_de, slice_language_tags(NEW.tags)) VALUES (FALSE, NEW.name, NEW.name_en, NEW.name_de, slice_language_tags(NEW.tags));
ON CONFLICT(is_old, name, name_en, name_de, tags) DO NOTHING;
END IF; END IF;
RETURN NULL; RETURN NULL;
END; END;
@ -123,11 +121,34 @@ BEGIN
RAISE LOG 'Refresh waterway'; RAISE LOG 'Refresh waterway';
-- REFRESH osm_important_waterway_linestring -- REFRESH osm_important_waterway_linestring
-- Compact the change history to keep only the first and last version, and then uniq version of row
CREATE TEMP TABLE changes_compact AS
SELECT DISTINCT ON (name, name_en, name_de, tags)
name,
name_en,
name_de,
tags
FROM ((
SELECT DISTINCT ON (osm_id) *
FROM waterway_important.changes
WHERE is_old
ORDER BY osm_id,
id ASC
)
UNION ALL
(
SELECT DISTINCT ON (osm_id) *
FROM waterway_important.changes
WHERE NOT is_old
ORDER BY osm_id,
id DESC
)) AS t;
DELETE DELETE
FROM osm_important_waterway_linestring AS w FROM osm_important_waterway_linestring AS w
USING waterway_important.changes AS c USING changes_compact AS c
WHERE c.is_old WHERE w.name = c.name
AND w.name = c.name
AND w.name_en IS NOT DISTINCT FROM c.name_en AND w.name_en IS NOT DISTINCT FROM c.name_en
AND w.name_de IS NOT DISTINCT FROM c.name_de AND w.name_de IS NOT DISTINCT FROM c.name_de
AND w.tags IS NOT DISTINCT FROM c.tags; AND w.tags IS NOT DISTINCT FROM c.tags;
@ -145,23 +166,21 @@ BEGIN
w.name_de, w.name_de,
slice_language_tags(w.tags) AS tags slice_language_tags(w.tags) AS tags
FROM osm_waterway_linestring AS w FROM osm_waterway_linestring AS w
JOIN waterway_important.changes AS c ON JOIN changes_compact AS c ON
w.name = c.name AND w.name_en IS NOT DISTINCT FROM c.name_en AND w.name = c.name AND w.name_en IS NOT DISTINCT FROM c.name_en AND
w.name_de IS NOT DISTINCT FROM c.name_de AND w.name_de IS NOT DISTINCT FROM c.name_de AND
slice_language_tags(w.tags) IS NOT DISTINCT FROM c.tags slice_language_tags(w.tags) IS NOT DISTINCT FROM c.tags
WHERE w.name <> '' WHERE w.name <> ''
AND w.waterway = 'river' AND w.waterway = 'river'
AND ST_IsValid(geometry) AND ST_IsValid(geometry)
AND NOT c.is_old
GROUP BY w.name, w.name_en, w.name_de, slice_language_tags(w.tags) GROUP BY w.name, w.name_en, w.name_de, slice_language_tags(w.tags)
) AS waterway_union; ) AS waterway_union;
-- REFRESH sm_important_waterway_linestring_gen1 -- REFRESH sm_important_waterway_linestring_gen1
DELETE DELETE
FROM osm_important_waterway_linestring_gen1 AS w FROM osm_important_waterway_linestring_gen1 AS w
USING waterway_important.changes AS c USING changes_compact AS c
WHERE c.is_old WHERE w.name = c.name
AND w.name = c.name
AND w.name_en IS NOT DISTINCT FROM c.name_en AND w.name_en IS NOT DISTINCT FROM c.name_en
AND w.name_de IS NOT DISTINCT FROM c.name_de AND w.name_de IS NOT DISTINCT FROM c.name_de
AND w.tags IS NOT DISTINCT FROM c.tags; AND w.tags IS NOT DISTINCT FROM c.tags;
@ -169,15 +188,13 @@ BEGIN
INSERT INTO osm_important_waterway_linestring_gen1 INSERT INTO osm_important_waterway_linestring_gen1
SELECT w.* SELECT w.*
FROM osm_important_waterway_linestring_gen1_view AS w FROM osm_important_waterway_linestring_gen1_view AS w
NATURAL JOIN waterway_important.changes AS c NATURAL JOIN changes_compact AS c;
WHERE NOT c.is_old;
-- REFRESH osm_important_waterway_linestring_gen2 -- REFRESH osm_important_waterway_linestring_gen2
DELETE DELETE
FROM osm_important_waterway_linestring_gen2 AS w FROM osm_important_waterway_linestring_gen2 AS w
USING waterway_important.changes AS c USING changes_compact AS c
WHERE c.is_old WHERE w.name = c.name
AND w.name = c.name
AND w.name_en IS NOT DISTINCT FROM c.name_en AND w.name_en IS NOT DISTINCT FROM c.name_en
AND w.name_de IS NOT DISTINCT FROM c.name_de AND w.name_de IS NOT DISTINCT FROM c.name_de
AND w.tags IS NOT DISTINCT FROM c.tags; AND w.tags IS NOT DISTINCT FROM c.tags;
@ -185,15 +202,13 @@ BEGIN
INSERT INTO osm_important_waterway_linestring_gen2 INSERT INTO osm_important_waterway_linestring_gen2
SELECT w.* SELECT w.*
FROM osm_important_waterway_linestring_gen2_view AS w FROM osm_important_waterway_linestring_gen2_view AS w
NATURAL JOIN waterway_important.changes AS c NATURAL JOIN changes_compact AS c;
WHERE NOT c.is_old;
-- REFRESH osm_important_waterway_linestring_gen3 -- REFRESH osm_important_waterway_linestring_gen3
DELETE DELETE
FROM osm_important_waterway_linestring_gen3 AS w FROM osm_important_waterway_linestring_gen3 AS w
USING waterway_important.changes AS c USING changes_compact AS c
WHERE c.is_old WHERE w.name = c.name
AND w.name = c.name
AND w.name_en IS NOT DISTINCT FROM c.name_en AND w.name_en IS NOT DISTINCT FROM c.name_en
AND w.name_de IS NOT DISTINCT FROM c.name_de AND w.name_de IS NOT DISTINCT FROM c.name_de
AND w.tags IS NOT DISTINCT FROM c.tags; AND w.tags IS NOT DISTINCT FROM c.tags;
@ -201,9 +216,9 @@ BEGIN
INSERT INTO osm_important_waterway_linestring_gen3 INSERT INTO osm_important_waterway_linestring_gen3
SELECT w.* SELECT w.*
FROM osm_important_waterway_linestring_gen3_view AS w FROM osm_important_waterway_linestring_gen3_view AS w
NATURAL JOIN waterway_important.changes AS c NATURAL JOIN changes_compact AS c;
WHERE NOT c.is_old;
DROP TABLE changes_compact;
-- noinspection SqlWithoutWhere -- noinspection SqlWithoutWhere
DELETE FROM waterway_important.changes; DELETE FROM waterway_important.changes;
-- noinspection SqlWithoutWhere -- noinspection SqlWithoutWhere