]> git.openstreetmap.org Git - nominatim.git/blobdiff - sql/functions.sql
Merge pull request #814 from lonvia/phrase-as-a-class
[nominatim.git] / sql / functions.sql
index 8d477a641d3250bbac170a8c4663403a44c70a7f..596bf808c35e2715400c3c5d930b37ca9b64fea3 100644 (file)
@@ -319,35 +319,31 @@ LANGUAGE plpgsql IMMUTABLE;
 CREATE OR REPLACE FUNCTION get_nearest_postcode(country VARCHAR(2), geom GEOMETRY) RETURNS TEXT
   AS $$
 DECLARE
-  item RECORD;
+  outcode TEXT;
+  cnt INTEGER;
 BEGIN
     -- If the geometry is an area then only one postcode must be within
     -- that area, otherwise consider the area as not having a postcode.
     IF ST_GeometryType(geom) in ('ST_Polygon','ST_MultiPolygon') THEN
-        FOR item IN
-            SELECT min(postcode) as postcode, count(*) as cnt FROM
+        SELECT min(postcode), count(*) FROM
               (SELECT postcode FROM location_postcode
                 WHERE ST_Contains(geom, location_postcode.geometry) LIMIT 2) sub
-        LOOP
-            IF item.cnt > 1 THEN
-                RETURN null;
-            ELSEIF item.cnt = 1 THEN
-                RETURN item.postcode;
-            END IF;
-        END LOOP;
+          INTO outcode, cnt;
+
+        IF cnt = 1 THEN
+            RETURN outcode;
+        ELSE
+            RETURN null;
+        END IF;
     END IF;
 
-    FOR item IN
-        SELECT postcode FROM location_postcode
-        WHERE ST_DWithin(geom, location_postcode.geometry, 0.05)
-              AND location_postcode.country_code = country
-        ORDER BY ST_Distance(geom, location_postcode.geometry)
-        LIMIT 1
-    LOOP
-        RETURN item.postcode;
-    END LOOP;
+    SELECT postcode FROM location_postcode
+     WHERE ST_DWithin(geom, location_postcode.geometry, 0.05)
+          AND location_postcode.country_code = country
+     ORDER BY ST_Distance(geom, location_postcode.geometry) LIMIT 1
+    INTO outcode;
 
-    RETURN null;
+    RETURN outcode;
 END;
 $$
 LANGUAGE plpgsql;
@@ -919,6 +915,9 @@ BEGIN
       ELSE
         NEW.rank_address := 0;
       END IF;
+    ELSEIF NEW.class = 'leisure' and NEW.type in ('park') THEN
+      NEW.rank_search := 24;
+      NEW.rank_address := 0;
     ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
       NEW.rank_search := 18;
       NEW.rank_address := 0;
@@ -1146,7 +1145,7 @@ BEGIN
                 NEW.startnumber := startnumber;
                 NEW.endnumber := endnumber;
                 NEW.linegeo := sectiongeo;
-                NEW.postcode := postcode;
+                NEW.postcode := upper(trim(postcode));
              ELSE
               insert into location_property_osmline
                      (linegeo, partition, osm_id, parent_place_id,
@@ -1563,7 +1562,7 @@ BEGIN
       -- determine postcode
       IF NEW.rank_search > 4 THEN
           IF NEW.address is not null AND NEW.address ? 'postcode' THEN
-              NEW.postcode = NEW.address->'postcode';
+              NEW.postcode = upper(trim(NEW.address->'postcode'));
           ELSE
              SELECT postcode FROM placex WHERE place_id = NEW.parent_place_id INTO NEW.postcode;
           END IF;
@@ -1587,7 +1586,7 @@ BEGIN
       -- Just be happy with inheriting from parent road only
 
       IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
-        result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.address->'postcode', NEW.geometry);
+        result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, upper(trim(NEW.address->'postcode')), NEW.geometry);
         --DEBUG: RAISE WARNING 'Place added to location table';
       END IF;
 
@@ -1758,7 +1757,7 @@ BEGIN
   END IF;
 
   -- make sure all names are in the word table
-  IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
+  IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R' THEN
     perform create_country(NEW.name, lower(NEW.country_code));
     --DEBUG: RAISE WARNING 'Country names updated';
   END IF;
@@ -1948,7 +1947,7 @@ BEGIN
 
   IF NEW.address is not null AND NEW.address ? 'postcode' 
      AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
-    NEW.postcode := NEW.address->'postcode';
+    NEW.postcode := upper(trim(NEW.address->'postcode'));
   END IF;
 
   IF NEW.postcode is null AND NEW.rank_search > 8 THEN
@@ -1959,7 +1958,7 @@ BEGIN
   IF NEW.name IS NOT NULL THEN
 
     IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
-      result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.address->'postcode', NEW.geometry);
+      result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, upper(trim(NEW.address->'postcode')), NEW.geometry);
       --DEBUG: RAISE WARNING 'added to location (full)';
     END IF;