From c6d859a08ac554ae8335bfc408f9af99ad24e910 Mon Sep 17 00:00:00 2001 From: Sarah Hoffmann Date: Fri, 10 Apr 2020 22:37:14 +0200 Subject: [PATCH 1/2] factor out computation of address and search rank --- sql/functions/placex_triggers.sql | 66 +++++++------------------------ sql/functions/ranking.sql | 65 ++++++++++++++++++++++++++++++ 2 files changed, 80 insertions(+), 51 deletions(-) diff --git a/sql/functions/placex_triggers.sql b/sql/functions/placex_triggers.sql index 0151162e..3f9fae7a 100644 --- a/sql/functions/placex_triggers.sql +++ b/sql/functions/placex_triggers.sql @@ -410,8 +410,8 @@ BEGIN is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon'); IF NEW.class in ('place','boundary') - AND NEW.type in ('postcode','postal_code') THEN - + AND NEW.type in ('postcode','postal_code') + THEN IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN -- most likely just a part of a multipolygon postcode boundary, throw it away RETURN NULL; @@ -419,61 +419,25 @@ BEGIN NEW.name := hstore('ref', NEW.address->'postcode'); - SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode') - INTO NEW.rank_search, NEW.rank_address; - - IF NOT is_area THEN - NEW.rank_address := 0; - END IF; ELSEIF NEW.class = 'boundary' AND NOT is_area THEN - return NULL; + RETURN NULL; ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative' - AND NEW.admin_level <= 4 AND NEW.osm_type = 'W' THEN - return NULL; - ELSEIF NEW.osm_type = 'N' AND NEW.class = 'highway' THEN - NEW.rank_search = 30; - NEW.rank_address = 0; - ELSEIF NEW.class = 'landuse' AND NOT is_area THEN - NEW.rank_search = 30; - NEW.rank_address = 0; - ELSE - -- do table lookup stuff - IF NEW.class = 'boundary' and NEW.type = 'administrative' THEN - classtype = NEW.type || NEW.admin_level::TEXT; - ELSE - classtype = NEW.type; - END IF; - SELECT l.rank_search, l.rank_address FROM address_levels l - WHERE (l.country_code = NEW.country_code or l.country_code is NULL) - AND l.class = NEW.class AND (l.type = classtype or l.type is NULL) - ORDER BY l.country_code, l.class, l.type LIMIT 1 - INTO NEW.rank_search, NEW.rank_address; - - IF NEW.rank_search is NULL THEN - NEW.rank_search := 30; - END IF; - - IF NEW.rank_address is NULL THEN - NEW.rank_address := 30; - END IF; + AND NEW.admin_level <= 4 AND NEW.osm_type = 'W' + THEN + RETURN NULL; END IF; - -- some postcorrections - IF NEW.class = 'waterway' AND NEW.osm_type = 'R' THEN - -- Slightly promote waterway relations so that they are processed - -- before their members. - NEW.rank_search := NEW.rank_search - 1; + SELECT * INTO NEW.rank_search, NEW.rank_address + FROM compute_place_rank(NEW.country_code, NEW.osm_type, NEW.class, + NEW.type, NEW.admin_level, is_area, + (NEW.extratags->'capital') = 'yes', + NEW.address->'postcode'); + + -- a country code make no sense below rank 4 (country) + IF NEW.rank_search < 4 THEN + NEW.country_code := NULL; END IF; - IF (NEW.extratags -> 'capital') = 'yes' THEN - NEW.rank_search := NEW.rank_search - 1; - END IF; - - END IF; - - -- a country code make no sense below rank 4 (country) - IF NEW.rank_search < 4 THEN - NEW.country_code := NULL; END IF; --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; diff --git a/sql/functions/ranking.sql b/sql/functions/ranking.sql index ecd31e90..d23944b1 100644 --- a/sql/functions/ranking.sql +++ b/sql/functions/ranking.sql @@ -114,3 +114,68 @@ BEGIN END; $$ LANGUAGE plpgsql IMMUTABLE; + + +-- Get standard search and address rank for an object +CREATE OR REPLACE FUNCTION compute_place_rank(country VARCHAR(2), + osm_type VARCHAR(1), + place_class TEXT, place_type TEXT, + admin_level SMALLINT, + is_area BOOLEAN, is_major BOOLEAN, + postcode TEXT, + OUT search_rank SMALLINT, + OUT address_rank SMALLINT) +AS $$ +DECLARE + classtype TEXT; +BEGIN + IF place_class in ('place','boundary') + and place_type in ('postcode','postal_code') + THEN + SELECT * INTO search_rank, address_rank + FROM get_postcode_rank(country, postcode); + + IF NOT is_area THEN + address_rank := 0; + END IF; + ELSEIF osm_type = 'N' AND place_class = 'highway' THEN + search_rank = 30; + address_rank = 0; + ELSEIF place_class = 'landuse' AND NOT is_area THEN + search_rank = 30; + address_rank = 0; + ELSE + IF place_class = 'boundary' and place_type = 'administrative' THEN + classtype = place_type || admin_level::TEXT; + ELSE + classtype = place_type; + END IF; + + SELECT l.rank_search, l.rank_address INTO search_rank, address_rank + FROM address_levels l + WHERE (l.country_code = country or l.country_code is NULL) + AND l.class = place_class AND (l.type = classtype or l.type is NULL) + ORDER BY l.country_code, l.class, l.type LIMIT 1; + + IF search_rank is NULL THEN + search_rank := 30; + END IF; + + IF address_rank is NULL THEN + address_rank := 30; + END IF; + + -- some postcorrections + IF place_class = 'waterway' AND osm_type = 'R' THEN + -- Slightly promote waterway relations so that they are processed + -- before their members. + search_rank := search_rank - 1; + END IF; + + IF is_major THEN + search_rank := search_rank - 1; + END IF; + END IF; +END; +$$ +LANGUAGE plpgsql IMMUTABLE; From cd96354bc7afc298303ad8b80afec16a48397779 Mon Sep 17 00:00:00 2001 From: Sarah Hoffmann Date: Sat, 11 Apr 2020 09:20:13 +0200 Subject: [PATCH 2/2] reset address and search ranks on update With ranks being dynamically changed through linking of places, it is important to reset the ranks on update, so that changes of the rank due to changes in linking are correctly taken into account. --- sql/functions/placex_triggers.sql | 17 ++++++++++++++--- sql/functions/ranking.sql | 25 ++++++++++++++++++------- 2 files changed, 32 insertions(+), 10 deletions(-) diff --git a/sql/functions/placex_triggers.sql b/sql/functions/placex_triggers.sql index 3f9fae7a..ab8f951f 100644 --- a/sql/functions/placex_triggers.sql +++ b/sql/functions/placex_triggers.sql @@ -392,7 +392,6 @@ DECLARE country_code VARCHAR(2); diameter FLOAT; classtable TEXT; - classtype TEXT; BEGIN --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; @@ -428,8 +427,9 @@ BEGIN END IF; SELECT * INTO NEW.rank_search, NEW.rank_address - FROM compute_place_rank(NEW.country_code, NEW.osm_type, NEW.class, - NEW.type, NEW.admin_level, is_area, + FROM compute_place_rank(NEW.country_code, + CASE WHEN is_area THEN 'A' ELSE NEW.osm_type END, + NEW.class, NEW.type, NEW.admin_level, (NEW.extratags->'capital') = 'yes', NEW.address->'postcode'); @@ -552,6 +552,17 @@ BEGIN RETURN NEW; END IF; + -- recompute the ranks, they might change when linking changes + SELECT * INTO NEW.rank_search, NEW.rank_address + FROM compute_place_rank(NEW.country_code, + CASE WHEN ST_GeometryType(NEW.geometry) + IN ('ST_Polygon','ST_MultiPolygon') + THEN 'A' ELSE NEW.osm_type END, + NEW.class, NEW.type, NEW.admin_level, + (NEW.extratags->'capital') = 'yes', + NEW.address->'postcode'); + + --DEBUG: RAISE WARNING 'Copy over address tags'; -- housenumber is a computed field, so start with an empty value NEW.housenumber := NULL; diff --git a/sql/functions/ranking.sql b/sql/functions/ranking.sql index d23944b1..98e70a42 100644 --- a/sql/functions/ranking.sql +++ b/sql/functions/ranking.sql @@ -116,12 +116,23 @@ $$ LANGUAGE plpgsql IMMUTABLE; --- Get standard search and address rank for an object +-- Get standard search and address rank for an object. +-- +-- \param country Two-letter country code where the object is in. +-- \param extended_type OSM type (N, W, R) or area type (A). +-- \param place_class Class (or tag key) of object. +-- \param place_type Type (or tag value) of object. +-- \param admin_level Value of admin_level tag. +-- \param is_major If true, boost search rank by one. +-- \param postcode Value of addr:postcode tag. +-- \param[out] search_rank Computed search rank. +-- \param[out] address_rank Computed address rank. +-- CREATE OR REPLACE FUNCTION compute_place_rank(country VARCHAR(2), - osm_type VARCHAR(1), + extended_type VARCHAR(1), place_class TEXT, place_type TEXT, admin_level SMALLINT, - is_area BOOLEAN, is_major BOOLEAN, + is_major BOOLEAN, postcode TEXT, OUT search_rank SMALLINT, OUT address_rank SMALLINT) @@ -135,13 +146,13 @@ BEGIN SELECT * INTO search_rank, address_rank FROM get_postcode_rank(country, postcode); - IF NOT is_area THEN + IF NOT extended_type = 'A' THEN address_rank := 0; END IF; - ELSEIF osm_type = 'N' AND place_class = 'highway' THEN + ELSEIF extended_type = 'N' AND place_class = 'highway' THEN search_rank = 30; address_rank = 0; - ELSEIF place_class = 'landuse' AND NOT is_area THEN + ELSEIF place_class = 'landuse' AND extended_type != 'A' THEN search_rank = 30; address_rank = 0; ELSE @@ -166,7 +177,7 @@ BEGIN END IF; -- some postcorrections - IF place_class = 'waterway' AND osm_type = 'R' THEN + IF place_class = 'waterway' AND extended_type = 'R' THEN -- Slightly promote waterway relations so that they are processed -- before their members. search_rank := search_rank - 1;